Skip to content

Commit

Permalink
Merge pull request #114 from wasade/patch_patch_0055
Browse files Browse the repository at this point in the history
Revise patch 0055, create pg93 compatible query
  • Loading branch information
wasade committed Apr 21, 2020
2 parents a8718d1 + cb53330 commit 151c051
Show file tree
Hide file tree
Showing 2 changed files with 26 additions and 13 deletions.
23 changes: 17 additions & 6 deletions microsetta_private_api/db/patches/0055.sql
Original file line number Diff line number Diff line change
Expand Up @@ -19,22 +19,33 @@ CREATE TABLE barcodes.kit (

-- Now lets make sure the barcodes are associated to the kits
ALTER TABLE barcodes.barcode ADD COLUMN kit_id VARCHAR;
ALTER TABLE barcodes.barcode ADD CONSTRAINT fk_barcode_kit_id
FOREIGN KEY (kit_id) REFERENCES barcodes.kit (kit_id);

-- Let's make sure all existing kits are reflected in this
-- table
INSERT INTO barcodes.kit (kit_id)
SELECT supplied_kit_id
FROM ag.ag_kit;

-- and we need to also set the kit_id reference in the barcodes.barcode
-- table
DO $do$
DECLARE
k varchar;
rec RECORD;
BEGIN
FOR k IN
SELECT supplied_kit_id FROM ag.ag_kit
FOR rec IN
SELECT supplied_kit_id, barcode
FROM ag.ag_kit
JOIN ag.ag_kit_barcodes USING(ag_kit_id)
LOOP
INSERT INTO barcodes.kit (kit_id) VALUES (k);
UPDATE barcodes.barcode
SET kit_id = rec.supplied_kit_id
WHERE barcode=rec.barcode;
END LOOP;
END $do$;


-- And finally, let's establish FK relationships
ALTER TABLE ag.ag_kit ADD CONSTRAINT fk_barcode_schema_kit_id
FOREIGN KEY (supplied_kit_id) REFERENCES barcodes.kit (kit_id);
ALTER TABLE barcodes.barcode ADD CONSTRAINT fk_barcode_kit_id
FOREIGN KEY (kit_id) REFERENCES barcodes.kit (kit_id);
16 changes: 9 additions & 7 deletions microsetta_private_api/repo/admin_repo.py
Original file line number Diff line number Diff line change
Expand Up @@ -224,13 +224,15 @@ def create_kits(self, number_of_kits, number_of_samples, kit_prefix,
kit_barcodes_insert)

with self._transaction.dict_cursor() as cur:
cur.execute("SELECT kit_id, "
" kit_uuid, "
" array_agg(barcode) as sample_barcodes "
"FROM barcodes.kit "
"LEFT JOIN barcodes.barcode USING (kit_id)"
"WHERE kit_id IN %s "
"GROUP BY (kit_id, kit_uuid)", (tuple(names), ))
cur.execute("SELECT i.kit_id, o.kit_uuid, i.sample_barcodes "
"FROM (SELECT kit_id, "
" array_agg(barcode) as sample_barcodes "
" FROM barcodes.kit "
" JOIN barcodes.barcode USING (kit_id) "
" WHERE kit_id IN %s "
" GROUP BY kit_id) i "
"JOIN barcodes.kit o USING (kit_id)", (tuple(names), ))

created = [{'kit_id': k, 'kit_uuid': u, 'sample_barcodes': b}
for k, u, b in cur.fetchall()]

Expand Down

0 comments on commit 151c051

Please sign in to comment.