Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

update code_to_name function #2991

Merged
merged 1 commit into from
Dec 1, 2023
Merged
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
195 changes: 195 additions & 0 deletions database/src/migrations/0080_update_code_to_name_again.ts
Original file line number Diff line number Diff line change
@@ -0,0 +1,195 @@
import { Knex } from 'knex';

export async function up(knex: Knex): Promise<void> {
await knex.raw(
`
set search_path=invasivesbc,public;

CREATE
OR REPLACE FUNCTION invasivesbc.code_to_name() RETURNS trigger LANGUAGE plpgsql AS $function$ BEGIN
set
search_path = invasivesbc,
public;
WITH species_code_by_activity_id AS (
select
aid.activity_incoming_data_id,
aid.activity_id,
species_positive_col as positive_code,
species_negative_col as negative_code,
species_treated_col as treated_code,
species_biocontrol as biocontrol_code
from
activity_incoming_data aid
left join jsonb_array_elements_text(
case jsonb_typeof(species_positive) when 'array' then species_positive else '[]' end
) species_positive_col on true
left join jsonb_array_elements_text(
case jsonb_typeof(species_negative) when 'array' then species_negative else '[]' end
) species_negative_col on true
left join jsonb_array_elements_text(
case jsonb_typeof(species_treated) when 'array' then species_treated else '[]' end
) species_treated_col on true
left join jsonb_array_elements(
case jsonb_typeof(
coalesce(
activity_payload #> '{form_data, activity_subtype_data, Biocontrol_Collection_Information}',
activity_payload #> '{form_data, activity_subtype_data, Monitoring_BiocontrolDispersal_Information}',
activity_payload #> '{form_data, activity_subtype_data, Monitoring_BiocontrolRelease_TerrestrialPlant_Information}',
activity_payload #> '{form_data, activity_subtype_data, Biocontrol_Release_Information}'))
when 'array' then coalesce(
activity_payload #> '{form_data, activity_subtype_data, Biocontrol_Collection_Information}',
activity_payload #> '{form_data, activity_subtype_data, Monitoring_BiocontrolDispersal_Information}',
activity_payload #> '{form_data, activity_subtype_data, Monitoring_BiocontrolRelease_TerrestrialPlant_Information}',
activity_payload #> '{form_data, activity_subtype_data, Biocontrol_Release_Information}')
else '[]' end
) species_biocontrol on true
where
aid.iscurrent
and aid.activity_id = new.activity_id
),
species_positive_translated_by_activity_id as (
select
im.char_code,
sid.positive_code,
im.invbc_name,
sid.activity_id,
sid.activity_incoming_data_id
from
iapp_invbc_mapping im
inner join species_code_by_activity_id sid on sid.positive_code = im.char_code
),
species_negative_translated_by_activity_id as (
select
im.char_code,
sid.negative_code,
im.invbc_name,
sid.activity_id,
sid.activity_incoming_data_id
from
iapp_invbc_mapping im
inner join species_code_by_activity_id sid on sid.negative_code = im.char_code
),
species_treated_translated_by_activity_id as (
select
im.char_code,
sid.treated_code,
im.invbc_name,
sid.activity_id,
sid.activity_incoming_data_id
from
iapp_invbc_mapping im
inner join species_code_by_activity_id sid on sid.treated_code = im.char_code
),
species_biocontrol_translated_by_activity_id as (
select
im.code_name,
sid.biocontrol_code ->> 'biological_agent_code',
im.code_description,
sid.activity_id,
sid.activity_incoming_data_id
from
code im
inner join species_code_by_activity_id sid on sid.biocontrol_code ->> 'biological_agent_code' = im.code_name
where
im.code_header_id = 43
),
species_positive_description_aggregated_by_activity_id as (
select
array_to_string(
ARRAY_AGG(distinct st.invbc_name),
', '
) as species_positive_full,
st.activity_id,
st.activity_incoming_data_id
from
species_positive_translated_by_activity_id st
group by
st.activity_id,
st.activity_incoming_data_id
),
species_negative_description_aggregated_by_activity_id as (
select
array_to_string(
ARRAY_AGG(distinct st.invbc_name),
', '
) as species_negative_full,
st.activity_id,
st.activity_incoming_data_id
from
species_negative_translated_by_activity_id st
group by
st.activity_id,
st.activity_incoming_data_id
),
species_treated_description_aggregated_by_activity_id as (
select
array_to_string(
ARRAY_AGG(distinct st.invbc_name),
', '
) as species_treated_full,
st.activity_id,
st.activity_incoming_data_id
from
species_treated_translated_by_activity_id st
group by
st.activity_id,
st.activity_incoming_data_id
),
species_biocontrol_description_aggregated_by_activity_id as (
select
array_to_string(
ARRAY_AGG(distinct st.code_description),
', '
) as species_biocontrol_full,
st.activity_id,
st.activity_incoming_data_id
from
species_biocontrol_translated_by_activity_id st
group by
st.activity_id,
st.activity_incoming_data_id
),
species_full_descriptions_by_activity_id as (
select
a.activity_id,
a.activity_incoming_data_id,
sp.species_positive_full,
sn.species_negative_full,
st.species_treated_full,
sb.species_biocontrol_full
from
activity_incoming_data a
left join species_positive_description_aggregated_by_activity_id sp on sp.activity_id = a.activity_id
left join species_negative_description_aggregated_by_activity_id sn on sn.activity_id = a.activity_id
left join species_treated_description_aggregated_by_activity_id st on st.activity_id = a.activity_id
left join species_biocontrol_description_aggregated_by_activity_id sb on sb.activity_id = a.activity_id
where
a.iscurrent
and a.activity_id = new.activity_id
)
UPDATE
activity_incoming_data aid
set
species_positive_full = sf.species_positive_full,
species_negative_full = sf.species_negative_full,
species_treated_full = sf.species_treated_full,
species_biocontrol_full = sf.species_biocontrol_full
FROM
species_full_descriptions_by_activity_id sf
WHERE
aid.activity_incoming_data_id = sf.activity_incoming_data_id
and aid.activity_incoming_data_id = new.activity_incoming_data_id
and aid.activity_id = new.activity_id;
RETURN NEW;
END $function$;
`
);
}

export async function down(knex: Knex): Promise<void> {
await knex.raw(`

set search_path = invasivesbc,public;

`);
}
Loading