From 90a1f266e6a19290d32f241e6bd40646957c9961 Mon Sep 17 00:00:00 2001 From: ronsh12 <101520407+ronsh12@users.noreply.github.com> Date: Tue, 12 Dec 2023 17:10:50 +0200 Subject: [PATCH] feat: Added queries for free AWS Compliance - Snowflake (#410) --- ...ompliance__api_gateway_method_settings.sql | 1 + ...> aws_compliance__pci_dss_v3_2_1_free.sql} | 0 .../autoscaling_groups_elb_check.sql | 14 ++++++ .../log_file_validation_enabled.sql | 14 ++++++ .../aws/macros/iam/avoid_root_usage.sql | 15 +++++++ .../aws/macros/iam/old_access_keys.sql | 15 +++++++ .../iam/password_policy_min_lowercase.sql | 16 +++++++ .../iam/password_policy_min_uppercase.sql | 16 +++++++ .../aws/macros/iam/unused_creds_disabled.sql | 17 ++++++++ .../macros/log_metric_filter_and_alarm.sql | 38 ++++++++++++++++ .../macros/networks_acls_ingress_rules.sql | 43 +++++++++++++++++++ .../macros/security_group_egress_rules.sql | 41 ++++++++++++++++++ ...ompliance__networks_acls_ingress_rules.sql | 19 +++----- ...ompliance__security_group_egress_rules.sql | 20 +++------ 14 files changed, 240 insertions(+), 29 deletions(-) create mode 100644 transformations/aws/compliance-free/models/aws_compliance__api_gateway_method_settings.sql rename transformations/aws/compliance-free/models/{aws_compliance__pci_dss_v3.2.1_free.sql => aws_compliance__pci_dss_v3_2_1_free.sql} (100%) create mode 100644 transformations/aws/macros/networks_acls_ingress_rules.sql create mode 100644 transformations/aws/macros/security_group_egress_rules.sql diff --git a/transformations/aws/compliance-free/models/aws_compliance__api_gateway_method_settings.sql b/transformations/aws/compliance-free/models/aws_compliance__api_gateway_method_settings.sql new file mode 100644 index 000000000..579e5c7c6 --- /dev/null +++ b/transformations/aws/compliance-free/models/aws_compliance__api_gateway_method_settings.sql @@ -0,0 +1 @@ +{{ api_gateway_method_settings() }} \ No newline at end of file diff --git a/transformations/aws/compliance-free/models/aws_compliance__pci_dss_v3.2.1_free.sql b/transformations/aws/compliance-free/models/aws_compliance__pci_dss_v3_2_1_free.sql similarity index 100% rename from transformations/aws/compliance-free/models/aws_compliance__pci_dss_v3.2.1_free.sql rename to transformations/aws/compliance-free/models/aws_compliance__pci_dss_v3_2_1_free.sql diff --git a/transformations/aws/macros/autoscaling/autoscaling_groups_elb_check.sql b/transformations/aws/macros/autoscaling/autoscaling_groups_elb_check.sql index 23192e190..9c4f57976 100644 --- a/transformations/aws/macros/autoscaling/autoscaling_groups_elb_check.sql +++ b/transformations/aws/macros/autoscaling/autoscaling_groups_elb_check.sql @@ -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 %} diff --git a/transformations/aws/macros/cloudtrail/log_file_validation_enabled.sql b/transformations/aws/macros/cloudtrail/log_file_validation_enabled.sql index 0514239aa..bb8819634 100644 --- a/transformations/aws/macros/cloudtrail/log_file_validation_enabled.sql +++ b/transformations/aws/macros/cloudtrail/log_file_validation_enabled.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/iam/avoid_root_usage.sql b/transformations/aws/macros/iam/avoid_root_usage.sql index 3cb65e063..76de91b58 100644 --- a/transformations/aws/macros/iam/avoid_root_usage.sql +++ b/transformations/aws/macros/iam/avoid_root_usage.sql @@ -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 = '' AND password_last_used > CURRENT_TIMESTAMP() - INTERVAL '30 DAY' + then 'fail' + else 'pass' + end as status +from aws_iam_users {% endmacro %} \ No newline at end of file diff --git a/transformations/aws/macros/iam/old_access_keys.sql b/transformations/aws/macros/iam/old_access_keys.sql index 3b4a2af51..7015f9145 100644 --- a/transformations/aws/macros/iam/old_access_keys.sql +++ b/transformations/aws/macros/iam/old_access_keys.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/iam/password_policy_min_lowercase.sql b/transformations/aws/macros/iam/password_policy_min_lowercase.sql index 8cfd35f92..5cc8e96e0 100644 --- a/transformations/aws/macros/iam/password_policy_min_lowercase.sql +++ b/transformations/aws/macros/iam/password_policy_min_lowercase.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/iam/password_policy_min_uppercase.sql b/transformations/aws/macros/iam/password_policy_min_uppercase.sql index ab54a0527..a07f55219 100644 --- a/transformations/aws/macros/iam/password_policy_min_uppercase.sql +++ b/transformations/aws/macros/iam/password_policy_min_uppercase.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/iam/unused_creds_disabled.sql b/transformations/aws/macros/iam/unused_creds_disabled.sql index 30b1487bf..a024b90e8 100644 --- a/transformations/aws/macros/iam/unused_creds_disabled.sql +++ b/transformations/aws/macros/iam/unused_creds_disabled.sql @@ -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 %} diff --git a/transformations/aws/macros/log_metric_filter_and_alarm.sql b/transformations/aws/macros/log_metric_filter_and_alarm.sql index 1e8b4d729..93574864f 100644 --- a/transformations/aws/macros/log_metric_filter_and_alarm.sql +++ b/transformations/aws/macros/log_metric_filter_and_alarm.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/networks_acls_ingress_rules.sql b/transformations/aws/macros/networks_acls_ingress_rules.sql new file mode 100644 index 000000000..7baee2446 --- /dev/null +++ b/transformations/aws/macros/networks_acls_ingress_rules.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/macros/security_group_egress_rules.sql b/transformations/aws/macros/security_group_egress_rules.sql new file mode 100644 index 000000000..1f37a953d --- /dev/null +++ b/transformations/aws/macros/security_group_egress_rules.sql @@ -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 %} \ No newline at end of file diff --git a/transformations/aws/models/aws_compliance__networks_acls_ingress_rules.sql b/transformations/aws/models/aws_compliance__networks_acls_ingress_rules.sql index 21bea671a..0642eee7a 100644 --- a/transformations/aws/models/aws_compliance__networks_acls_ingress_rules.sql +++ b/transformations/aws/models/aws_compliance__networks_acls_ingress_rules.sql @@ -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 diff --git a/transformations/aws/models/aws_compliance__security_group_egress_rules.sql b/transformations/aws/models/aws_compliance__security_group_egress_rules.sql index a1c0eda5f..ed4cf6a07 100644 --- a/transformations/aws/models/aws_compliance__security_group_egress_rules.sql +++ b/transformations/aws/models/aws_compliance__security_group_egress_rules.sql @@ -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 \ No newline at end of file