From 877a6d6616d8cba8172455eb68d6cacbe816038b Mon Sep 17 00:00:00 2001 From: Devin AI <158243242+devin-ai-integration[bot]@users.noreply.github.com> Date: Tue, 18 Nov 2025 01:33:57 +0000 Subject: [PATCH 1/2] Fix concurrent role creation race condition - Add advisory locks (pg_advisory_xact_lock) to serialize role creation - Catch both duplicate_object and unique_violation exceptions - Fixes error: duplicate key value violates unique constraint pg_authid_rolname_index - Applied to all role creation code paths: - bootstrap-roles.sql (anonymous, authenticated, administrator) - bootstrap-test-roles.sql (app_user, app_admin) - LaunchQLInit.bootstrapDbRoles() - DbAdmin.createUserRole() Under concurrent execution, CREATE ROLE can hit the pg_authid_rolname_index unique constraint before the duplicate_object check, resulting in unique_violation (23505) instead of duplicate_object (42710). Advisory locks prevent the race entirely, and catching both exceptions provides defense in depth. Co-Authored-By: Dan Lynch --- packages/core/src/init/client.ts | 4 ++-- packages/core/src/init/sql/bootstrap-roles.sql | 17 ++++++++++------- .../core/src/init/sql/bootstrap-test-roles.sql | 8 ++++---- packages/pgsql-test/src/admin.ts | 4 ++-- 4 files changed, 18 insertions(+), 15 deletions(-) diff --git a/packages/core/src/init/client.ts b/packages/core/src/init/client.ts index ca7a7fa91..e5b854ef9 100644 --- a/packages/core/src/init/client.ts +++ b/packages/core/src/init/client.ts @@ -70,10 +70,10 @@ DECLARE v_password TEXT := '${password.replace(/'/g, "''")}'; BEGIN BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext(v_username)); EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_username, v_password); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN NULL; END; END diff --git a/packages/core/src/init/sql/bootstrap-roles.sql b/packages/core/src/init/sql/bootstrap-roles.sql index 6b455b741..5d8939494 100644 --- a/packages/core/src/init/sql/bootstrap-roles.sql +++ b/packages/core/src/init/sql/bootstrap-roles.sql @@ -3,28 +3,31 @@ DO $do$ BEGIN -- anonymous BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('anonymous')); EXECUTE format('CREATE ROLE %I', 'anonymous'); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN + -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) NULL; END; -- authenticated BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('authenticated')); EXECUTE format('CREATE ROLE %I', 'authenticated'); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN + -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) NULL; END; -- administrator BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('administrator')); EXECUTE format('CREATE ROLE %I', 'administrator'); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN + -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) NULL; END; END @@ -52,4 +55,4 @@ ALTER USER administrator WITH NOLOGIN; ALTER USER administrator WITH NOREPLICATION; -- they CAN bypass RLS ALTER USER administrator WITH BYPASSRLS; -COMMIT; \ No newline at end of file +COMMIT; diff --git a/packages/core/src/init/sql/bootstrap-test-roles.sql b/packages/core/src/init/sql/bootstrap-test-roles.sql index d5bc68f21..69209246e 100644 --- a/packages/core/src/init/sql/bootstrap-test-roles.sql +++ b/packages/core/src/init/sql/bootstrap-test-roles.sql @@ -2,18 +2,18 @@ BEGIN; DO $do$ BEGIN BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('app_user')); EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_user', 'app_password'); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN NULL; END; BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('app_admin')); EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_admin', 'admin_password'); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN NULL; END; END diff --git a/packages/pgsql-test/src/admin.ts b/packages/pgsql-test/src/admin.ts index 16adf666e..4edf88037 100644 --- a/packages/pgsql-test/src/admin.ts +++ b/packages/pgsql-test/src/admin.ts @@ -157,10 +157,10 @@ $$; BEGIN -- Create role if it doesn't exist BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext(v_user)); EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_user, v_password); EXCEPTION - WHEN duplicate_object THEN - -- Role already exists; optionally sync attributes here with ALTER ROLE + WHEN duplicate_object OR unique_violation THEN NULL; END; From 8a3e6dbc64fbb47cfd05455e9d840251a25fd158 Mon Sep 17 00:00:00 2001 From: Devin AI <158243242+devin-ai-integration[bot]@users.noreply.github.com> Date: Tue, 18 Nov 2025 01:50:15 +0000 Subject: [PATCH 2/2] Add pre-existence checks to all CREATE ROLE and GRANT statements - Add IF NOT EXISTS checks before every CREATE ROLE statement - Add membership pre-checks before every GRANT statement - Keep advisory locks for serialization (with-locks variant) - Keep both exception handlers (duplicate_object OR unique_violation) - Defense-in-depth: pre-check + lock + exceptions This pedantic approach ensures maximum safety against concurrent role creation and membership grant races. Co-Authored-By: Dan Lynch --- packages/core/src/init/client.ts | 67 ++++---- .../core/src/init/sql/bootstrap-roles.sql | 54 +++---- .../src/init/sql/bootstrap-test-roles.sql | 149 +++++++++++------- packages/pgsql-test/src/admin.ts | 17 +- 4 files changed, 168 insertions(+), 119 deletions(-) diff --git a/packages/core/src/init/client.ts b/packages/core/src/init/client.ts index e5b854ef9..5fa7953c0 100644 --- a/packages/core/src/init/client.ts +++ b/packages/core/src/init/client.ts @@ -69,42 +69,53 @@ DECLARE v_username TEXT := '${username.replace(/'/g, "''")}'; v_password TEXT := '${password.replace(/'/g, "''")}'; BEGIN - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext(v_username)); - EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_username, v_password); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = v_username) THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext(v_username)); + EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_username, v_password); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; END $do$; --- Robust GRANTs under concurrency: GRANT can race on pg_auth_members unique index. --- Catch unique_violation (23505) and continue so CI/CD concurrent jobs don't fail. DO $do$ DECLARE v_username TEXT := '${username.replace(/'/g, "''")}'; BEGIN - BEGIN - EXECUTE format('GRANT %I TO %I', 'anonymous', v_username); - EXCEPTION - WHEN unique_violation THEN - -- Membership was granted concurrently; ignore. - NULL; - WHEN undefined_object THEN - -- One of the roles doesn't exist yet; order operations as needed. - RAISE NOTICE 'Missing role when granting % to %', 'anonymous', v_username; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'anonymous' AND r2.rolname = v_username + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'anonymous', v_username); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'anonymous', v_username; + END; + END IF; - BEGIN - EXECUTE format('GRANT %I TO %I', 'authenticated', v_username); - EXCEPTION - WHEN unique_violation THEN - -- Membership was granted concurrently; ignore. - NULL; - WHEN undefined_object THEN - RAISE NOTICE 'Missing role when granting % to %', 'authenticated', v_username; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'authenticated' AND r2.rolname = v_username + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'authenticated', v_username); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'authenticated', v_username; + END; + END IF; END $do$; COMMIT; diff --git a/packages/core/src/init/sql/bootstrap-roles.sql b/packages/core/src/init/sql/bootstrap-roles.sql index 5d8939494..91f636243 100644 --- a/packages/core/src/init/sql/bootstrap-roles.sql +++ b/packages/core/src/init/sql/bootstrap-roles.sql @@ -1,35 +1,35 @@ BEGIN; DO $do$ BEGIN - -- anonymous - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext('anonymous')); - EXECUTE format('CREATE ROLE %I', 'anonymous'); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = 'anonymous') THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('anonymous')); + EXECUTE format('CREATE ROLE %I', 'anonymous'); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; - -- authenticated - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext('authenticated')); - EXECUTE format('CREATE ROLE %I', 'authenticated'); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = 'authenticated') THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('authenticated')); + EXECUTE format('CREATE ROLE %I', 'authenticated'); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; - -- administrator - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext('administrator')); - EXECUTE format('CREATE ROLE %I', 'administrator'); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - -- Role already exists (duplicate_object) or concurrent creation hit unique index (unique_violation) - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = 'administrator') THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('administrator')); + EXECUTE format('CREATE ROLE %I', 'administrator'); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; END $do$; diff --git a/packages/core/src/init/sql/bootstrap-test-roles.sql b/packages/core/src/init/sql/bootstrap-test-roles.sql index 69209246e..4a5177238 100644 --- a/packages/core/src/init/sql/bootstrap-test-roles.sql +++ b/packages/core/src/init/sql/bootstrap-test-roles.sql @@ -1,72 +1,109 @@ BEGIN; DO $do$ BEGIN - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext('app_user')); - EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_user', 'app_password'); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = 'app_user') THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('app_user')); + EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_user', 'app_password'); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext('app_admin')); - EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_admin', 'admin_password'); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = 'app_admin') THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext('app_admin')); + EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', 'app_admin', 'admin_password'); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; END $do$; DO $do$ BEGIN - BEGIN - EXECUTE format('GRANT %I TO %I', 'anonymous', 'app_user'); - EXCEPTION - WHEN unique_violation THEN - -- Membership was granted concurrently; ignore. - NULL; - WHEN undefined_object THEN - -- One of the roles doesn't exist yet; order operations as needed. - RAISE NOTICE 'Missing role when granting % to %', 'anonymous', 'app_user'; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'anonymous' AND r2.rolname = 'app_user' + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'anonymous', 'app_user'); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'anonymous', 'app_user'; + END; + END IF; - BEGIN - EXECUTE format('GRANT %I TO %I', 'authenticated', 'app_user'); - EXCEPTION - WHEN unique_violation THEN - NULL; - WHEN undefined_object THEN - RAISE NOTICE 'Missing role when granting % to %', 'authenticated', 'app_user'; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'authenticated' AND r2.rolname = 'app_user' + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'authenticated', 'app_user'); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'authenticated', 'app_user'; + END; + END IF; - BEGIN - EXECUTE format('GRANT %I TO %I', 'anonymous', 'administrator'); - EXCEPTION - WHEN unique_violation THEN - NULL; - WHEN undefined_object THEN - RAISE NOTICE 'Missing role when granting % to %', 'anonymous', 'administrator'; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'anonymous' AND r2.rolname = 'administrator' + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'anonymous', 'administrator'); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'anonymous', 'administrator'; + END; + END IF; - BEGIN - EXECUTE format('GRANT %I TO %I', 'authenticated', 'administrator'); - EXCEPTION - WHEN unique_violation THEN - NULL; - WHEN undefined_object THEN - RAISE NOTICE 'Missing role when granting % to %', 'authenticated', 'administrator'; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'authenticated' AND r2.rolname = 'administrator' + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'authenticated', 'administrator'); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'authenticated', 'administrator'; + END; + END IF; - BEGIN - EXECUTE format('GRANT %I TO %I', 'administrator', 'app_admin'); - EXCEPTION - WHEN unique_violation THEN - NULL; - WHEN undefined_object THEN - RAISE NOTICE 'Missing role when granting % to %', 'administrator', 'app_admin'; - END; + IF NOT EXISTS ( + SELECT 1 FROM pg_auth_members am + JOIN pg_roles r1 ON am.roleid = r1.oid + JOIN pg_roles r2 ON am.member = r2.oid + WHERE r1.rolname = 'administrator' AND r2.rolname = 'app_admin' + ) THEN + BEGIN + EXECUTE format('GRANT %I TO %I', 'administrator', 'app_admin'); + EXCEPTION + WHEN unique_violation THEN + NULL; + WHEN undefined_object THEN + RAISE NOTICE 'Missing role when granting % to %', 'administrator', 'app_admin'; + END; + END IF; END $do$; COMMIT; diff --git a/packages/pgsql-test/src/admin.ts b/packages/pgsql-test/src/admin.ts index 4edf88037..5aad7ef26 100644 --- a/packages/pgsql-test/src/admin.ts +++ b/packages/pgsql-test/src/admin.ts @@ -155,14 +155,15 @@ $$; v_user TEXT := '${user.replace(/'/g, "''")}'; v_password TEXT := '${password.replace(/'/g, "''")}'; BEGIN - -- Create role if it doesn't exist - BEGIN - PERFORM pg_advisory_xact_lock(42, hashtext(v_user)); - EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_user, v_password); - EXCEPTION - WHEN duplicate_object OR unique_violation THEN - NULL; - END; + IF NOT EXISTS (SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = v_user) THEN + BEGIN + PERFORM pg_advisory_xact_lock(42, hashtext(v_user)); + EXECUTE format('CREATE ROLE %I LOGIN PASSWORD %L', v_user, v_password); + EXCEPTION + WHEN duplicate_object OR unique_violation THEN + NULL; + END; + END IF; -- CI/CD concurrency note: GRANT role membership can race on pg_auth_members unique index -- We pre-check membership and still catch unique_violation to handle TOCTOU safely.