Skip to content

Commit a47e746

Browse files
Feature/as 3090 create spo flow for cra import (#84)
* AS-3090: Fix type mismatch error in Postgres. * AS-3090: Fix type mismatch error for farms_staging_pkg.insert_z05. * AS-3090: Fix the issue of missing sin in new.
1 parent d8a8277 commit a47e746

File tree

8 files changed

+618
-6
lines changed

8 files changed

+618
-6
lines changed

farms-api/farms-persistence/src/main/java/ca/bc/gov/farms/persistence/v1/dao/mybatis/StagingDaoImpl.java

Lines changed: 6 additions & 6 deletions
Original file line numberDiff line numberDiff line change
@@ -211,18 +211,18 @@ public void insert(final Z05PartnerInfo obj, final String userId) throws SQLExce
211211
.prepareCall(
212212
"call farms_staging_pkg.insert_z05(?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)")) {
213213

214-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getPartnerInfoKey()));
215-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getParticipantPin()));
216-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getProgramYear()));
217-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getOperationNumber()));
214+
callableStatement.setObject(i++, toLong(obj.getPartnerInfoKey()), Types.BIGINT);
215+
callableStatement.setObject(i++, obj.getParticipantPin(), Types.INTEGER);
216+
callableStatement.setObject(i++, toShort(obj.getProgramYear()), Types.SMALLINT);
217+
callableStatement.setObject(i++, toShort(obj.getOperationNumber()), Types.SMALLINT);
218218

219-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getPartnershipPin()));
219+
callableStatement.setObject(i++, obj.getPartnershipPin(), Types.INTEGER);
220220
callableStatement.setString(i++, obj.getPartnerFirstName());
221221
callableStatement.setString(i++, obj.getPartnerLastName());
222222
callableStatement.setString(i++, obj.getPartnerCorpName());
223223
callableStatement.setString(i++, obj.getPartnerSinCtnBn());
224224
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getPartnerPercent()));
225-
callableStatement.setBigDecimal(i++, toBigDecimal(obj.getPartnerPin()));
225+
callableStatement.setObject(i++, obj.getPartnerPin(), Types.INTEGER);
226226
callableStatement.setString(i++, userId);
227227

228228
callableStatement.execute();

farms-liquibase/changelog.json

Lines changed: 10 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -194,6 +194,16 @@
194194
"include": {
195195
"file": "scripts/01_00_xx/01_00_04/03/farms.01_00_04_03.ddl.json"
196196
}
197+
},
198+
{
199+
"include": {
200+
"file": "scripts/01_00_xx/01_00_04/04/farms.01_00_04_04.ddl.json"
201+
}
202+
},
203+
{
204+
"include": {
205+
"file": "scripts/01_00_xx/01_00_04/05/farms.01_00_04_05.ddl.json"
206+
}
197207
}
198208
]
199209
}
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
GRANT EXECUTE ON FUNCTION farms_import_pkg.production_unit TO "app_farms_rest_proxy";
Lines changed: 119 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,119 @@
1+
create or replace function farms_import_pkg.production_unit(
2+
in in_version_id bigint,
3+
in in_user varchar
4+
)
5+
returns numeric
6+
language plpgsql
7+
as $$
8+
declare
9+
pu_cursor cursor for
10+
select z.production_unit,
11+
z.production_unit_description new_description,
12+
cu.description old_description
13+
from farms.farm_z28_prod_insurance_refs z
14+
left outer join farms.farm_crop_unit_codes cu on z.production_unit::varchar = cu.crop_unit_code
15+
where (cu.crop_unit_code is null
16+
or z.production_unit_description <> cu.description)
17+
and z.production_unit::varchar not in ('67', '70');
18+
pu_val record;
19+
20+
opened numeric := 0;
21+
closed numeric := 0;
22+
23+
exp_date date := null;
24+
errors numeric := 0;
25+
26+
v_production_unit farms.farm_z28_prod_insurance_refs.production_unit%type := null;
27+
begin
28+
-- type casts will not occur because they have been completed
29+
30+
for pu_val in pu_cursor
31+
loop
32+
v_production_unit := pu_val.production_unit;
33+
if opened < 1 then
34+
call farms_import_pkg.append_imp1(in_version_id, '<PRODUCTION_UNITS>');
35+
opened := 1;
36+
end if;
37+
38+
-- old pu codes are not removed though this process.
39+
begin
40+
if pu_val.old_description is null then
41+
call farms_import_pkg.append_imp1(in_version_id,
42+
'<PRODUCTION_UNIT crop_unit_code="' ||
43+
farms_import_pkg.scrub(pu_val.production_unit::varchar) || '" action="add">' ||
44+
'<ATTR name="description" new="' ||
45+
farms_import_pkg.scrub(pu_val.new_description) ||
46+
'"/></PRODUCTION_UNIT>');
47+
48+
exp_date := to_date('12/31/9999', 'MM/DD/YYYY');
49+
50+
insert into farms.farm_crop_unit_codes(
51+
crop_unit_code,
52+
description,
53+
established_date,
54+
expiry_date,
55+
revision_count,
56+
who_created,
57+
when_created,
58+
who_updated,
59+
when_updated
60+
) values (
61+
pu_val.production_unit::varchar,
62+
pu_val.new_description,
63+
current_date,
64+
exp_date,
65+
1,
66+
in_user,
67+
current_timestamp,
68+
in_user,
69+
current_timestamp
70+
);
71+
else
72+
call farms_import_pkg.append_imp1(in_version_id,
73+
'<PRODUCTION_UNIT crop_unit_code="' ||
74+
farms_import_pkg.scrub(pu_val.production_unit::varchar) || '" action="update">' ||
75+
'<ATTR name="description" old="' ||
76+
farms_import_pkg.scrub(pu_val.old_description) || '" new="' ||
77+
farms_import_pkg.scrub(pu_val.new_description) ||
78+
'"/></PRODUCTION_UNIT>');
79+
80+
update farms.farm_crop_unit_codes
81+
set description = pu_val.new_description,
82+
revision_count = revision_count + 1,
83+
who_updated = in_user,
84+
when_updated = current_timestamp
85+
where crop_unit_code = pu_val.production_unit::varchar;
86+
end if;
87+
exception
88+
when others then
89+
errors := errors + 1;
90+
91+
call farms_import_pkg.append_imp1(in_version_id,
92+
'<PRODUCTION_UNIT crop_unit_code="' ||
93+
farms_import_pkg.scrub(pu_val.production_unit::varchar) ||
94+
'" action="error"><ERROR>' ||
95+
farms_import_pkg.scrub(farms_error_pkg.codify_production_unit(sqlerrm,
96+
v_production_unit::varchar)) ||
97+
'</ERROR></PRODUCTION_UNIT>');
98+
end;
99+
end loop;
100+
101+
if opened > 0 then
102+
call farms_import_pkg.append_imp1(in_version_id, '</PRODUCTION_UNITS>');
103+
closed := 1;
104+
end if;
105+
106+
return errors;
107+
exception
108+
when others then
109+
if opened > 0 and closed < 1 then
110+
call farms_import_pkg.append_imp1(in_version_id, '</PRODUCTION_UNITS>');
111+
end if;
112+
113+
call farms_import_pkg.append_imp1(in_version_id, -- generic error
114+
'<ERROR>' || farms_import_pkg.scrub(farms_error_pkg.codify(sqlerrm)) ||
115+
'</ERROR>');
116+
117+
return errors + 1;
118+
end;
119+
$$;
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
{
2+
"databaseChangeLog": [
3+
{
4+
"changeSet": {
5+
"author": "hwang",
6+
"id": "40",
7+
"changes": [
8+
{
9+
"sqlFile": {
10+
"relativeToChangeLogFile": "true",
11+
"splitStatements": "false",
12+
"path": "ddl/routines/farms_import_pkg.production_unit.sql"
13+
}
14+
},
15+
{
16+
"sqlFile": {
17+
"relativeToChangeLogFile": "true",
18+
"path": "ddl/grants/farms.ddl.apply_grants.sql"
19+
}
20+
}
21+
]
22+
}
23+
}
24+
]
25+
}
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
GRANT EXECUTE ON FUNCTION farms_import_pkg.participant TO "app_farms_rest_proxy";

0 commit comments

Comments
 (0)