Skip to content
This repository was archived by the owner on Sep 30, 2024. It is now read-only.

Commit ec80653

Browse files
authored
[feat] Adding a few DB triggers to delete permissions when items are soft deleted (#48189)
These entities are referenced via foreign key in the `user_repo_permissions` table, and are soft deleted potentially: - user - user_external_account - repo All of them would leave rows in the user_repo_permissions table, which is not desired. The `user_external_account` one was the most problematic from the point of view of behavior of `authzQuery`. This change only affects the new unified permissions table, old behavior is not affected. ## Test plan Tested locally, directly in the database with the following scenarios: 1. up and down migration works correctly 1. user_repo_permissions table is empty -> nothing happens 1. user_repo_permissions has data from 2 users, 2 repos and 2 external accounts 1. mark repo as deleted -> only the rows with the same `repo_id` are deleted 2. mark user_external_account as deleted -> only the rows with same `user_id` and `user_external_account` are deleted 3. mark user as deleted -> only the rows with the same `user_id` are deleted
1 parent d56de83 commit ec80653

File tree

6 files changed

+114
-1
lines changed

6 files changed

+114
-1
lines changed

internal/database/schema.json

+26-1
Original file line numberDiff line numberDiff line change
@@ -92,6 +92,18 @@
9292
"Name": "delete_repo_ref_on_external_service_repos",
9393
"Definition": "CREATE OR REPLACE FUNCTION public.delete_repo_ref_on_external_service_repos()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$\n BEGIN\n -- if a repo is soft-deleted, delete every row that references that repo\n IF (OLD.deleted_at IS NULL AND NEW.deleted_at IS NOT NULL) THEN\n DELETE FROM\n external_service_repos\n WHERE\n repo_id = OLD.id;\n END IF;\n\n RETURN OLD;\n END;\n$function$\n"
9494
},
95+
{
96+
"Name": "delete_user_repo_permissions_on_external_account_soft_delete",
97+
"Definition": "CREATE OR REPLACE FUNCTION public.delete_user_repo_permissions_on_external_account_soft_delete()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$ BEGIN\n IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN\n \tDELETE FROM user_repo_permissions WHERE user_id = OLD.user_id AND user_external_account_id = OLD.id;\n END IF;\n RETURN NULL;\n END\n$function$\n"
98+
},
99+
{
100+
"Name": "delete_user_repo_permissions_on_repo_soft_delete",
101+
"Definition": "CREATE OR REPLACE FUNCTION public.delete_user_repo_permissions_on_repo_soft_delete()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$ BEGIN\n IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN\n \tDELETE FROM user_repo_permissions WHERE repo_id = NEW.id;\n END IF;\n RETURN NULL;\n END\n$function$\n"
102+
},
103+
{
104+
"Name": "delete_user_repo_permissions_on_user_soft_delete",
105+
"Definition": "CREATE OR REPLACE FUNCTION public.delete_user_repo_permissions_on_user_soft_delete()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$ BEGIN\n IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN\n \tDELETE FROM user_repo_permissions WHERE user_id = OLD.id;\n END IF;\n RETURN NULL;\n END\n$function$\n"
106+
},
95107
{
96108
"Name": "func_configuration_policies_delete",
97109
"Definition": "CREATE OR REPLACE FUNCTION public.func_configuration_policies_delete()\n RETURNS trigger\n LANGUAGE plpgsql\nAS $function$\n BEGIN\n UPDATE configuration_policies_audit_logs\n SET record_deleted_at = NOW()\n WHERE policy_id IN (\n SELECT id FROM OLD\n );\n\n RETURN NULL;\n END;\n$function$\n"
@@ -19626,6 +19638,10 @@
1962619638
"Name": "trig_delete_repo_ref_on_external_service_repos",
1962719639
"Definition": "CREATE TRIGGER trig_delete_repo_ref_on_external_service_repos AFTER UPDATE OF deleted_at ON repo FOR EACH ROW EXECUTE FUNCTION delete_repo_ref_on_external_service_repos()"
1962819640
},
19641+
{
19642+
"Name": "trig_delete_user_repo_permissions_on_repo_soft_delete",
19643+
"Definition": "CREATE TRIGGER trig_delete_user_repo_permissions_on_repo_soft_delete AFTER UPDATE ON repo FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_repo_soft_delete()"
19644+
},
1962919645
{
1963019646
"Name": "trig_recalc_repo_statistics_on_repo_delete",
1963119647
"Definition": "CREATE TRIGGER trig_recalc_repo_statistics_on_repo_delete AFTER DELETE ON repo REFERENCING OLD TABLE AS oldtab FOR EACH STATEMENT EXECUTE FUNCTION recalc_repo_statistics_on_repo_delete()"
@@ -22274,7 +22290,12 @@
2227422290
"ConstraintDefinition": "FOREIGN KEY (user_id) REFERENCES users(id)"
2227522291
}
2227622292
],
22277-
"Triggers": []
22293+
"Triggers": [
22294+
{
22295+
"Name": "trig_delete_user_repo_permissions_on_external_account_soft_dele",
22296+
"Definition": "CREATE TRIGGER trig_delete_user_repo_permissions_on_external_account_soft_dele AFTER UPDATE ON user_external_accounts FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete()"
22297+
}
22298+
]
2227822299
},
2227922300
{
2228022301
"Name": "user_pending_permissions",
@@ -23157,6 +23178,10 @@
2315723178
}
2315823179
],
2315923180
"Triggers": [
23181+
{
23182+
"Name": "trig_delete_user_repo_permissions_on_user_soft_delete",
23183+
"Definition": "CREATE TRIGGER trig_delete_user_repo_permissions_on_user_soft_delete AFTER UPDATE ON users FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_user_soft_delete()"
23184+
},
2316023185
{
2316123186
"Name": "trig_invalidate_session_on_password_change",
2316223187
"Definition": "CREATE TRIGGER trig_invalidate_session_on_password_change BEFORE UPDATE OF passwd ON users FOR EACH ROW EXECUTE FUNCTION invalidate_session_for_userid_on_password_change()"

internal/database/schema.md

+4
Original file line numberDiff line numberDiff line change
@@ -3019,6 +3019,7 @@ Referenced by:
30193019
Triggers:
30203020
trig_create_zoekt_repo_on_repo_insert AFTER INSERT ON repo FOR EACH ROW EXECUTE FUNCTION func_insert_zoekt_repo()
30213021
trig_delete_repo_ref_on_external_service_repos AFTER UPDATE OF deleted_at ON repo FOR EACH ROW EXECUTE FUNCTION delete_repo_ref_on_external_service_repos()
3022+
trig_delete_user_repo_permissions_on_repo_soft_delete AFTER UPDATE ON repo FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_repo_soft_delete()
30223023
trig_recalc_repo_statistics_on_repo_delete AFTER DELETE ON repo REFERENCING OLD TABLE AS oldtab FOR EACH STATEMENT EXECUTE FUNCTION recalc_repo_statistics_on_repo_delete()
30233024
trig_recalc_repo_statistics_on_repo_insert AFTER INSERT ON repo REFERENCING NEW TABLE AS newtab FOR EACH STATEMENT EXECUTE FUNCTION recalc_repo_statistics_on_repo_insert()
30243025
trig_recalc_repo_statistics_on_repo_update AFTER UPDATE ON repo REFERENCING OLD TABLE AS oldtab NEW TABLE AS newtab FOR EACH STATEMENT EXECUTE FUNCTION recalc_repo_statistics_on_repo_update()
@@ -3487,6 +3488,8 @@ Foreign-key constraints:
34873488
"user_external_accounts_user_id_fkey" FOREIGN KEY (user_id) REFERENCES users(id)
34883489
Referenced by:
34893490
TABLE "user_repo_permissions" CONSTRAINT "user_repo_permissions_user_external_account_id_fkey" FOREIGN KEY (user_external_account_id) REFERENCES user_external_accounts(id) ON DELETE CASCADE
3491+
Triggers:
3492+
trig_delete_user_repo_permissions_on_external_account_soft_dele AFTER UPDATE ON user_external_accounts FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete()
34903493
34913494
```
34923495

@@ -3680,6 +3683,7 @@ Referenced by:
36803683
TABLE "webhooks" CONSTRAINT "webhooks_created_by_user_id_fkey" FOREIGN KEY (created_by_user_id) REFERENCES users(id) ON DELETE SET NULL
36813684
TABLE "webhooks" CONSTRAINT "webhooks_updated_by_user_id_fkey" FOREIGN KEY (updated_by_user_id) REFERENCES users(id) ON DELETE SET NULL
36823685
Triggers:
3686+
trig_delete_user_repo_permissions_on_user_soft_delete AFTER UPDATE ON users FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_user_soft_delete()
36833687
trig_invalidate_session_on_password_change BEFORE UPDATE OF passwd ON users FOR EACH ROW EXECUTE FUNCTION invalidate_session_for_userid_on_password_change()
36843688
trig_soft_delete_user_reference_on_external_service AFTER UPDATE OF deleted_at ON users FOR EACH ROW EXECUTE FUNCTION soft_delete_user_reference_on_external_service()
36853689
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,8 @@
1+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_repo_soft_delete ON repo;
2+
DROP FUNCTION IF EXISTS delete_user_repo_permissions_on_repo_soft_delete;
3+
4+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_external_account_soft_delete ON user_external_accounts;
5+
DROP FUNCTION IF EXISTS delete_user_repo_permissions_on_external_account_soft_delete;
6+
7+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_user_soft_delete ON users;
8+
DROP FUNCTION IF EXISTS delete_user_repo_permissions_on_user_soft_delete;
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,2 @@
1+
name: add_triggers_for_soft_deleted_perms_entities
2+
parents: [1677073533]
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,38 @@
1+
CREATE OR REPLACE FUNCTION delete_user_repo_permissions_on_repo_soft_delete() RETURNS trigger
2+
LANGUAGE plpgsql
3+
AS $$ BEGIN
4+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
5+
DELETE FROM user_repo_permissions WHERE repo_id = NEW.id;
6+
END IF;
7+
RETURN NULL;
8+
END
9+
$$;
10+
11+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_repo_soft_delete ON repo;
12+
CREATE TRIGGER trig_delete_user_repo_permissions_on_repo_soft_delete AFTER UPDATE ON repo FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_repo_soft_delete();
13+
14+
CREATE OR REPLACE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete() RETURNS trigger
15+
LANGUAGE plpgsql
16+
AS $$ BEGIN
17+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
18+
DELETE FROM user_repo_permissions WHERE user_id = OLD.user_id AND user_external_account_id = OLD.id;
19+
END IF;
20+
RETURN NULL;
21+
END
22+
$$;
23+
24+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_external_account_soft_delete ON user_external_accounts;
25+
CREATE TRIGGER trig_delete_user_repo_permissions_on_external_account_soft_delete AFTER UPDATE ON user_external_accounts FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete();
26+
27+
CREATE OR REPLACE FUNCTION delete_user_repo_permissions_on_user_soft_delete() RETURNS trigger
28+
LANGUAGE plpgsql
29+
AS $$ BEGIN
30+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
31+
DELETE FROM user_repo_permissions WHERE user_id = OLD.id;
32+
END IF;
33+
RETURN NULL;
34+
END
35+
$$;
36+
37+
DROP TRIGGER IF EXISTS trig_delete_user_repo_permissions_on_user_soft_delete ON users;
38+
CREATE TRIGGER trig_delete_user_repo_permissions_on_user_soft_delete AFTER UPDATE ON users FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_user_soft_delete();

migrations/frontend/squashed.sql

+36
Original file line numberDiff line numberDiff line change
@@ -164,6 +164,36 @@ CREATE FUNCTION delete_repo_ref_on_external_service_repos() RETURNS trigger
164164
END;
165165
$$;
166166

167+
CREATE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete() RETURNS trigger
168+
LANGUAGE plpgsql
169+
AS $$ BEGIN
170+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
171+
DELETE FROM user_repo_permissions WHERE user_id = OLD.user_id AND user_external_account_id = OLD.id;
172+
END IF;
173+
RETURN NULL;
174+
END
175+
$$;
176+
177+
CREATE FUNCTION delete_user_repo_permissions_on_repo_soft_delete() RETURNS trigger
178+
LANGUAGE plpgsql
179+
AS $$ BEGIN
180+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
181+
DELETE FROM user_repo_permissions WHERE repo_id = NEW.id;
182+
END IF;
183+
RETURN NULL;
184+
END
185+
$$;
186+
187+
CREATE FUNCTION delete_user_repo_permissions_on_user_soft_delete() RETURNS trigger
188+
LANGUAGE plpgsql
189+
AS $$ BEGIN
190+
IF NEW.deleted_at IS NOT NULL AND OLD.deleted_at IS NULL THEN
191+
DELETE FROM user_repo_permissions WHERE user_id = OLD.id;
192+
END IF;
193+
RETURN NULL;
194+
END
195+
$$;
196+
167197
CREATE FUNCTION func_configuration_policies_delete() RETURNS trigger
168198
LANGUAGE plpgsql
169199
AS $$
@@ -5244,6 +5274,12 @@ CREATE TRIGGER trig_delete_batch_change_reference_on_changesets AFTER DELETE ON
52445274

52455275
CREATE TRIGGER trig_delete_repo_ref_on_external_service_repos AFTER UPDATE OF deleted_at ON repo FOR EACH ROW EXECUTE FUNCTION delete_repo_ref_on_external_service_repos();
52465276

5277+
CREATE TRIGGER trig_delete_user_repo_permissions_on_external_account_soft_dele AFTER UPDATE ON user_external_accounts FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_external_account_soft_delete();
5278+
5279+
CREATE TRIGGER trig_delete_user_repo_permissions_on_repo_soft_delete AFTER UPDATE ON repo FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_repo_soft_delete();
5280+
5281+
CREATE TRIGGER trig_delete_user_repo_permissions_on_user_soft_delete AFTER UPDATE ON users FOR EACH ROW EXECUTE FUNCTION delete_user_repo_permissions_on_user_soft_delete();
5282+
52475283
CREATE TRIGGER trig_invalidate_session_on_password_change BEFORE UPDATE OF passwd ON users FOR EACH ROW EXECUTE FUNCTION invalidate_session_for_userid_on_password_change();
52485284

52495285
CREATE TRIGGER trig_recalc_gitserver_repos_statistics_on_delete AFTER DELETE ON gitserver_repos REFERENCING OLD TABLE AS oldtab FOR EACH STATEMENT EXECUTE FUNCTION recalc_gitserver_repos_statistics_on_delete();

0 commit comments

Comments
 (0)