turbot/oci_compliance

Query: core_network_security_group_restrict_ingress_ssh_all

Usage

powerpipe query oci_compliance.query.core_network_security_group_restrict_ingress_ssh_all

SQL

with non_compliant_rules as (
select
id,
count(*) as num_noncompliant_rules
from
oci_core_network_security_group,
jsonb_array_elements(rules) as r
where
r ->> 'direction' = 'INGRESS'
and r ->> 'sourceType' = 'CIDR_BLOCK'
and r ->> 'source' = '0.0.0.0/0'
and (
r ->> 'protocol' = 'all'
or (
(r -> 'tcpOptions' -> 'destinationPortRange' ->> 'min') :: integer <= 22
and (r -> 'tcpOptions' -> 'destinationPortRange' ->> 'max') :: integer >= 22
)
)
group by
id
)
select
nsg.id as resource,
case
when non_compliant_rules.id is null then 'ok'
else 'alarm'
end as status,
case
when non_compliant_rules.id is null then nsg.display_name || ' ingress restricted for SSH from 0.0.0.0/0.'
else nsg.display_name || ' contains ' || non_compliant_rules.num_noncompliant_rules || ' ingress rule(s) allowing SSH from 0.0.0.0/0.'
end as reason,
nsg.region as region,
nsg.tenant_name as tenant,
coalesce(c.name, 'root') as compartment
from
oci_core_network_security_group as nsg
left join non_compliant_rules on non_compliant_rules.id = nsg.id
left join oci_identity_compartment c on c.id = nsg.compartment_id;

Controls

The query is being used by the following controls: