diff --git a/build/kind/postgres.yaml b/build/kind/postgres.yaml index 59a45ab1..9dd78516 100644 --- a/build/kind/postgres.yaml +++ b/build/kind/postgres.yaml @@ -68,6 +68,10 @@ spec: - ssl_key_file=/var/lib/postgresql/tls/tls.key - -c - ssl_ca_file=/var/lib/postgresql/tls/ca.crt + - -c + - log_statement=all + - -c + - log_destination=stderr # This is a mirror of postgres:13 on Docker Hub to avoid rate limits. image: quay.io/stolostron/grc-ci-postgres:13 imagePullPolicy: "IfNotPresent" diff --git a/controllers/complianceeventsapi/migrations/000001_compliance_history_initial_tables.up.sql b/controllers/complianceeventsapi/migrations/000001_compliance_history_initial_tables.up.sql index c4e5c937..f2dd1e88 100644 --- a/controllers/complianceeventsapi/migrations/000001_compliance_history_initial_tables.up.sql +++ b/controllers/complianceeventsapi/migrations/000001_compliance_history_initial_tables.up.sql @@ -18,6 +18,20 @@ CREATE TABLE IF NOT EXISTS parent_policies( UNIQUE (name, categories, controls, standards) ); +-- This is required until we only support Postgres 15+ to utilize NULLS NOT DISTINCT. +-- Partial indexes with 1 null unique field provided (e.g. A, B, C) +CREATE UNIQUE INDEX parent_policies_null1 ON parent_policies (name, controls, standards) WHERE categories IS NULL; +CREATE UNIQUE INDEX parent_policies_null2 ON parent_policies (name, categories, standards) WHERE controls IS NULL; +CREATE UNIQUE INDEX parent_policies_null3 ON parent_policies (name, categories, controls) WHERE standards IS NULL; + +-- Partial indexes with 2 null unique field provided (e.g. AB AC BC) +CREATE UNIQUE INDEX parent_policies_null4 ON parent_policies (name, standards) WHERE categories IS NULL AND controls IS NULL; +CREATE UNIQUE INDEX parent_policies_null5 ON parent_policies (name, controls) WHERE categories IS NULL AND standards IS NULL; +CREATE UNIQUE INDEX parent_policies_null6 ON parent_policies (name, categories) WHERE controls IS NULL AND standards IS NULL; + +-- Partial index with no null unique fields provided (e.g. ABC) +CREATE UNIQUE INDEX parent_policies_null7 ON parent_policies (name) WHERE categories IS NULL AND controls IS NULL AND standards IS NULL; + CREATE TABLE IF NOT EXISTS policies( id serial PRIMARY KEY, kind TEXT NOT NULL, @@ -35,6 +49,20 @@ CREATE TABLE IF NOT EXISTS policies( UNIQUE (kind, api_group, name, namespace, parent_policy_id, spec_hash, severity) ); +-- This is required until we only support Postgres 15+ to utilize NULLS NOT DISTINCT. +-- Partial indexes with 1 null unique field provided (e.g. A, B, C) +CREATE UNIQUE INDEX policies_null1 ON policies (kind, api_group, name, parent_policy_id, spec_hash, severity) WHERE namespace IS NULL; +CREATE UNIQUE INDEX policies_null2 ON policies (kind, api_group, name, namespace, spec_hash, severity) WHERE parent_policy_id IS NULL; +CREATE UNIQUE INDEX policies_null3 ON policies (kind, api_group, name, namespace, parent_policy_id, spec_hash) WHERE severity IS NULL; + +-- Partial indexes with 2 null unique field provided (e.g. AB AC BC) +CREATE UNIQUE INDEX policies_null4 ON policies (kind, api_group, name, spec_hash, severity) WHERE namespace IS NULL AND parent_policy_id IS NULL; +CREATE UNIQUE INDEX policies_null5 ON policies (kind, api_group, name, parent_policy_id, spec_hash) WHERE namespace IS NULL AND severity IS NULL; +CREATE UNIQUE INDEX policies_null6 ON policies (kind, api_group, name, namespace, spec_hash) WHERE parent_policy_id IS NULL AND severity IS NULL; + +-- Partial index with no null unique fields provided (e.g. ABC) +CREATE UNIQUE INDEX policies_null7 ON policies (kind, api_group, name, spec_hash) WHERE namespace IS NULL AND parent_policy_id IS NULL AND severity IS NULL; + CREATE INDEX IF NOT EXISTS idx_policies_spec_hash ON policies (spec_hash); CREATE TABLE IF NOT EXISTS compliance_events(