1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
|
"""
refactor: drop 'group_id' from 'resources' table.
"""
import sqlite3
from yoyo import step
__depends__ = {'20230907_02_Enicg-refactor-add-system-and-group-resource-categories'}
def drop_group_id_from_group_user_roles_on_resources(conn):
conn.execute(
"ALTER TABLE group_user_roles_on_resources "
"RENAME TO group_user_roles_on_resources_bkp")
conn.execute(
"""
CREATE TABLE group_user_roles_on_resources (
group_id TEXT NOT NULL,
user_id TEXT NOT NULL,
role_id TEXT NOT NULL,
resource_id TEXT NOT NULL,
PRIMARY KEY (group_id, user_id, role_id, resource_id),
FOREIGN KEY (user_id)
REFERENCES users(user_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (group_id, role_id)
REFERENCES group_roles(group_id, role_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (resource_id)
REFERENCES resources(resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO group_user_roles_on_resources "
"(group_id, user_id, role_id, resource_id)"
"SELECT group_id, user_id, role_id, resource_id "
"FROM group_user_roles_on_resources_bkp")
conn.execute("DROP TABLE IF EXISTS group_user_roles_on_resources_bkp")
def drop_group_id_from_mrna_resources(conn):
conn.execute("ALTER TABLE mrna_resources RENAME TO mrna_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS mrna_resources
-- Link mRNA data to specific resource
(
resource_id TEXT NOT NULL, -- A resource can have multiple items
data_link_id TEXT NOT NULL,
PRIMARY KEY (resource_id, data_link_id),
UNIQUE (data_link_id) -- ensure data is linked to single resource
FOREIGN KEY (resource_id)
REFERENCES resources(resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id) REFERENCES linked_mrna_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO mrna_resources "
"SELECT resource_id, data_link_id FROM mrna_resources_bkp")
conn.execute("DROP TABLE IF EXISTS mrna_resources_bkp")
def drop_group_id_from_genotype_resources(conn):
conn.execute(
"ALTER TABLE genotype_resources RENAME TO genotype_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS genotype_resources
-- Link genotype data to specific resource
(
resource_id TEXT NOT NULL, -- A resource can have multiple items
data_link_id TEXT NOT NULL,
PRIMARY KEY (resource_id, data_link_id),
UNIQUE (data_link_id) -- ensure data is linked to single resource
FOREIGN KEY (resource_id)
REFERENCES resources(resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id)
REFERENCES linked_genotype_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO genotype_resources "
"SELECT resource_id, data_link_id FROM genotype_resources_bkp")
conn.execute("DROP TABLE IF EXISTS genotype_resources_bkp")
def drop_group_id_from_phenotype_resources(conn):
conn.execute(
"ALTER TABLE phenotype_resources RENAME TO phenotype_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS phenotype_resources
-- Link phenotype data to specific resources
(
resource_id TEXT NOT NULL, -- A resource can have multiple data items
data_link_id TEXT NOT NULL,
PRIMARY KEY(resource_id, data_link_id),
UNIQUE (data_link_id), -- ensure data is linked to only one resource
FOREIGN KEY (resource_id)
REFERENCES resources(resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id)
REFERENCES linked_phenotype_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO phenotype_resources "
"SELECT resource_id, data_link_id FROM phenotype_resources_bkp")
conn.execute("DROP TABLE IF EXISTS phenotype_resources_bkp")
def drop_group_id_from_resources_table(conn):
conn.row_factory = sqlite3.Row
conn.execute("PRAGMA foreign_keys = OFF")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS resources_new(
resource_id TEXT NOT NULL,
resource_name TEXT NOT NULL UNIQUE,
resource_category_id TEXT NOT NULL,
public INTEGER NOT NULL DEFAULT 0 CHECK (public=0 or public=1),
PRIMARY KEY(resource_id),
FOREIGN KEY(resource_category_id)
REFERENCES resource_categories(resource_category_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO resources_new "
"SELECT resource_id, resource_name, resource_category_id, public "
"FROM resources")
conn.execute("DROP TABLE IF EXISTS resources")
conn.execute("ALTER TABLE resources_new RENAME TO resources")
drop_group_id_from_mrna_resources(conn)
drop_group_id_from_genotype_resources(conn)
drop_group_id_from_phenotype_resources(conn)
drop_group_id_from_group_user_roles_on_resources(conn)
conn.execute("PRAGMA foreign_key_check")
conn.execute("PRAGMA foreign_keys = ON")
def restore_group_id_from_group_user_roles_on_resources(conn):
conn.execute(
"ALTER TABLE group_user_roles_on_resources "
"RENAME TO group_user_roles_on_resources_bkp")
conn.execute(
"""
CREATE TABLE group_user_roles_on_resources (
group_id TEXT NOT NULL,
user_id TEXT NOT NULL,
role_id TEXT NOT NULL,
resource_id TEXT NOT NULL,
PRIMARY KEY (group_id, user_id, role_id, resource_id),
FOREIGN KEY (user_id)
REFERENCES users(user_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (group_id, role_id)
REFERENCES group_roles(group_id, role_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (group_id, resource_id)
REFERENCES resources(group_id, resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
conn.execute(
"INSERT INTO group_user_roles_on_resources "
"(group_id, user_id, role_id, resource_id)"
"SELECT group_id, user_id, role_id, resource_id "
"FROM group_user_roles_on_resources_bkp")
conn.execute("DROP TABLE IF EXISTS group_user_roles_on_resources_bkp")
def restore_group_id_from_mrna_resources(conn, resource_group_map):
conn.execute("ALTER TABLE mrna_resources RENAME TO mrna_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS mrna_resources
-- Link mRNA data to specific resource
(
group_id TEXT NOT NULL,
resource_id TEXT NOT NULL, -- A resource can have multiple items
data_link_id TEXT NOT NULL,
PRIMARY KEY (resource_id, data_link_id),
UNIQUE (data_link_id) -- ensure data is linked to single resource
FOREIGN KEY (group_id, resource_id)
REFERENCES resources(group_id, resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id) REFERENCES linked_mrna_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
cursor = conn.cursor()
cursor.execute("SELECT * FROM mrna_resources_bkp")
resources = tuple({
"group_id": resource_group_map[row["resource_id"]],
**dict(row)
} for row in cursor.fetchall())
cursor.executemany(
"INSERT INTO mrna_resources(group_id, resource_id, data_link_id) "
"VALUES(:group_id, :resource_id, :data_link_id)",
resources)
conn.execute("DROP TABLE IF EXISTS mrna_resources_bkp")
def restore_group_id_from_genotype_resources(conn, resource_group_map):
conn.execute(
"ALTER TABLE genotype_resources RENAME TO genotype_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS genotype_resources
-- Link genotype data to specific resource
(
group_id TEXT NOT NULL,
resource_id TEXT NOT NULL, -- A resource can have multiple items
data_link_id TEXT NOT NULL,
PRIMARY KEY (group_id, resource_id, data_link_id),
UNIQUE (data_link_id) -- ensure data is linked to single resource
FOREIGN KEY (group_id, resource_id)
REFERENCES resources(group_id, resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id)
REFERENCES linked_genotype_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
cursor = conn.cursor()
cursor.execute("SELECT * FROM genotype_resources_bkp")
resources = tuple({
"group_id": resource_group_map[row["resource_id"]],
**dict(row)
} for row in cursor.fetchall())
cursor.executemany(
"INSERT INTO genotype_resources(group_id, resource_id, data_link_id) "
"VALUES(:group_id, :resource_id, :data_link_id)",
resources)
conn.execute("DROP TABLE IF EXISTS genotype_resources_bkp")
def restore_group_id_from_phenotype_resources(conn, resource_group_map):
conn.execute(
"ALTER TABLE phenotype_resources RENAME TO phenotype_resources_bkp")
conn.execute(
"""
CREATE TABLE IF NOT EXISTS phenotype_resources
-- Link phenotype data to specific resources
(
group_id TEXT NOT NULL,
resource_id TEXT NOT NULL, -- A resource can have multiple data items
data_link_id TEXT NOT NULL,
PRIMARY KEY(group_id, resource_id, data_link_id),
UNIQUE (data_link_id), -- ensure data is linked to only one resource
FOREIGN KEY (group_id, resource_id)
REFERENCES resources(group_id, resource_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY (data_link_id)
REFERENCES linked_phenotype_data(data_link_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
cursor = conn.cursor()
cursor.execute("SELECT * FROM phenotype_resources_bkp")
resources = tuple({
"group_id": resource_group_map[row["resource_id"]],
**dict(row)
} for row in cursor.fetchall())
cursor.executemany(
"INSERT INTO phenotype_resources(group_id, resource_id, data_link_id) "
"VALUES(:group_id, :resource_id, :data_link_id)",
resources)
conn.execute("DROP TABLE IF EXISTS phenotype_resources_bkp")
def restore_group_id_to_resources_table(conn):
conn.row_factory = sqlite3.Row
conn.execute("PRAGMA foreign_keys = OFF")
cursor = conn.cursor()
cursor.execute("ALTER TABLE resources RENAME TO resources_bkp")
cursor.execute(
"SELECT r.*, ro.group_id FROM resources_bkp AS r "
"INNER JOIN resource_ownership AS ro "
"ON r.resource_id=ro.resource_id")
group_resources = tuple(dict(row) for row in cursor.fetchall())
cursor.execute(
"""
CREATE TABLE IF NOT EXISTS resources(
group_id TEXT NOT NULL,
resource_id TEXT NOT NULL,
resource_name TEXT NOT NULL UNIQUE,
resource_category_id TEXT NOT NULL,
public INTEGER NOT NULL DEFAULT 0 CHECK (public=0 or public=1),
PRIMARY KEY(group_id, resource_id),
FOREIGN KEY(group_id)
REFERENCES groups(group_id)
ON UPDATE CASCADE ON DELETE RESTRICT,
FOREIGN KEY(resource_category_id)
REFERENCES resource_categories(resource_category_id)
ON UPDATE CASCADE ON DELETE RESTRICT
) WITHOUT ROWID
""")
cursor.executemany(
"INSERT INTO resources"
"(group_id, resource_id, resource_name, resource_category_id)"
"VALUES "
"(:group_id, :resource_id, :resource_name, :resource_category_id)",
group_resources)
cursor.execute("DROP TABLE IF EXISTS resources_bkp")
resource_group_map = {
res["resource_id"]: res["group_id"]
for res in group_resources
}
restore_group_id_from_group_user_roles_on_resources(conn)
restore_group_id_from_mrna_resources(conn, resource_group_map)
restore_group_id_from_genotype_resources(conn, resource_group_map)
restore_group_id_from_phenotype_resources(conn, resource_group_map)
conn.execute("PRAGMA foreign_key_check")
conn.execute("PRAGMA foreign_keys = ON")
steps = [
step(
drop_group_id_from_resources_table, restore_group_id_to_resources_table)
]
|