File tree Expand file tree Collapse file tree 2 files changed +107
-0
lines changed
src/main/resources/db/migration Expand file tree Collapse file tree 2 files changed +107
-0
lines changed Original file line number Diff line number Diff line change 1+ -- See the NOTICE file distributed with this work for additional information
2+ -- regarding copyright ownership.
3+ --
4+ -- Licensed under the Apache License, Version 2.0 (the "License");
5+ -- you may not use this file except in compliance with the License.
6+ -- You may obtain a copy of the License at
7+ --
8+ -- http://www.apache.org/licenses/LICENSE-2.0
9+ --
10+ -- Unless required by applicable law or agreed to in writing, software
11+ -- distributed under the License is distributed on an "AS IS" BASIS,
12+ -- WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
13+ -- See the License for the specific language governing permissions and
14+ -- limitations under the License.
15+
16+ -- Updates trial.additional_info to have a datasets array instead of just observationDatasetId.
17+ -- Leaves observationDatasetId in place out of an abundance of caution.
18+ -- Only updates rows that don't already have datasets key (just in case the code was updated prematurely).
19+ DO
20+ $$
21+ BEGIN
22+ UPDATE
23+ trial
24+ SET
25+ additional_info = additional_info
26+ || JSONB_BUILD_OBJECT(
27+ ' datasets' ,
28+ JSONB_BUILD_ARRAY(
29+ JSONB_BUILD_OBJECT(
30+ ' id' , additional_info- > ' observationDatasetId' ,
31+ ' name' , additional_info- > ' defaultObservationLevel' ,
32+ ' level' , ' 0'
33+ )
34+ )
35+ )
36+ WHERE
37+ additional_info- > ' datasets' IS NULL ;
38+ END
39+ $$;
Original file line number Diff line number Diff line change 1+
2+ -- This migration updates existing list_item records based on DeltaBreed (Breeding Insight) specific fields.
3+ --
4+ -- These are the list types, the BJTS uses Java enums and stores ints in the database.
5+ -- 0: germplasm
6+ -- 1: markers
7+ -- 2: programs
8+ -- 3: trials
9+ -- 4: studies
10+ -- 5: observationUnits
11+ -- 6: observations
12+ -- 7: observationVariables
13+ -- 8: samples
14+
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+ -- Subtract 1 from row_number to get zero indexing.
27+ row_number() OVER (PARTITION BY li .list_id ORDER BY (g .additional_info - > ' listEntryNumbers' - >> xr .external_reference_id ::text )::int ) - 1 AS position,
28+ li .id AS list_item_id
29+ FROM
30+ list_item li
31+ JOIN list l ON li .list_id = l .id
32+ JOIN list_external_references ler ON l .id = ler .list_entity_id
33+ JOIN external_reference xr ON xr .id = ler .external_references_id AND xr .external_reference_source = ' breedinginsight.org/lists'
34+ JOIN germplasm g ON li .item = g .germplasm_name
35+ WHERE
36+ l .list_type = 0 -- 0 is germplasm
37+ ORDER BY
38+ l .id
39+ ) AS subquery
40+ WHERE
41+ list_item .id = subquery .list_item_id
42+ ;
43+
44+ -- Update all non-germplasm list items. There is no existing order to preserve, assign sequential position values arbitrarily.
45+ UPDATE
46+ list_item
47+ SET
48+ position = subquery .position
49+ FROM
50+ (
51+ SELECT
52+ -- Subtract 1 from row_number to get zero indexing.
53+ row_number() OVER (PARTITION BY li .list_id ) - 1 AS position,
54+ li .id AS list_item_id
55+ FROM
56+ list_item li
57+ JOIN list l ON li .list_id = l .id
58+ WHERE
59+ l .list_type != 0 -- 0 is germplasm, here we are addressing non-germplasm lists.
60+ ORDER BY
61+ l .id
62+ ) AS subquery
63+ WHERE
64+ list_item .id = subquery .list_item_id
65+ ;
66+
67+ END;
68+ $$;
You can’t perform that action at this time.
0 commit comments