Skip to content
This repository was archived by the owner on Aug 1, 2025. It is now read-only.

Commit ea85b8c

Browse files
committed
[BI-2304] - fixed migration
1 parent 3377138 commit ea85b8c

File tree

1 file changed

+50
-48
lines changed

1 file changed

+50
-48
lines changed
Lines changed: 50 additions & 48 deletions
Original file line numberDiff line numberDiff line change
@@ -1,7 +1,7 @@
11

22
-- This migration updates existing list_item records based on DeltaBreed (Breeding Insight) specific fields.
33
--
4-
-- These are the list types, since the BJTS uses Java enums, they are stored as int in the database.
4+
-- These are the list types, the BJTS uses Java enums and stores ints in the database.
55
-- 0: germplasm
66
-- 1: markers
77
-- 2: programs
@@ -12,53 +12,55 @@
1212
-- 7: observationVariables
1313
-- 8: samples
1414

15+
DO
16+
$$
17+
BEGIN
18+
-- Update germplasm list items, the goal is to use the order defined by the listEntryNumbers.
19+
UPDATE
20+
list_item
21+
SET
22+
position = subquery.position
23+
FROM
24+
(
25+
SELECT
26+
row_number() OVER (PARTITION BY li.list_id ORDER BY (g.additional_info->'listEntryNumbers'->>xr.external_reference_id)::int) AS position,
27+
li.id AS list_item_id
28+
FROM
29+
list_item li
30+
JOIN list l ON li.list_id = l.id
31+
JOIN list_external_references ler ON l.id = ler.list_entity_id
32+
JOIN external_reference xr ON xr.id = ler.external_references_id AND xr.external_reference_source = 'breedinginsight.org/lists'
33+
JOIN germplasm g ON li.item = g.germplasm_name
34+
WHERE
35+
l.list_type = 0 -- 0 is germplasm
36+
ORDER BY
37+
l.id
38+
) AS subquery
39+
WHERE
40+
list_item.id = subquery.list_item_id
41+
;
1542

16-
-- Update germplasm list items, the goal is to use the order defined by the listEntryNumbers.
17-
UPDATE
18-
list_item
19-
SET
20-
position = subquery.position
21-
FROM
22-
(
23-
SELECT
24-
row_number() OVER (PARTITION BY li.list_id ORDER BY (g.additional_info->'listEntryNumbers'->>xr.external_reference_id)::int) AS position,
25-
li.id AS list_item_id
26-
FROM
27-
list_item li
43+
-- Update all non-germplasm list items. There is no existing order to preserve, assign sequential position values arbitrarily.
44+
UPDATE
45+
list_item
46+
SET
47+
position = subquery.position
48+
FROM
49+
(
50+
SELECT
51+
row_number() OVER (PARTITION BY li.list_id) AS position,
52+
li.id AS list_item_id
53+
FROM
54+
list_item li
2855
JOIN list l ON li.list_id = l.id
29-
JOIN list_external_references ler ON l.id = ler.list_entity_id
30-
JOIN external_reference xr ON xr.id = ler.external_references_id AND xr.external_reference_source = 'breedinginsight.org/lists'
31-
JOIN germplasm g ON li.item = g.germplasm_name
32-
WHERE
33-
l.list_type = 0 -- 0 is germplasm
34-
ORDER BY
35-
l.id
36-
) AS subquery
37-
WHERE
38-
list_item.id = subquery.list_item_id
39-
;
56+
WHERE
57+
l.list_type != 0 -- 0 is germplasm, here we are addressing non-germplasm lists.
58+
ORDER BY
59+
l.id
60+
) AS subquery
61+
WHERE
62+
list_item.id = subquery.list_item_id
63+
;
4064

41-
-- Update all non-germplasm list items. There is no existing order to preserve, assign sequential position values arbitrarily.
42-
UPDATE
43-
list_item
44-
SET
45-
position = subquery.position
46-
FROM
47-
(
48-
SELECT
49-
row_number() OVER (PARTITION BY li.list_id) AS position,
50-
li.id AS list_item_id
51-
FROM
52-
list_item li
53-
JOIN list l ON li.list_id = l.id
54-
JOIN list_external_references ler ON l.id = ler.list_entity_id
55-
JOIN external_reference xr ON xr.id = ler.external_references_id AND xr.external_reference_source = 'breedinginsight.org/lists'
56-
JOIN germplasm g ON li.item = g.germplasm_name
57-
WHERE
58-
l.list_type != 0 -- 0 is germplasm, here we are addressing non-germplasm lists.
59-
ORDER BY
60-
l.id
61-
) AS subquery
62-
WHERE
63-
list_item.id = subquery.list_item_id
64-
;
65+
END;
66+
$$;

0 commit comments

Comments
 (0)