Skip to content

Commit b8f1237

Browse files
mprahlopenshift-merge-bot[bot]
authored andcommitted
Add partial indexes to account for null values
In Postgres 15+, NULLS NOT DISTINCT is supported so that a null value in the same column is seen as the same value. This is not standard SQL and Postgres 15 is likely too new to require. This is a workaround to include partial indexes when some null values are provided. Signed-off-by: mprahl <[email protected]>
1 parent 6304ef9 commit b8f1237

File tree

1 file changed

+28
-0
lines changed

1 file changed

+28
-0
lines changed

controllers/complianceeventsapi/migrations/000001_compliance_history_initial_tables.up.sql

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -18,6 +18,20 @@ CREATE TABLE IF NOT EXISTS parent_policies(
1818
UNIQUE (name, categories, controls, standards)
1919
);
2020

21+
-- This is required until we only support Postgres 15+ to utilize NULLS NOT DISTINCT.
22+
-- Partial indexes with 1 null unique field provided (e.g. A, B, C)
23+
CREATE UNIQUE INDEX parent_policies_null1 ON parent_policies (name, controls, standards) WHERE categories IS NULL;
24+
CREATE UNIQUE INDEX parent_policies_null2 ON parent_policies (name, categories, standards) WHERE controls IS NULL;
25+
CREATE UNIQUE INDEX parent_policies_null3 ON parent_policies (name, categories, controls) WHERE standards IS NULL;
26+
27+
-- Partial indexes with 2 null unique field provided (e.g. AB AC BC)
28+
CREATE UNIQUE INDEX parent_policies_null4 ON parent_policies (name, standards) WHERE categories IS NULL AND controls IS NULL;
29+
CREATE UNIQUE INDEX parent_policies_null5 ON parent_policies (name, controls) WHERE categories IS NULL AND standards IS NULL;
30+
CREATE UNIQUE INDEX parent_policies_null6 ON parent_policies (name, categories) WHERE controls IS NULL AND standards IS NULL;
31+
32+
-- Partial index with no null unique fields provided (e.g. ABC)
33+
CREATE UNIQUE INDEX parent_policies_null7 ON parent_policies (name) WHERE categories IS NULL AND controls IS NULL AND standards IS NULL;
34+
2135
CREATE TABLE IF NOT EXISTS policies(
2236
id serial PRIMARY KEY,
2337
kind TEXT NOT NULL,
@@ -35,6 +49,20 @@ CREATE TABLE IF NOT EXISTS policies(
3549
UNIQUE (kind, api_group, name, namespace, parent_policy_id, spec_hash, severity)
3650
);
3751

52+
-- This is required until we only support Postgres 15+ to utilize NULLS NOT DISTINCT.
53+
-- Partial indexes with 1 null unique field provided (e.g. A, B, C)
54+
CREATE UNIQUE INDEX policies_null1 ON policies (kind, api_group, name, parent_policy_id, spec_hash, severity) WHERE namespace IS NULL;
55+
CREATE UNIQUE INDEX policies_null2 ON policies (kind, api_group, name, namespace, spec_hash, severity) WHERE parent_policy_id IS NULL;
56+
CREATE UNIQUE INDEX policies_null3 ON policies (kind, api_group, name, namespace, parent_policy_id, spec_hash) WHERE severity IS NULL;
57+
58+
-- Partial indexes with 2 null unique field provided (e.g. AB AC BC)
59+
CREATE UNIQUE INDEX policies_null4 ON policies (kind, api_group, name, spec_hash, severity) WHERE namespace IS NULL AND parent_policy_id IS NULL;
60+
CREATE UNIQUE INDEX policies_null5 ON policies (kind, api_group, name, parent_policy_id, spec_hash) WHERE namespace IS NULL AND severity IS NULL;
61+
CREATE UNIQUE INDEX policies_null6 ON policies (kind, api_group, name, namespace, spec_hash) WHERE parent_policy_id IS NULL AND severity IS NULL;
62+
63+
-- Partial index with no null unique fields provided (e.g. ABC)
64+
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;
65+
3866
CREATE INDEX IF NOT EXISTS idx_policies_spec_hash ON policies (spec_hash);
3967

4068
CREATE TABLE IF NOT EXISTS compliance_events(

0 commit comments

Comments
 (0)