You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
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]>
-- 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
+
CREATEUNIQUE INDEXpolicies_null1ON policies (kind, api_group, name, parent_policy_id, spec_hash, severity) WHERE namespace IS NULL;
55
+
CREATEUNIQUE INDEXpolicies_null2ON policies (kind, api_group, name, namespace, spec_hash, severity) WHERE parent_policy_id IS NULL;
56
+
CREATEUNIQUE INDEXpolicies_null3ON 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
+
CREATEUNIQUE INDEXpolicies_null4ON policies (kind, api_group, name, spec_hash, severity) WHERE namespace IS NULLAND parent_policy_id IS NULL;
60
+
CREATEUNIQUE INDEXpolicies_null5ON policies (kind, api_group, name, parent_policy_id, spec_hash) WHERE namespace IS NULLAND severity IS NULL;
61
+
CREATEUNIQUE INDEXpolicies_null6ON policies (kind, api_group, name, namespace, spec_hash) WHERE parent_policy_id IS NULLAND severity IS NULL;
62
+
63
+
-- Partial index with no null unique fields provided (e.g. ABC)
64
+
CREATEUNIQUE INDEXpolicies_null7ON policies (kind, api_group, name, spec_hash) WHERE namespace IS NULLAND parent_policy_id IS NULLAND severity IS NULL;
65
+
38
66
CREATEINDEXIF NOT EXISTS idx_policies_spec_hash ON policies (spec_hash);
0 commit comments