Skip to content

Instantly share code, notes, and snippets.

@titan-teej
Last active June 3, 2024 19:24
Show Gist options
  • Save titan-teej/924dcb42604a98b90d641926271831b3 to your computer and use it in GitHub Desktop.
Save titan-teej/924dcb42604a98b90d641926271831b3 to your computer and use it in GitHub Desktop.
Audits your Snowflake account to show which users have privileged access
USE ROLE ACCOUNTADMIN;
USE WAREHOUSE <warehouse_name>;
WITH privileged_users_check AS PROCEDURE()
RETURNS TABLE()
LANGUAGE PYTHON
RUNTIME_VERSION = '3.9'
PACKAGES = ('snowflake-snowpark-python')
HANDLER = 'main'
EXECUTE AS CALLER
AS $$
# =============================================================================
# Copyright (C) 2024 Titan Systems, Inc
#
# This script is open source and available under the MIT License.
# You may use, distribute, and modify this code under the terms of the MIT License.
#
# Permission is hereby granted, free of charge, to any person obtaining a copy
# of this software and associated documentation files (the "Software"), to deal
# in the Software without restriction, including without limitation the rights
# to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
# copies of the Software, and to permit persons to whom the Software is
# furnished to do so, subject to the following conditions:
#
# The above copyright notice and this permission notice shall be included in all
# copies or substantial portions of the Software.
#
# THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
# IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
# FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
# AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
# LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
# OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE
# SOFTWARE.
# =============================================================================
from snowflake.snowpark import Row
from snowflake.snowpark.functions import array_agg, col
def main(session):
roles_with_manage_grants = session.sql("SHOW GRANTS ON ACCOUNT")\
.filter(col('"privilege"') == "MANAGE GRANTS")\
.select(col('"grantee_name"'))\
.distinct()\
.collect()
privileged_roles = list(set(["SECURITYADMIN", "ACCOUNTADMIN"] + [str(role.grantee_name) for role in roles_with_manage_grants]))
privileged_roles = [(role, f"Has MANAGE GRANTS rights via {role} role.") for role in privileged_roles]
privileged_users = []
while privileged_roles:
(role, reason) = privileged_roles.pop(0)
for role_grant in session.sql(f'SHOW GRANTS OF ROLE "{role}"').collect():
if role_grant.granted_to == "USER":
privileged_users.append(Row(name=role_grant.grantee_name, reason=reason))
if role_grant.granted_to == "ROLE":
privileged_roles.append((role_grant.grantee_name, f"Can escalate to gain MANAGE GRANTS rights through {role_grant.grantee_name} -> {role_grant.role}"))
privileged_users = session.create_dataframe(privileged_users)\
.group_by(col("name"))\
.agg(array_agg("reason", True).alias("privileged_access"))
auth_factor = session.sql("""
SELECT
DISTINCT user_name as name
, first_value(first_authentication_factor)
OVER (
PARTITION BY user_name
ORDER BY event_timestamp DESC)
AS most_recent_auth_factor
FROM snowflake.account_usage.login_history
""")
all_users = session.sql("SHOW USERS")\
.filter(col('"ext_authn_duo"') == "false")\
.select([col(f'"{c}"').alias(c) for c in ['name', 'has_password', 'disabled', 'last_success_login']])
return all_users\
.join(privileged_users, on="name", how="left")\
.join(auth_factor, on="name", how="left")\
.sort(col('privileged_access'), ascending=False)\
.sort(col('disabled'), ascending=True)
$$
CALL privileged_users_check()
;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment