Commit 73fae146 authored by Frank Bergmann's avatar Frank Bergmann

- Fixed AEC issue with exchanges rates not filling holes

parent 225b6799
...@@ -32,7 +32,7 @@ create table im_exchange_rates ( ...@@ -32,7 +32,7 @@ create table im_exchange_rates (
-- Fill "holes" (=missing exchange rate entries) -- Fill "holes" (=missing exchange rate entries)
-- with the values from the last manually entered -- with the values from the last manually entered
-- rates. This procedure is "idempotent", so it -- rates. This procedure is "idempotent", so it
-- can be executed at any time. -- can be executed at any time.
create or replace function im_exchange_rate_fill_holes (varchar, date, date) create or replace function im_exchange_rate_fill_holes (varchar, date, date)
returns integer as $body$ returns integer as $body$
...@@ -43,60 +43,67 @@ DECLARE ...@@ -43,60 +43,67 @@ DECLARE
v_rate numeric; v_rate numeric;
row2 RECORD; row2 RECORD;
exists integer; v_exists_p integer;
v_manual_p boolean;
BEGIN BEGIN
RAISE NOTICE 'im_exchange_rate_fill_holes: cur=%, start=%, end=%', p_currency, p_start_date, p_end_date; RAISE NOTICE 'im_exchange_rate_fill_holes: cur=%, start=%, end=%', p_currency, p_start_date, p_end_date;
-- Loop through all dates and check if there -- Loop through all dates and check if there
-- is a hole (no entry for a date) -- is a hole (no entry for a date)
FOR row2 IN FOR row2 IN
select im_day_enumerator as day select im_day_enumerator as day
from im_day_enumerator(p_start_date, p_end_date) from im_day_enumerator(p_start_date, p_end_date)
LEFT OUTER JOIN ( LEFT OUTER JOIN (
select * select *
from im_exchange_rates from im_exchange_rates
where currency = p_currency where currency = p_currency
) ex on (im_day_enumerator = ex.day) ) ex on (im_day_enumerator = ex.day)
where ex.rate is null where 1=1 -- ex.rate is null
LOOP LOOP
-- RAISE NOTICE 'im_exchange_rate_fill_holes: day=%', row2.day; -- RAISE NOTICE 'im_exchange_rate_fill_holes: cur=%, day=%', p_currency, row2.day;
-- get the latest manually entered exchange rate -- get the latest manually entered exchange rate
select rate select rate into v_rate
into v_rate from im_exchange_rates
from im_exchange_rates where day = (
where day = ( select max(day)
select max(day) from im_exchange_rates
from im_exchange_rates where day < row2.day
where day < row2.day
and currency = p_currency and currency = p_currency
and manual_p = 't' and manual_p = 't'
) )
and currency = p_currency; and currency = p_currency;
-- RAISE NOTICE 'im_exchange_rate_fill_holes: rate=%', v_rate; -- RAISE NOTICE 'im_exchange_rate_fill_holes: rate=%', v_rate;
-- use the latest exchange rate for the next few years... -- use the latest exchange rate for the next few years...
select count(*) into exists select 1, manual_p into v_exists_p, v_manual_p
from im_exchange_rates from im_exchange_rates
where day=row2.day and currency=p_currency; where day = row2.day and currency = p_currency;
IF exists > 0 THEN
IF (v_manual_p) THEN continue; END IF; -- never overwrite manually entered values
IF v_exists_p > 0 THEN
update im_exchange_rates update im_exchange_rates
set rate = v_rate, set rate = v_rate,
manual_p = 'f' manual_p = 'f'
where day = row2.day where day = row2.day
and currency = p_currency; and currency = p_currency;
ELSE ELSE
RAISE NOTICE 'im_exchange_rate_fill_holes: day=%, cur=%, rate=%, x=%',row2.day, p_currency, v_rate, exists; RAISE NOTICE 'im_exchange_rate_fill_holes: day=%, cur=%, rate=%, x=%',row2.day, p_currency, v_rate, v_exists_p;
insert into im_exchange_rates ( insert into im_exchange_rates (
day, rate, currency, manual_p day, rate, currency, manual_p
) values ( ) values (
row2.day, v_rate, p_currency, 'f' row2.day, v_rate, p_currency, 'f'
); );
END IF; END IF;
END LOOP; END LOOP;
return 0; return 0;
end;$body$ language 'plpgsql'; end;$body$ language 'plpgsql';
-- Compatibility version of fill_holes: -- Compatibility version of fill_holes:
-- Fills holes for 2013 - 2020. -- Fills holes for 2013 - 2020.
create or replace function im_exchange_rate_fill_holes (varchar) create or replace function im_exchange_rate_fill_holes (varchar)
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment