-
Notifications
You must be signed in to change notification settings - Fork 57
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
- Loading branch information
1 parent
8d42c28
commit 613caf5
Showing
2 changed files
with
181 additions
and
0 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,73 @@ | ||
-- Automatic Clustering Spend | ||
-- this query finds tables where the automatic clustering spend has gone over 10 credits in the past 5 hours | ||
WITH table_spend AS ( | ||
SELECT | ||
table_id, | ||
table_name, | ||
SUM(credits_used) AS credits | ||
FROM snowflake.account_usage.automatic_clustering_history | ||
WHERE DATEDIFF(HOUR, end_time, CURRENT_TIMESTAMP) < 5 | ||
GROUP BY 1, 2 | ||
ORDER BY 3 DESC | ||
) | ||
SELECT * | ||
FROM table_spend | ||
WHERE credits > 10 | ||
; | ||
|
||
-- Materialized View Spend | ||
-- this query finds tables where the materialized view spend has gone over 10 credits in the past 5 hours | ||
WITH table_spend AS ( | ||
SELECT | ||
table_id, | ||
table_name, | ||
SUM(credits_used) AS credits | ||
FROM snowflake.account_usage.materialized_view_refresh_history | ||
WHERE DATEDIFF(HOUR, end_time, CURRENT_TIMESTAMP) < 5 | ||
GROUP BY 1, 2 | ||
ORDER BY 3 DESC) | ||
SELECT * FROM table_spend | ||
WHERE credits > 10 | ||
; | ||
|
||
-- Snowpipe spend | ||
-- this query finds tables where the snowpipe spend has gone over 10 credits in the past 12 hours | ||
WITH pipe_spend AS ( | ||
SELECT | ||
pipe_id, | ||
pipe_name, | ||
SUM(credits_used) AS credits_used | ||
FROM snowflake.account_usage.pipe_usage_history | ||
WHERE DATEDIFF(HOUR, end_time, CURRENT_TIMESTAMP) < 12 | ||
GROUP BY 1, 2 | ||
ORDER BY 3 DESC | ||
) | ||
SELECT * | ||
FROM pipe_spend | ||
WHERE credits_used > 10 | ||
; | ||
|
||
-- Warehouse Spending Spike | ||
-- this query compares the last day credit spend vs. the last 28 day average for the account | ||
WITH average_use AS ( | ||
SELECT | ||
warehouse_id, | ||
warehouse_name, | ||
SUM(credits_used) AS total_credits_used, | ||
SUM(credits_used) / 28 AS avg_credits_used | ||
FROM snowflake.account_usage.warehouse_metering_history | ||
WHERE DATEDIFF(DAY, start_time, CURRENT_TIMESTAMP) < 28 | ||
GROUP BY 1, 2 | ||
) | ||
SELECT | ||
w.warehouse_id, | ||
w.warehouse_name, | ||
SUM(w.credits_used) AS ld_credits_used, | ||
a.avg_credits_used | ||
FROM snowflake.account_usage.warehouse_metering_history w | ||
JOIN average_use a | ||
ON w.warehouse_id = a.warehouse_id | ||
WHERE DATEDIFF(DAY, start_time, CURRENT_TIMESTAMP) < 2 | ||
GROUP BY 1, 2, 4 | ||
HAVING ld_credits_used > (a.avg_credits_used * 2) | ||
; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,108 @@ | ||
-- Too many bad logins by a single IP | ||
WITH ip_login_fails AS ( | ||
SELECT | ||
client_ip, | ||
reported_client_type, | ||
ARRAY_AGG(DISTINCT error_code), | ||
ARRAY_AGG(DISTINCT error_message), | ||
COUNT(event_id) AS counts | ||
FROM account_usage.login_history | ||
WHERE DATEDIFF(HOUR, event_timestamp, CURRENT_TIMESTAMP) < 24 | ||
AND error_code IS NOT NULL | ||
GROUP BY client_ip, reported_client_type | ||
) | ||
SELECT * | ||
FROM ip_login_fails | ||
WHERE counts > 5 | ||
; | ||
|
||
-- Too many bad logins by a single User | ||
WITH user_login_fails AS ( | ||
SELECT | ||
user_name, | ||
reported_client_type, | ||
ARRAY_AGG(DISTINCT error_code), | ||
ARRAY_AGG(DISTINCT error_message), | ||
COUNT(event_id) AS counts | ||
FROM account_usage.login_history | ||
WHERE DATEDIFF(HOUR, event_timestamp, CURRENT_TIMESTAMP) < 12 | ||
AND error_code IS NOT NULL | ||
GROUP BY user_name, reported_client_type | ||
) | ||
SELECT * | ||
FROM user_login_fails | ||
WHERE counts > 3 | ||
; | ||
|
||
-- Modifications to sensitive roles | ||
SELECT | ||
query_id, | ||
query_text, | ||
user_name, | ||
role_name, | ||
start_time | ||
FROM snowflake.account_usage.query_history | ||
WHERE QUERY_TYPE = 'ALTER_USER' | ||
and QUERY_TEXT ilike '%ADMIN%' | ||
; | ||
|
||
-- Password changes | ||
SELECT | ||
query_id, | ||
query_text, | ||
user_name, | ||
role_name, | ||
start_time | ||
FROM snowflake.account_usage.query_history | ||
WHERE query_type = 'ALTER_USER' | ||
AND query_text ILIKE '%password%' | ||
; | ||
|
||
-- New Users Created | ||
SELECT | ||
query_id, | ||
query_text, | ||
user_name, | ||
role_name, | ||
start_time | ||
FROM snowflake.account_usage.query_history | ||
WHERE query_type = 'CREATE_USER' | ||
; | ||
|
||
-- User not using Multi Factor Authentication | ||
SELECT | ||
event_timestamp, | ||
user_name, | ||
client_IP, | ||
reported_client_type, | ||
first_authentication_factor, | ||
second_authentication_factor | ||
FROM snowflake.account_usage.login_history | ||
WHERE second_authentication_factor IS NULL | ||
AND ( | ||
reported_client_type = 'SNOWFLAKE_UI' | ||
OR reported_client_type = 'OTHER' | ||
) | ||
; | ||
|
||
-- Suspicious increase in queries by a user | ||
WITH average_queries AS ( | ||
SELECT | ||
user_name, | ||
COUNT(query_id) AS total_queries, | ||
COUNT(query_id) / 28 AS avg_queries | ||
FROM snowflake.account_usage.query_history | ||
WHERE DATEDIFF(DAY, start_time, CURRENT_TIMESTAMP) < 28 | ||
GROUP BY 1 | ||
) | ||
SELECT | ||
w.user_name, | ||
SUM(w.query_id) AS ld_queries, | ||
a.avg_queries | ||
FROM snowflake.account_usage.query_history w | ||
JOIN average_queries a | ||
ON w.user_name = a.user_name | ||
WHERE DATEDIFF(DAY, start_time, CURRENT_TIMESTAMP) < 2 | ||
GROUP BY 1,3 | ||
HAVING ld_queries > (a.avg_queries * 10) | ||
; |