Skip to content

Commit 4c3c3e9

Browse files
Feature/as 2549 fix database packages (#82)
* AS-2549: Implement farms_import_pkg.reported_inventory. * AS-2549: Implement farms_staging_pkg.insert_z21. * AS-2549: Implement farms_staging_pkg.insert_z40. * AS-2549: Add changelog.
1 parent f5f4a3f commit 4c3c3e9

File tree

6 files changed

+375
-0
lines changed

6 files changed

+375
-0
lines changed

farms-liquibase/changelog.json

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -184,6 +184,11 @@
184184
"include": {
185185
"file": "scripts/01_00_xx/01_00_04/01/farms.01_00_04_01.ddl.json"
186186
}
187+
},
188+
{
189+
"include": {
190+
"file": "scripts/01_00_xx/01_00_04/02/farms.01_00_04_02.ddl.json"
191+
}
187192
}
188193
]
189194
}
Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,3 @@
1+
GRANT EXECUTE ON FUNCTION farms_import_pkg.reported_inventory TO "app_farms_rest_proxy";
2+
GRANT EXECUTE ON PROCEDURE farms_staging_pkg.insert_z21 TO "app_farms_rest_proxy";
3+
GRANT EXECUTE ON PROCEDURE farms_staging_pkg.insert_z40 TO "app_farms_rest_proxy";
Lines changed: 188 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,188 @@
1+
create or replace function farms_import_pkg.reported_inventory(
2+
in in_program_year_version_id farms.farm_program_year_versions.program_year_version_id%type,
3+
in in_user varchar
4+
)
5+
returns varchar
6+
language plpgsql
7+
as $$
8+
declare
9+
Unknown constant varchar := '-1';
10+
inv_insert_cursor cursor for
11+
select z21.inventory_code::varchar inventory_item_code,
12+
z21.inventory_type_code::varchar inventory_class_code,
13+
z21.crop_unit_type::varchar crop_unit_code,
14+
z21.crop_qty_produced quantity_produced,
15+
z21.crop_on_farm_acres on_farm_acres,
16+
z21.crop_unseedable_acres unseedable_acres,
17+
z21.quantity_end quantity_end,
18+
null price_end,
19+
null price_start,
20+
null start_of_year_amount,
21+
z21.end_of_year_amount end_of_year_amount,
22+
null quantity_start,
23+
z21.end_of_year_price end_year_producer_price,
24+
'N' accept_producer_price_ind,
25+
null aarm_reference_p1_price,
26+
null aarm_reference_p2_price,
27+
op.farming_operation_id,
28+
(case
29+
when x.agristabilty_cmmdty_xref_id is not null then null
30+
else z21.inventory_code || ' ' || z21.inventory_type_code
31+
end) import_comment,
32+
coalesce(x.agristabilty_cmmdty_xref_id, x2.agristabilty_cmmdty_xref_id) agristabilty_cmmdty_xref_id
33+
from farms.farm_z21_participant_suppls z21
34+
left outer join farms.farm_agristabilty_cmmdty_xref x on z21.inventory_code::varchar = x.inventory_item_code
35+
and z21.inventory_type_code::varchar = x.inventory_class_code
36+
left outer join farms.farm_agristabilty_cmmdty_xref x2 on x2.inventory_class_code = z21.inventory_type_code::varchar
37+
and x2.inventory_item_code = Unknown
38+
join farms.farm_agristability_clients ac on z21.participant_pin = ac.participant_pin
39+
join farms.farm_program_years py on ac.agristability_client_id = py.agristability_client_id
40+
and z21.program_year = py.year
41+
join farms.farm_program_year_versions pyv on py.program_year_id = pyv.program_year_id
42+
join farms.farm_farming_operations op on pyv.program_year_version_id = op.program_year_version_id
43+
and op.operation_number = z21.operation_number
44+
where pyv.program_year_version_id = in_program_year_version_id
45+
union all
46+
select zz.inventory_code::varchar inventory_item_code,
47+
zz.inventory_type_code::varchar inventory_class_code,
48+
zz.production_unit::varchar crop_unit_code,
49+
zz.crop_qty_produced quantity_produced,
50+
zz.crop_on_farm_acres on_farm_acres,
51+
null unseedable_acres,
52+
zz.quantity_end,
53+
zz.end_year_price price_end,
54+
zz.starting_price price_start,
55+
zz.quantity_start start_of_year_amount,
56+
zz.quantity_end end_of_year_amount,
57+
zz.quantity_start,
58+
zz.end_year_producer_price,
59+
zz.accept_producer_price_ind,
60+
zz.aarm_reference_p1_price,
61+
zz.aarm_reference_p2_price,
62+
op.farming_operation_id,
63+
(case
64+
when x.agristabilty_cmmdty_xref_id is not null then null
65+
else zz.inventory_code || ' ' || zz.inventory_type_code
66+
end) import_comment,
67+
coalesce(x.agristabilty_cmmdty_xref_id, x2.agristabilty_cmmdty_xref_id) agristabilty_cmmdty_xref_id
68+
from (
69+
select z40.*
70+
from farms.farm_z40_prtcpnt_ref_supl_dtls z40
71+
left outer join farms.farm_aarm_margins aarm on aarm.participant_pin = z40.participant_pin
72+
and aarm.program_year = z40.program_year
73+
and aarm.operation_number = z40.operation_number
74+
and aarm.inventory_type_code = z40.inventory_type_code
75+
and aarm.inventory_code = z40.inventory_code
76+
and (aarm.production_unit = z40.production_unit
77+
or (aarm.production_unit is null and z40.production_unit is null))
78+
where aarm.aarm_margin_id is null
79+
) zz
80+
left outer join farms.farm_agristabilty_cmmdty_xref x on zz.inventory_code::varchar = x.inventory_item_code
81+
and zz.inventory_type_code::varchar = x.inventory_class_code
82+
left outer join farms.farm_agristabilty_cmmdty_xref x2 on x2.inventory_class_code = zz.inventory_type_code::varchar
83+
and x2.inventory_item_code = Unknown
84+
join farms.farm_agristability_clients ac on zz.participant_pin = ac.participant_pin
85+
join farms.farm_program_years py on ac.agristability_client_id = py.agristability_client_id
86+
and zz.program_year = py.year
87+
join farms.farm_program_year_versions pyv on py.program_year_id = pyv.program_year_id
88+
join farms.farm_farming_operations op on pyv.program_year_version_id = op.program_year_version_id
89+
and op.operation_number = zz.operation_number
90+
where pyv.program_year_version_id = in_program_year_version_id;
91+
inv_insert_val record;
92+
93+
ri_id farms.farm_reported_inventories.reported_inventory_id%type;
94+
95+
v_inventory_item_code farms.farm_agristabilty_cmmdty_xref.inventory_item_code%type := null;
96+
v_inventory_class_code farms.farm_agristabilty_cmmdty_xref.inventory_class_code%type := null;
97+
v_crop_unit_code farms.farm_reported_inventories.crop_unit_code%type := null;
98+
v_farming_operation_id farms.farm_reported_inventories.farming_operation_id%type := null;
99+
begin
100+
101+
call farms_import_pkg.setup_unknown_codes();
102+
103+
for inv_insert_val in inv_insert_cursor
104+
loop
105+
v_inventory_item_code := inv_insert_val.inventory_item_code;
106+
v_inventory_class_code := inv_insert_val.inventory_class_code;
107+
v_crop_unit_code := inv_insert_val.crop_unit_code;
108+
v_farming_operation_id := inv_insert_val.farming_operation_id;
109+
110+
if v_inventory_class_code is null or inv_insert_val.agristabilty_cmmdty_xref_id is null then
111+
return farms_import_pkg.scrub(farms_error_pkg.codify_reported_inventory(
112+
'INV_CLS_CD',
113+
v_inventory_item_code,
114+
v_inventory_class_code,
115+
v_crop_unit_code,
116+
v_farming_operation_id
117+
));
118+
end if;
119+
120+
select nextval('farms.farm_ri_seq')
121+
into ri_id;
122+
123+
insert into farms.farm_reported_inventories (
124+
reported_inventory_id,
125+
price_start,
126+
price_end,
127+
end_year_producer_price,
128+
quantity_end,
129+
start_of_year_amount,
130+
end_of_year_amount,
131+
quantity_produced,
132+
on_farm_acres,
133+
unseedable_acres,
134+
quantity_start,
135+
accept_producer_price_ind,
136+
aarm_reference_p1_price,
137+
aarm_reference_p2_price,
138+
import_comment,
139+
agristabilty_cmmdty_xref_id,
140+
crop_unit_code,
141+
farming_operation_id,
142+
agristability_scenario_id,
143+
revision_count,
144+
who_created,
145+
when_created,
146+
who_updated,
147+
when_updated
148+
) values (
149+
ri_id,
150+
inv_insert_val.price_start,
151+
inv_insert_val.price_end,
152+
inv_insert_val.end_year_producer_price,
153+
inv_insert_val.quantity_end,
154+
inv_insert_val.start_of_year_amount,
155+
inv_insert_val.end_of_year_amount,
156+
inv_insert_val.quantity_produced,
157+
inv_insert_val.on_farm_acres,
158+
inv_insert_val.unseedable_acres,
159+
inv_insert_val.quantity_start,
160+
inv_insert_val.accept_producer_price_ind,
161+
inv_insert_val.aarm_reference_p1_price,
162+
inv_insert_val.aarm_reference_p2_price,
163+
inv_insert_val.import_comment,
164+
inv_insert_val.agristabilty_cmmdty_xref_id,
165+
inv_insert_val.crop_unit_code,
166+
inv_insert_val.farming_operation_id,
167+
null,
168+
1,
169+
in_user,
170+
current_timestamp,
171+
in_user,
172+
current_timestamp
173+
);
174+
175+
end loop;
176+
177+
return null;
178+
exception
179+
when others then
180+
return farms_import_pkg.scrub(farms_error_pkg.codify_reported_inventory(
181+
sqlerrm,
182+
v_inventory_item_code,
183+
v_inventory_class_code,
184+
v_crop_unit_code,
185+
v_farming_operation_id
186+
));
187+
end;
188+
$$;
Lines changed: 64 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,64 @@
1+
create or replace procedure farms_staging_pkg.insert_z21(
2+
in in_inventory_key farms.farm_z21_participant_suppls.inventory_key%type,
3+
in in_participant_pin farms.farm_z21_participant_suppls.participant_pin%type,
4+
in in_program_year farms.farm_z21_participant_suppls.program_year%type,
5+
in in_operation_number farms.farm_z21_participant_suppls.operation_number%type,
6+
in in_inventory_type_code farms.farm_z21_participant_suppls.inventory_type_code%type,
7+
in in_inventory_code farms.farm_z21_participant_suppls.inventory_code%type,
8+
in in_crop_unit_type farms.farm_z21_participant_suppls.crop_unit_type%type,
9+
in in_crop_on_farm_acres farms.farm_z21_participant_suppls.crop_on_farm_acres%type,
10+
in in_crop_qty_produced farms.farm_z21_participant_suppls.crop_qty_produced%type,
11+
in in_quantity_end farms.farm_z21_participant_suppls.quantity_end%type,
12+
in in_end_of_year_price farms.farm_z21_participant_suppls.end_of_year_price%type,
13+
in in_end_of_year_amount farms.farm_z21_participant_suppls.end_of_year_amount%type,
14+
in in_crop_unseedable_acres farms.farm_z21_participant_suppls.crop_unseedable_acres%type,
15+
in in_user varchar
16+
)
17+
language plpgsql
18+
as $$
19+
begin
20+
insert into farms.farm_z21_participant_suppls (
21+
inventory_key,
22+
participant_pin,
23+
program_year,
24+
operation_number,
25+
inventory_type_code,
26+
inventory_code,
27+
crop_unit_type,
28+
crop_on_farm_acres,
29+
crop_qty_produced,
30+
quantity_end,
31+
end_of_year_price,
32+
end_of_year_amount,
33+
crop_unseedable_acres,
34+
revision_count,
35+
who_created,
36+
when_created,
37+
who_updated,
38+
when_updated
39+
) values (
40+
in_inventory_key,
41+
in_participant_pin,
42+
in_program_year,
43+
in_operation_number,
44+
in_inventory_type_code,
45+
in_inventory_code,
46+
case in_crop_unit_type
47+
when '67' then '10'
48+
when '70' then '15'
49+
else in_crop_unit_type
50+
end,
51+
in_crop_on_farm_acres,
52+
in_crop_qty_produced,
53+
in_quantity_end,
54+
in_end_of_year_price,
55+
in_end_of_year_amount,
56+
in_crop_unseedable_acres,
57+
1,
58+
in_user,
59+
current_timestamp,
60+
in_user,
61+
current_timestamp
62+
);
63+
end;
64+
$$;
Lines changed: 76 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,76 @@
1+
create or replace procedure farms_staging_pkg.insert_z40(
2+
in in_prior_year_supplemental_key farms.farm_z40_prtcpnt_ref_supl_dtls.prior_year_supplemental_key%type,
3+
in in_participant_pin farms.farm_z40_prtcpnt_ref_supl_dtls.participant_pin%type,
4+
in in_program_year farms.farm_z40_prtcpnt_ref_supl_dtls.program_year%type,
5+
in in_operation_number farms.farm_z40_prtcpnt_ref_supl_dtls.operation_number%type,
6+
in in_production_unit farms.farm_z40_prtcpnt_ref_supl_dtls.production_unit%type,
7+
in in_inventory_type_code farms.farm_z40_prtcpnt_ref_supl_dtls.inventory_type_code%type,
8+
in in_inventory_code farms.farm_z40_prtcpnt_ref_supl_dtls.inventory_code%type,
9+
in in_quantity_start farms.farm_z40_prtcpnt_ref_supl_dtls.quantity_start%type,
10+
in in_starting_price farms.farm_z40_prtcpnt_ref_supl_dtls.starting_price%type,
11+
in in_crop_on_farm_acres farms.farm_z40_prtcpnt_ref_supl_dtls.crop_on_farm_acres%type,
12+
in in_crop_qty_produced farms.farm_z40_prtcpnt_ref_supl_dtls.crop_qty_produced%type,
13+
in in_quantity_end farms.farm_z40_prtcpnt_ref_supl_dtls.quantity_end%type,
14+
in in_end_year_producer_price farms.farm_z40_prtcpnt_ref_supl_dtls.end_year_producer_price%type,
15+
in in_accept_producer_price_ind farms.farm_z40_prtcpnt_ref_supl_dtls.accept_producer_price_ind%type,
16+
in in_end_year_price farms.farm_z40_prtcpnt_ref_supl_dtls.end_year_price%type,
17+
in in_aarm_reference_p1_price farms.farm_z40_prtcpnt_ref_supl_dtls.aarm_reference_p1_price%type,
18+
in in_aarm_reference_p2_price farms.farm_z40_prtcpnt_ref_supl_dtls.aarm_reference_p2_price%type,
19+
in in_user varchar
20+
)
21+
language plpgsql
22+
as $$
23+
begin
24+
insert into farms.farm_z40_prtcpnt_ref_supl_dtls (
25+
prior_year_supplemental_key,
26+
participant_pin,
27+
program_year,
28+
operation_number,
29+
production_unit,
30+
inventory_type_code,
31+
inventory_code,
32+
quantity_start,
33+
starting_price,
34+
crop_on_farm_acres,
35+
crop_qty_produced,
36+
quantity_end,
37+
end_year_producer_price,
38+
accept_producer_price_ind,
39+
end_year_price,
40+
aarm_reference_p1_price,
41+
aarm_reference_p2_price,
42+
revision_count,
43+
who_created,
44+
when_created,
45+
who_updated,
46+
when_updated
47+
) values (
48+
in_prior_year_supplemental_key,
49+
in_participant_pin,
50+
in_program_year,
51+
in_operation_number,
52+
case in_production_unit
53+
when '67' then '10'
54+
when '70' then '15'
55+
else in_production_unit
56+
end,
57+
in_inventory_type_code,
58+
in_inventory_code,
59+
in_quantity_start,
60+
in_starting_price,
61+
in_crop_on_farm_acres,
62+
in_crop_qty_produced,
63+
in_quantity_end,
64+
in_end_year_producer_price,
65+
in_accept_producer_price_ind,
66+
in_end_year_price,
67+
in_aarm_reference_p1_price,
68+
in_aarm_reference_p2_price,
69+
1,
70+
in_user,
71+
current_timestamp,
72+
in_user,
73+
current_timestamp
74+
);
75+
end;
76+
$$;
Lines changed: 39 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,39 @@
1+
{
2+
"databaseChangeLog": [
3+
{
4+
"changeSet": {
5+
"author": "hwang",
6+
"id": "38",
7+
"changes": [
8+
{
9+
"sqlFile": {
10+
"relativeToChangeLogFile": "true",
11+
"splitStatements": "false",
12+
"path": "ddl/routines/farms_import_pkg.reported_inventory.sql"
13+
}
14+
},
15+
{
16+
"sqlFile": {
17+
"relativeToChangeLogFile": "true",
18+
"splitStatements": "false",
19+
"path": "ddl/routines/farms_staging_pkg.insert_z21.sql"
20+
}
21+
},
22+
{
23+
"sqlFile": {
24+
"relativeToChangeLogFile": "true",
25+
"splitStatements": "false",
26+
"path": "ddl/routines/farms_staging_pkg.insert_z40.sql"
27+
}
28+
},
29+
{
30+
"sqlFile": {
31+
"relativeToChangeLogFile": "true",
32+
"path": "ddl/grants/farms.ddl.apply_grants.sql"
33+
}
34+
}
35+
]
36+
}
37+
}
38+
]
39+
}

0 commit comments

Comments
 (0)