Skip to content

Add partial indexes to account for null values #155

New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Merged
merged 2 commits into from
Dec 19, 2023
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
4 changes: 4 additions & 0 deletions build/kind/postgres.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -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
Comment on lines +71 to +74
Copy link
Member

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

I could just check this myself I guess, but is this just a "echo all incoming requests" kind of thing?

Copy link
Member Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Yeah, exactly.

# This is a mirror of postgres:13 on Docker Hub to avoid rate limits.
image: quay.io/stolostron/grc-ci-postgres:13
imagePullPolicy: "IfNotPresent"
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -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,
Expand All @@ -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(
Expand Down