Skip to content

Commit d8a8277

Browse files
AS-3456: Update negative margin calculation by introducing Negative Margin Purchase Requirement. (#83)
1 parent 4c3c3e9 commit d8a8277

File tree

5 files changed

+298
-0
lines changed

5 files changed

+298
-0
lines changed

farms-liquibase/changelog.json

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -189,6 +189,11 @@
189189
"include": {
190190
"file": "scripts/01_00_xx/01_00_04/02/farms.01_00_04_02.ddl.json"
191191
}
192+
},
193+
{
194+
"include": {
195+
"file": "scripts/01_00_xx/01_00_04/03/farms.01_00_04_03.ddl.json"
196+
}
192197
}
193198
]
194199
}
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
GRANT EXECUTE ON PROCEDURE farms_negative_margin_pkg.calculate_negative_margins TO "app_farms_rest_proxy";
Lines changed: 216 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,216 @@
1+
create or replace procedure farms_negative_margin_pkg.calculate_negative_margins(
2+
in in_farming_operation_id farms.farm_farming_operations.farming_operation_id%type,
3+
in in_agristability_scenario_id farms.farm_agristability_scenarios.agristability_scenario_id%type,
4+
in in_user farms.farm_negative_margins.who_created%type
5+
)
6+
language plpgsql
7+
as
8+
$$
9+
begin
10+
execute $q$
11+
merge into farms.farm_negative_margins as o
12+
using (
13+
with ivpr as (
14+
select case when sv.year = 2024 then sv.year
15+
when bct.bpu_lead_ind = 'N' then (sv.year - 1)
16+
else sv.year
17+
end ivpr_year
18+
from farms.farm_scenarios_vw sv
19+
join farms.farm_reference_scenarios rs on rs.for_agristability_scenario_id = sv.agristability_scenario_id
20+
join farms.farm_scenarios_vw rsv on rsv.agristability_scenario_id = rs.agristability_scenario_id
21+
and rsv.year = (sv.year - 1)
22+
join farms.farm_benefit_calc_totals bct on bct.agristability_scenario_id = rsv.agristability_scenario_id
23+
where sv.agristability_scenario_id = in_agristability_scenario_id
24+
), a as (
25+
select nm.negative_margin_id,
26+
fo.farming_operation_id,
27+
acx.inventory_item_code,
28+
sv.agristability_scenario_id,
29+
nm.revision_count,
30+
iic.description as inventory_desc,
31+
nm.deductible_percentage,
32+
iid.insurable_value required_insurable_value,
33+
nm.insurable_value_purchased,
34+
sum(ri.quantity_produced) as reported,
35+
nm.guaranteed_prod_value,
36+
nm.premiums_paid,
37+
nm.claims_received,
38+
iid.premium_rate,
39+
ycp.parameter_value::numeric / 100 as negative_margin_purchase_requirement
40+
from farms.farm_farming_operations fo
41+
join farms.farm_scenarios_vw sv on sv.program_year_version_id = fo.program_year_version_id
42+
join farms.farm_reported_inventories ri on fo.farming_operation_id = ri.farming_operation_id
43+
and (
44+
ri.agristability_scenario_id = sv.agristability_scenario_id
45+
or coalesce(ri.agristability_scenario_id::text, '') = ''
46+
)
47+
join farms.farm_agristabilty_cmmdty_xref acx on ri.agristabilty_cmmdty_xref_id = acx.agristabilty_cmmdty_xref_id
48+
and acx.inventory_class_code in ('1','2')
49+
join farms.farm_inventory_item_codes iic on acx.inventory_item_code = iic.inventory_item_code
50+
join farms.farm_inventory_item_details iid on iic.inventory_item_code = iid.inventory_item_code
51+
left join farms.farm_negative_margins nm on fo.farming_operation_id = nm.farming_operation_id
52+
and acx.inventory_item_code = nm.inventory_item_code
53+
and nm.agristability_scenario_id = sv.agristability_scenario_id
54+
left join farm_year_configuration_params ycp on iid.program_year = ycp.program_year
55+
and 'Negative Margin Purchase Requirement' = ycp.parameter_name
56+
where fo.farming_operation_id = in_farming_operation_id
57+
and iid.program_year = coalesce((select ivpr_year from ivpr), sv.year)
58+
and (
59+
(iid.insurable_value is not null and iid.insurable_value::text <> '')
60+
or (iid.premium_rate is not null and iid.premium_rate::text <> '')
61+
)
62+
and sv.agristability_scenario_id = in_agristability_scenario_id
63+
group by nm.negative_margin_id,
64+
fo.farming_operation_id,
65+
acx.inventory_item_code,
66+
sv.agristability_scenario_id,
67+
nm.revision_count,
68+
iic.description,
69+
nm.deductible_percentage,
70+
iid.insurable_value,
71+
nm.insurable_value_purchased,
72+
nm.guaranteed_prod_value,
73+
nm.premiums_paid,
74+
nm.claims_received,
75+
iid.premium_rate,
76+
ycp.parameter_value
77+
having sum(ri.quantity_produced) != 0
78+
), claims_calc as (
79+
select a.*,
80+
(case
81+
when(a.guaranteed_prod_value - a.reported) >= 0 then (a.guaranteed_prod_value - a.reported) * a.negative_margin_purchase_requirement * a.required_insurable_value
82+
else 0
83+
end) as est_claims_received
84+
from a
85+
), premium_calc as (
86+
select cc.*,
87+
cc.guaranteed_prod_value * cc.negative_margin_purchase_requirement * cc.required_insurable_value * cc.premium_rate * 0.54 as required_premium
88+
from claims_calc cc
89+
), mrp_calc as (
90+
select pc.*,
91+
least(pc.required_premium * mrp.risk_charge_pct_premium / 100 + mrp.risk_charge_flat_amount + mrp.adjust_charge_flat_amount, 1000) as mrp_value
92+
from premium_calc pc
93+
left join farms.farm_market_rate_premium mrp on trunc(pc.required_premium) between mrp.min_total_premium_amount and mrp.max_total_premium_amount
94+
), deemed_premium_calc as (
95+
select mc.*,
96+
greatest(mc.required_premium + mc.mrp_value - mc.premiums_paid, 0) as deemed_premium
97+
from mrp_calc mc
98+
), deemed_received_calc as (
99+
select dpc.*,
100+
(case
101+
when dpc.est_claims_received - dpc.deemed_premium - dpc.claims_received > 0 then dpc.est_claims_received - dpc.deemed_premium - dpc.claims_received
102+
else 0
103+
end) as deemed_received
104+
from deemed_premium_calc dpc
105+
), deemed_pi_value_calc as (
106+
select drc.*,
107+
(case
108+
when drc.deductible_percentage > 30 or drc.required_insurable_value <> drc.insurable_value_purchased then drc.deemed_received
109+
else 0
110+
end) as deemed_pi_value
111+
from deemed_received_calc drc
112+
)
113+
select coalesce(dpvc.negative_margin_id, nm.negative_margin_id) negative_margin_id,
114+
coalesce(dpvc.farming_operation_id, nm.farming_operation_id) farming_operation_id,
115+
coalesce(dpvc.inventory_item_code, nm.inventory_item_code) inventory_item_code,
116+
coalesce(dpvc.agristability_scenario_id, nm.agristability_scenario_id) agristability_scenario_id,
117+
dpvc.revision_count,
118+
dpvc.inventory_desc,
119+
dpvc.deductible_percentage,
120+
dpvc.required_insurable_value,
121+
dpvc.insurable_value_purchased,
122+
dpvc.reported as reported_quantity,
123+
dpvc.guaranteed_prod_value,
124+
dpvc.premiums_paid,
125+
dpvc.claims_received,
126+
round((dpvc.deemed_received)::numeric, 2) as deemed_received,
127+
round((dpvc.deemed_pi_value)::numeric, 2) as deemed_pi_value,
128+
dpvc.premium_rate,
129+
round((dpvc.est_claims_received)::numeric, 2) as claims_calculation,
130+
round((dpvc.required_premium)::numeric, 2) as required_premium,
131+
round((dpvc.mrp_value)::numeric, 2) as market_rate_premium,
132+
round((dpvc.deemed_premium)::numeric, 2) as deemed_premium,
133+
case when coalesce(dpvc.farming_operation_id::text, '') = '' then 'Y' else 'N' end delete_row
134+
from deemed_pi_value_calc dpvc
135+
full outer join (
136+
select *
137+
from farms.farm_negative_margins
138+
where farming_operation_id = in_farming_operation_id
139+
and agristability_scenario_id = in_agristability_scenario_id
140+
) nm on nm.inventory_item_code = dpvc.inventory_item_code
141+
) n on o.farming_operation_id = in_farming_operation_id
142+
and o.agristability_scenario_id = in_agristability_scenario_id
143+
and o.farming_operation_id = n.farming_operation_id
144+
and o.inventory_item_code = n.inventory_item_code
145+
and o.agristability_scenario_id = n.agristability_scenario_id
146+
when matched then
147+
update set
148+
required_insurable_value = n.required_insurable_value,
149+
reported_quantity = n.reported_quantity,
150+
premium_rate = n.premium_rate,
151+
required_premium = n.required_premium,
152+
market_rate_premium = n.market_rate_premium,
153+
claims_calculation = n.claims_calculation,
154+
deemed_premium = n.deemed_premium,
155+
deemed_received = n.deemed_received,
156+
deemed_pi_value = n.deemed_pi_value,
157+
revision_count = revision_count + 1,
158+
who_updated = in_user,
159+
when_updated = current_timestamp
160+
161+
when matched and delete_row = 'Y' then
162+
delete
163+
164+
when not matched then
165+
insert (
166+
negative_margin_id,
167+
farming_operation_id,
168+
inventory_item_code,
169+
agristability_scenario_id,
170+
revision_count,
171+
deductible_percentage,
172+
required_insurable_value,
173+
insurable_value_purchased,
174+
reported_quantity,
175+
guaranteed_prod_value,
176+
premiums_paid,
177+
claims_received,
178+
deemed_received,
179+
deemed_pi_value,
180+
premium_rate,
181+
claims_calculation,
182+
required_premium,
183+
market_rate_premium,
184+
deemed_premium,
185+
who_created,
186+
when_created,
187+
who_updated,
188+
when_updated
189+
) values (
190+
nextval('farms.farm_nm_seq'),
191+
n.farming_operation_id,
192+
n.inventory_item_code,
193+
n.agristability_scenario_id,
194+
1,
195+
n.deductible_percentage,
196+
n.required_insurable_value,
197+
n.insurable_value_purchased,
198+
n.reported_quantity,
199+
n.guaranteed_prod_value,
200+
n.premiums_paid,
201+
n.claims_received,
202+
n.deemed_received,
203+
n.deemed_pi_value,
204+
n.premium_rate,
205+
n.claims_calculation,
206+
n.required_premium,
207+
n.market_rate_premium,
208+
n.deemed_premium,
209+
in_user,
210+
current_timestamp,
211+
in_user,
212+
current_timestamp
213+
);
214+
$q$;
215+
end;
216+
$$;
Lines changed: 45 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,45 @@
1+
insert into farms.farm_year_configuration_params (
2+
year_configuration_param_id,
3+
program_year,
4+
parameter_name,
5+
parameter_value,
6+
config_param_type_code,
7+
revision_count,
8+
who_created,
9+
when_created,
10+
who_updated,
11+
when_updated
12+
) values (
13+
nextval('farms.farm_ycp_seq'),
14+
2024,
15+
'Negative Margin Purchase Requirement',
16+
'70',
17+
'DECIMAL',
18+
1,
19+
'FARM_02_43_00-00',
20+
current_timestamp,
21+
'FARM_02_43_00-00',
22+
current_timestamp
23+
), (
24+
nextval('farms.farm_ycp_seq'),
25+
2025,
26+
'Negative Margin Purchase Requirement',
27+
'80',
28+
'DECIMAL',
29+
1,
30+
'FARM_02_43_00-00',
31+
current_timestamp,
32+
'FARM_02_43_00-00',
33+
current_timestamp
34+
), (
35+
nextval('farms.farm_ycp_seq'),
36+
2026,
37+
'Negative Margin Purchase Requirement',
38+
'80',
39+
'DECIMAL',
40+
1,
41+
'FARM_02_43_00-00',
42+
current_timestamp,
43+
'FARM_02_43_00-00',
44+
current_timestamp
45+
);
Lines changed: 31 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,31 @@
1+
{
2+
"databaseChangeLog": [
3+
{
4+
"changeSet": {
5+
"author": "hwang",
6+
"id": "39",
7+
"changes": [
8+
{
9+
"sqlFile": {
10+
"relativeToChangeLogFile": "true",
11+
"path": "dml/farms.farm_year_configuration_params.sql"
12+
}
13+
},
14+
{
15+
"sqlFile": {
16+
"relativeToChangeLogFile": "true",
17+
"splitStatements": "false",
18+
"path": "ddl/routines/farms_negative_margin_pkg.calculate_negative_margins.sql"
19+
}
20+
},
21+
{
22+
"sqlFile": {
23+
"relativeToChangeLogFile": "true",
24+
"path": "ddl/grants/farms.ddl.apply_grants.sql"
25+
}
26+
}
27+
]
28+
}
29+
}
30+
]
31+
}

0 commit comments

Comments
 (0)