Skip to content

Commit 417bd12

Browse files
committed
Update db/project.xml per review
Make external_ids unique per project regardless of external org (name) and adjust tests accordingly. Make the new tables' audit_log_id field non-NULL, and cons up a new audit_log entry for the external_id migrations to refer to. Add comments clarifying PRIMARY_EXTERNAL_ORG. Drop the old external_id fields' not-NULL constraint before clearing their values -- previously omitted as this was tested only on empty tables! This is in a separate changeSet as system_versioning_alter_history=1 is needed, and we'd prefer not to set that during the main changeSet.
1 parent 8644930 commit 417bd12

File tree

3 files changed

+60
-25
lines changed

3 files changed

+60
-25
lines changed

db/project.xml

+31-11
Original file line numberDiff line numberDiff line change
@@ -1302,7 +1302,7 @@
13021302
<column name="meta" type="LONGTEXT" />
13031303
<column name="audit_log_id" type="INT">
13041304
<constraints
1305-
nullable="true"
1305+
nullable="false"
13061306
foreignKeyName="FK_PARTICIPANT_EXTERNAL_ID_CHANGELOG_ID"
13071307
references="audit_log(id)" />
13081308
</column>
@@ -1315,7 +1315,7 @@
13151315
/>
13161316
<addUniqueConstraint
13171317
tableName="participant_external_id"
1318-
columnNames="project,name,external_id"
1318+
columnNames="project,external_id"
13191319
constraintName="UK_PARTICIPANT_EXTERNAL_ID_UNIQUE_EIDS"
13201320
validate="true"
13211321
/>
@@ -1347,7 +1347,7 @@
13471347
<column name="meta" type="LONGTEXT" />
13481348
<column name="audit_log_id" type="INT">
13491349
<constraints
1350-
nullable="true"
1350+
nullable="false"
13511351
foreignKeyName="FK_SAMPLE_EXTERNAL_ID_CHANGELOG_ID"
13521352
references="audit_log(id)" />
13531353
</column>
@@ -1360,7 +1360,7 @@
13601360
/>
13611361
<addUniqueConstraint
13621362
tableName="sample_external_id"
1363-
columnNames="project,name,external_id"
1363+
columnNames="project,external_id"
13641364
constraintName="UK_SAMPLE_EXTERNAL_ID_UNIQUE_EIDS"
13651365
validate="true"
13661366
/>
@@ -1375,10 +1375,28 @@
13751375
<sql>ALTER TABLE participant_external_id ADD SYSTEM VERSIONING;</sql>
13761376
<sql>ALTER TABLE sample_external_id ADD SYSTEM VERSIONING;</sql>
13771377

1378-
<sql>INSERT INTO participant_external_id (project, participant_id, name, external_id)
1379-
SELECT project, id, '', external_id
1380-
FROM participant
1378+
<!-- Migrate existing external_ids to the new tables, keyed by PRIMARY_EXTERNAL_ORG, i.e. '' -->
1379+
<sql>INSERT INTO audit_log (author, on_behalf_of, ar_guid, comment, auth_project, meta)
1380+
VALUES ('liquibase', NULL, NULL, 'participant/sample external_id migration', NULL, NULL)
1381+
RETURNING @audit_log_id := id;
1382+
1383+
INSERT INTO participant_external_id (project, participant_id, name, external_id, audit_log_id)
1384+
SELECT project, id, '', external_id, @audit_log_id
1385+
FROM participant;
1386+
1387+
INSERT INTO sample_external_id (project, sample_id, name, external_id, audit_log_id)
1388+
SELECT project, id, '', external_id, @audit_log_id
1389+
FROM sample;
13811390
</sql>
1391+
</changeSet>
1392+
<changeSet id="2024-06-11-drop-old-external-id-columns" author="john.marshall">
1393+
<sql>SET @@system_versioning_alter_history = 1;</sql>
1394+
1395+
<dropNotNullConstraint
1396+
tableName="participant"
1397+
columnName="external_id"
1398+
columnDataType="VARCHAR(255)"
1399+
/>
13821400
<sql>UPDATE participant SET external_id = NULL</sql>
13831401
<renameColumn
13841402
tableName="participant"
@@ -1387,10 +1405,12 @@
13871405
columnDataType="VARCHAR(255)"
13881406
remarks="Migration of external IDs to separate table"
13891407
/>
1390-
<sql>INSERT INTO sample_external_id (project, sample_id, name, external_id)
1391-
SELECT project, id, '', external_id
1392-
FROM sample
1393-
</sql>
1408+
1409+
<dropNotNullConstraint
1410+
tableName="sample"
1411+
columnName="external_id"
1412+
columnDataType="VARCHAR(255)"
1413+
/>
13941414
<sql>UPDATE sample SET external_id = NULL</sql>
13951415
<renameColumn
13961416
tableName="sample"

models/base.py

+1
Original file line numberDiff line numberDiff line change
@@ -7,6 +7,7 @@
77

88

99
# The primary {sample,participant}_external_id entry, previously {sample,participant}.external_id
10+
# TODO This will eventually be removed when all analysis endpoints have been updated to record an external org
1011
PRIMARY_EXTERNAL_ORG = ''
1112

1213

test/test_external_id.py

+28-14
Original file line numberDiff line numberDiff line change
@@ -36,10 +36,16 @@ async def setUp(self):
3636
async def insert(self, participant_id, org, external_id):
3737
"""Directly insert into participant_external_id table"""
3838
query = """
39-
INSERT INTO participant_external_id (project, participant_id, name, external_id)
40-
VALUES (:project, :id, :org, :external_id)
39+
INSERT INTO participant_external_id (project, participant_id, name, external_id, audit_log_id)
40+
VALUES (:project, :id, :org, :external_id, :audit_log_id)
4141
"""
42-
values = {'project': self.project_id, 'id': participant_id, 'org': org, 'external_id': external_id}
42+
values = {
43+
'project': self.project_id,
44+
'id': participant_id,
45+
'org': org,
46+
'external_id': external_id,
47+
'audit_log_id': await self.audit_log_id(),
48+
}
4349
await self.connection.connection.execute(query, values)
4450

4551
@run_as_sync
@@ -53,9 +59,10 @@ async def test_constraints(self):
5359
with self.assertRaises(IntegrityError):
5460
await self.insert(self.p1.id, 'CONTROL', 'Maxwell')
5561

56-
# Can have eids in lots of organisations, even if the eid duplicates one in a different org
62+
# Can have eids in lots of organisations, but not if the eid duplicates one in a different org
5763
await self.insert(self.p1.id, 'OTHER1', 'Maxwell')
58-
await self.insert(self.p1.id, 'OTHER2', '86')
64+
with self.assertRaises(IntegrityError):
65+
await self.insert(self.p1.id, 'OTHER2', '86')
5966

6067
# Another participant can't have the same eid
6168
with self.assertRaises(IntegrityError):
@@ -76,11 +83,11 @@ async def test_insert(self):
7683

7784
result = await self.player.upsert_participant(
7885
ParticipantUpsertInternal(
79-
external_ids={PRIMARY_EXTERNAL_ORG: 'P10', 'A': 'A1', 'B': None, 'C': 'A1'},
86+
external_ids={PRIMARY_EXTERNAL_ORG: 'P10', 'A': 'A1', 'B': None, 'C': 'C1'},
8087
)
8188
)
8289
participants = await self.player.get_participants_by_ids([result.id])
83-
self.assertDictEqual(participants[0].external_ids, {PRIMARY_EXTERNAL_ORG: 'P10', 'a': 'A1', 'c': 'A1'})
90+
self.assertDictEqual(participants[0].external_ids, {PRIMARY_EXTERNAL_ORG: 'P10', 'a': 'A1', 'c': 'C1'})
8491

8592
@run_as_sync
8693
async def test_update(self):
@@ -215,10 +222,16 @@ async def setUp(self):
215222
async def insert(self, sample_id, org, external_id):
216223
"""Directly insert into sample_external_id table"""
217224
query = """
218-
INSERT INTO sample_external_id (project, sample_id, name, external_id)
219-
VALUES (:project, :id, :org, :external_id)
225+
INSERT INTO sample_external_id (project, sample_id, name, external_id, audit_log_id)
226+
VALUES (:project, :id, :org, :external_id, :audit_log_id)
220227
"""
221-
values = {'project': self.project_id, 'id': sample_id, 'org': org, 'external_id': external_id}
228+
values = {
229+
'project': self.project_id,
230+
'id': sample_id,
231+
'org': org,
232+
'external_id': external_id,
233+
'audit_log_id': await self.audit_log_id(),
234+
}
222235
await self.connection.connection.execute(query, values)
223236

224237
@run_as_sync
@@ -232,9 +245,10 @@ async def test_constraints(self):
232245
with self.assertRaises(IntegrityError):
233246
await self.insert(self.s1.id, 'CONTROL', 'Maxwell')
234247

235-
# Can have eids in lots of organisations, even if the eid duplicates one in a different org
248+
# Can have eids in lots of organisations, but not if the eid duplicates one in a different org
236249
await self.insert(self.s1.id, 'OTHER1', 'Maxwell')
237-
await self.insert(self.s1.id, 'OTHER2', '86')
250+
with self.assertRaises(IntegrityError):
251+
await self.insert(self.s1.id, 'OTHER2', '86')
238252

239253
# Another sample can't have the same eid
240254
with self.assertRaises(IntegrityError):
@@ -255,11 +269,11 @@ async def test_insert(self):
255269

256270
result = await self.slayer.upsert_sample(
257271
SampleUpsertInternal(
258-
external_ids={PRIMARY_EXTERNAL_ORG: 'S10', 'A': 'A1', 'B': None, 'C': 'A1'},
272+
external_ids={PRIMARY_EXTERNAL_ORG: 'S10', 'A': 'A1', 'B': None, 'C': 'C1'},
259273
)
260274
)
261275
sample = await self.slayer.get_sample_by_id(result.id)
262-
self.assertDictEqual(sample.external_ids, {PRIMARY_EXTERNAL_ORG: 'S10', 'a': 'A1', 'c': 'A1'})
276+
self.assertDictEqual(sample.external_ids, {PRIMARY_EXTERNAL_ORG: 'S10', 'a': 'A1', 'c': 'C1'})
263277

264278
@run_as_sync
265279
async def test_update(self):

0 commit comments

Comments
 (0)