Skip to content

Commit

Permalink
feat: Added queries for free AWS Compliance - Snowflake (#410)
Browse files Browse the repository at this point in the history
  • Loading branch information
ronsh12 authored Dec 12, 2023
1 parent 82cc595 commit 90a1f26
Show file tree
Hide file tree
Showing 14 changed files with 240 additions and 29 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
{{ api_gateway_method_settings() }}
Original file line number Diff line number Diff line change
Expand Up @@ -17,3 +17,17 @@ select
end as status
from aws_autoscaling_groups
{% endmacro %}

{% macro snowflake__autoscaling_groups_elb_check(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Auto Scaling groups associated with a load balancer should use health checks' as title,
account_id,
arn as resource_id,
case
when ARRAY_SIZE(load_balancer_names) > 0 and health_check_type is distinct from 'ELB' then 'fail'
else 'pass'
end as status
from aws_autoscaling_groups
{% endmacro %}
Original file line number Diff line number Diff line change
Expand Up @@ -31,3 +31,17 @@ select
end as status
from {{ full_table_name("aws_cloudtrail_trails") }}
{% endmacro %}

{% macro snowflake__log_file_validation_enabled(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Ensure CloudTrail log file validation is enabled' as title,
account_id,
arn as resource_id,
case
when log_file_validation_enabled = false then 'fail'
else 'pass'
end as status
from aws_cloudtrail_trails
{% endmacro %}
15 changes: 15 additions & 0 deletions transformations/aws/macros/iam/avoid_root_usage.sql
Original file line number Diff line number Diff line change
Expand Up @@ -32,4 +32,19 @@ select
else 'pass'
end as status
from {{ full_table_name("aws_iam_users") }}
{% endmacro %}

{% macro snowflake__avoid_root_usage(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Avoid the use of "root" account. Show used in last 30 days (Scored)' as title,
account_id,
arn as resource_id,
case when
user_name = '<root_account>' AND password_last_used > CURRENT_TIMESTAMP() - INTERVAL '30 DAY'
then 'fail'
else 'pass'
end as status
from aws_iam_users
{% endmacro %}
15 changes: 15 additions & 0 deletions transformations/aws/macros/iam/old_access_keys.sql
Original file line number Diff line number Diff line change
Expand Up @@ -32,4 +32,19 @@ select
else 'pass'
end
from {{ full_table_name("aws_iam_user_access_keys") }}
{% endmacro %}

{% macro snowflake__old_access_keys(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Ensure access keys are rotated every 90 days or less' as title,
account_id,
user_arn,
case when
last_rotated < (CURRENT_TIMESTAMP() - INTERVAL '90 DAY')
then 'fail'
else 'pass'
end
from aws_iam_user_access_keys
{% endmacro %}
16 changes: 16 additions & 0 deletions transformations/aws/macros/iam/password_policy_min_lowercase.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,4 +35,20 @@ select
end as status
from
{{ full_table_name("aws_iam_password_policies") }}
{% endmacro %}

{% macro snowflake__password_policy_min_lowercase(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Ensure IAM password policy requires at least one lowercase letter' as title,
account_id,
account_id,
case when
require_lowercase_characters = false or policy_exists = false
then 'fail'
else 'pass'
end as status
from
aws_iam_password_policies
{% endmacro %}
16 changes: 16 additions & 0 deletions transformations/aws/macros/iam/password_policy_min_uppercase.sql
Original file line number Diff line number Diff line change
Expand Up @@ -35,3 +35,19 @@ select
from
{{ full_table_name("aws_iam_password_policies") }}
{% endmacro %}

{% macro snowflake__password_policy_min_uppercase(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Ensure IAM password policy requires at least one uppercase letter' as title,
account_id,
account_id,
case when
not require_uppercase_characters or not policy_exists
then 'fail'
else 'pass'
end
from
aws_iam_password_policies
{% endmacro %}
17 changes: 17 additions & 0 deletions transformations/aws/macros/iam/unused_creds_disabled.sql
Original file line number Diff line number Diff line change
Expand Up @@ -37,3 +37,20 @@ select
from {{ full_table_name("aws_iam_credential_reports") }} r
left join {{ full_table_name("aws_iam_user_access_keys") }} k on k.user_arn = r.arn
{% endmacro %}

{% macro snowflake__unused_creds_disabled(framework, check_id) %}
select
'{{framework}}' as framework,
'{{check_id}}' as check_id,
'Ensure credentials unused for 90 days or greater are disabled (Scored)' as title,
split_part(r.arn, ':', 5) as account_id,
r.arn,
case when
(r.password_status IN ('TRUE', 'true') and r.password_last_used < (CURRENT_TIMESTAMP() - INTERVAL '90 DAY')
or (k.last_used < (CURRENT_TIMESTAMP() - INTERVAL '90 DAY')))
then 'fail'
else 'pass'
end
from aws_iam_credential_reports r
left join aws_iam_user_access_keys k on k.user_arn = r.arn
{% endmacro %}
38 changes: 38 additions & 0 deletions transformations/aws/macros/log_metric_filter_and_alarm.sql
Original file line number Diff line number Diff line change
Expand Up @@ -47,3 +47,41 @@ where t.is_multi_region_trail = TRUE
and tes.read_write_type = 'All'
and ss.arn like 'aws:arn:%'
{% endmacro %}

{% macro snowflake__log_metric_filter_and_alarm() %}
WITH af AS (
SELECT DISTINCT
a.arn,
a.actions_enabled,
a.alarm_actions,
m.value:MetricStat:Metric:MetricName AS metric_name
FROM aws_cloudwatch_alarms a,
LATERAL FLATTEN(input => a.metrics) AS m
)

SELECT
t.account_id,
t.region,
t.cloud_watch_logs_log_group_arn,
mf.filter_pattern AS pattern
FROM
aws_cloudtrail_trails t
INNER JOIN
aws_cloudtrail_trail_event_selectors tes ON t.arn = tes.trail_arn
INNER JOIN
aws_cloudwatchlogs_metric_filters mf ON mf.log_group_name = t.cloudwatch_logs_log_group_name
INNER JOIN
af ON mf.filter_name = af.metric_name
INNER JOIN LATERAL (
SELECT arn, topic_arn
FROM aws_sns_subscriptions ss
WHERE ARRAY_CONTAINS(ss.topic_arn::variant, af.alarm_actions)
LIMIT 1
) ss ON TRUE
WHERE
t.is_multi_region_trail = TRUE
AND (t.status:IsLogging)::BOOLEAN = TRUE
AND tes.include_management_events = TRUE
AND tes.read_write_type = 'All'
AND ss.arn LIKE 'aws:arn:%'
{% endmacro %}
43 changes: 43 additions & 0 deletions transformations/aws/macros/networks_acls_ingress_rules.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,43 @@
{% macro networks_acls_ingress_rules(framework, check_id) %}
{{ return(adapter.dispatch('networks_acls_ingress_rules')()) }}
{% endmacro %}

{% macro default__networks_acls_ingress_rules() %}{% endmacro %}

{% macro postgres__networks_acls_ingress_rules() %}
WITH rules AS (SELECT aena.arn,
aena.account_id,
(jsonb_array_elements(entries) -> 'PortRange' ->> 'From')::int AS port_range_from,
(jsonb_array_elements(entries) -> 'PortRange' ->> 'To')::int AS port_range_to,
jsonb_array_elements(entries) ->> 'Protocol' AS protocol,
jsonb_array_elements(entries) ->> 'CidrBlock' AS cidr_block,
jsonb_array_elements(entries) ->> 'Ipv6CidrBlock' AS ipv6_cidr_block,
jsonb_array_elements(entries) ->> 'Egress' AS egress,
jsonb_array_elements(entries) ->> 'RuleAction' AS rule_action
FROM aws_ec2_network_acls aena)
SELECT arn, account_id, port_range_from, port_range_to, protocol, cidr_block, ipv6_cidr_block
FROM rules
WHERE egress IS DISTINCT FROM 'true'
AND rule_action = 'allow'
{% endmacro %}

{% macro snowflake__networks_acls_ingress_rules() %}
WITH rules AS (
SELECT
aena.arn,
aena.account_id,
(v.value:PortRange:From)::int as port_range_from,
(v.value:PortRange:To)::int as port_range_to,
v.value:Protocol as protocol,
v.value:CidrBlock as cidr_block,
v.value:Ipv6CidrBlock as ipv6_cidr_block,
v.value:Egress as egress,
v.value:RuleAction as rule_action
FROM aws_ec2_network_acls aena,
LATERAL FLATTEN(ENTRIES) v
)
SELECT arn, account_id, port_range_from, port_range_to, protocol, cidr_block, ipv6_cidr_block
FROM rules
WHERE egress IS DISTINCT FROM 'true'
AND rule_action = 'allow'
{% endmacro %}
41 changes: 41 additions & 0 deletions transformations/aws/macros/security_group_egress_rules.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
{% macro security_group_egress_rules(framework, check_id) %}
{{ return(adapter.dispatch('security_group_egress_rules')()) }}
{% endmacro %}

{% macro default__security_group_egress_rules() %}{% endmacro %}

{% macro postgres__security_group_egress_rules() %}
select
account_id,
region,
group_name,
arn,
group_id as id,
vpc_id,
(i->>'FromPort')::integer AS from_port,
(i->>'ToPort')::integer AS to_port,
i->>'IpProtocol' AS ip_protocol,
ip_ranges->>'CidrIp' AS ip,
ip6_ranges->>'CidrIpv6' AS ip6
from aws_ec2_security_groups, JSONB_ARRAY_ELEMENTS(aws_ec2_security_groups.ip_permissions_egress) as i
LEFT JOIN JSONB_ARRAY_ELEMENTS(i->'IpRanges') as ip_ranges ON true
LEFT JOIN JSONB_ARRAY_ELEMENTS(i->'Ipv6Ranges') as ip6_ranges ON true
{% endmacro %}

{% macro snowflake__security_group_egress_rules() %}
select
account_id,
region,
group_name,
arn,
group_id as id,
vpc_id,
i.value:FromPort::number AS from_port,
i.value:ToPort::number AS to_port,
i.value:IpProtocol AS ip_protocol,
ip_ranges.value:CidrIp AS ip,
ip6_ranges.value:CidrIpv6 AS ip6
from aws_ec2_security_groups, lateral flatten(input => parse_json(aws_ec2_security_groups.ip_permissions_egress)) as i,
lateral flatten(input => i.value:IpRanges, OUTER => TRUE) as ip_ranges,
lateral flatten(input => i.value:Ipv6Ranges, OUTER => TRUE) as ip6_ranges
{% endmacro %}
Original file line number Diff line number Diff line change
@@ -1,14 +1,5 @@
WITH rules AS (SELECT aena.arn,
aena.account_id,
(jsonb_array_elements(entries) -> 'PortRange' ->> 'From')::int AS port_range_from,
(jsonb_array_elements(entries) -> 'PortRange' ->> 'To')::int AS port_range_to,
jsonb_array_elements(entries) ->> 'Protocol' AS protocol,
jsonb_array_elements(entries) ->> 'CidrBlock' AS cidr_block,
jsonb_array_elements(entries) ->> 'Ipv6CidrBlock' AS ipv6_cidr_block,
jsonb_array_elements(entries) ->> 'Egress' AS egress,
jsonb_array_elements(entries) ->> 'RuleAction' AS rule_action
FROM aws_ec2_network_acls aena)
SELECT arn, account_id, port_range_from, port_range_to, protocol, cidr_block, ipv6_cidr_block
FROM rules
WHERE egress IS DISTINCT FROM 'true'
AND rule_action = 'allow'
with
aggregated as (
({{ networks_acls_ingress_rules() }})
)
select * from aggregated
Original file line number Diff line number Diff line change
@@ -1,15 +1,5 @@
select
account_id,
region,
group_name,
arn,
group_id as id,
vpc_id,
(i->>'FromPort')::integer AS from_port,
(i->>'ToPort')::integer AS to_port,
i->>'IpProtocol' AS ip_protocol,
ip_ranges->>'CidrIp' AS ip,
ip6_ranges->>'CidrIpv6' AS ip6
from aws_ec2_security_groups, JSONB_ARRAY_ELEMENTS(aws_ec2_security_groups.ip_permissions_egress) as i
LEFT JOIN JSONB_ARRAY_ELEMENTS(i->'IpRanges') as ip_ranges ON true
LEFT JOIN JSONB_ARRAY_ELEMENTS(i->'Ipv6Ranges') as ip6_ranges ON true
with
aggregated as (
({{ security_group_egress_rules() }})
)
select * from aggregated

0 comments on commit 90a1f26

Please sign in to comment.