Skip to content

Commit b308814

Browse files
committed
Changed the permissions migration SQL to use the standard approach with a temp table
1 parent 38fe53c commit b308814

File tree

1 file changed

+35
-51
lines changed

1 file changed

+35
-51
lines changed

src/main/resources/db/migration/postgresql/V2.15.0.20250220000001__webapi_snapshots_schema_init.sql

Lines changed: 35 additions & 51 deletions
Original file line numberDiff line numberDiff line change
@@ -86,56 +86,40 @@ CREATE TABLE ${ohdsiSchema}.INCLUDED_SOURCE_CODES_SNAPSHOTS (
8686
--for each concept set which has a "conceptset:%s:put" permission. This is made to allow making snapshot actions to old concept sets
8787
--which were created before the snapshot/lock feature was deployed
8888

89-
DO $$
90-
DECLARE
91-
permission RECORD;
92-
new_permission_id INTEGER;
93-
new_permission_value VARCHAR;
94-
new_role_permission_id INTEGER;
95-
BEGIN
96-
FOR permission IN
97-
SELECT p.id AS permission_id, p.value AS permission_value, rp.role_id AS role_id
98-
FROM ${ohdsiSchema}.sec_permission p
99-
INNER JOIN ${ohdsiSchema}.sec_role_permission rp
100-
ON p.id = rp.permission_id
101-
WHERE p.value ~ '^conceptset:[0-9]+:put$'
102-
LOOP
103-
new_permission_value := 'conceptset:' || split_part(permission.permission_value, ':', 2) || ':snapshot:post';
89+
DROP TABLE IF EXISTS temp_migration;
10490

105-
IF NOT EXISTS (
106-
SELECT 1
107-
FROM ${ohdsiSchema}.sec_permission
108-
WHERE "value" = new_permission_value
109-
)
110-
THEN
111-
new_permission_id := nextval('${ohdsiSchema}.sec_permission_id_seq');
112-
113-
INSERT INTO ${ohdsiSchema}.sec_permission (id, value, description)
114-
VALUES (new_permission_id, new_permission_value, 'Permission to create snapshot for concept set');
115-
116-
RAISE NOTICE 'Inserted New Permission: % (ID: %)', new_permission_value, new_permission_id;
117-
ELSE
118-
SELECT id INTO new_permission_id
119-
FROM ${ohdsiSchema}.sec_permission
120-
WHERE "value" = new_permission_value;
121-
122-
RAISE NOTICE 'Permission Already Exists: % (ID: %)', new_permission_value, new_permission_id;
123-
END IF;
124-
125-
IF NOT EXISTS (
126-
SELECT 1
127-
FROM ${ohdsiSchema}.sec_role_permission
128-
WHERE role_id = permission.role_id AND permission_id = new_permission_id
129-
)
130-
THEN
131-
new_role_permission_id := nextval('${ohdsiSchema}.sec_role_permission_sequence');
132-
133-
INSERT INTO ${ohdsiSchema}.sec_role_permission (id, role_id, permission_id)
134-
VALUES (new_role_permission_id, permission.role_id, new_permission_id);
91+
CREATE TEMP TABLE temp_migration (
92+
from_perm_id INT,
93+
new_value CHARACTER VARYING(255)
94+
);
13595

136-
RAISE NOTICE 'Mapped New Permission to Role: % (Role ID: %)', new_permission_value, permission.role_id;
137-
ELSE
138-
RAISE NOTICE 'Mapping Already Exists: Permission: % - Role ID: %', new_permission_value, permission.role_id;
139-
END IF;
140-
END LOOP;
141-
END $$;
96+
INSERT INTO temp_migration (from_perm_id, new_value)
97+
SELECT
98+
p.id AS from_perm_id,
99+
'conceptset:' || split_part(p.value, ':', 2) || ':snapshot:post' AS new_value
100+
FROM
101+
${ohdsiSchema}.sec_permission p
102+
WHERE
103+
p.value ~ '^conceptset:[0-9]+:put$';
104+
105+
INSERT INTO ${ohdsiSchema}.sec_permission (id, value, description)
106+
SELECT
107+
nextval('${ohdsiSchema}.sec_permission_id_seq') AS id,
108+
new_value AS value,
109+
'Permission to create snapshot for concept set'
110+
FROM
111+
temp_migration;
112+
113+
INSERT INTO ${ohdsiSchema}.sec_role_permission (id, role_id, permission_id)
114+
SELECT
115+
nextval('${ohdsiSchema}.sec_role_permission_sequence') AS id,
116+
srp.role_id AS role_id,
117+
sp.id AS permission_id
118+
FROM
119+
temp_migration AS tm
120+
JOIN
121+
${ohdsiSchema}.sec_permission sp ON tm.new_value = sp.value
122+
JOIN
123+
${ohdsiSchema}.sec_role_permission srp ON tm.from_perm_id = srp.permission_id;
124+
125+
DROP TABLE temp_migration;

0 commit comments

Comments
 (0)