1 -- @tag: konjunkturpaket_2020
2 -- @description: Anpassung der Steuersätze für 16%/5% für Deutsche DATEV-Kontenrahmen SKR03 und SKR04
3 -- @depends: release_3_5_5 konjunkturpaket_2020_SKR03 konjunkturpaket_2020_SKR04
11 -- variables for main taxkey creation loop, not all are needed
17 _taxkeyentry_id int[];
22 current_taxkey record;
25 _tax record; -- store the new tax we need to assign to a chart, e.g. 5%, 16%
33 _tax_conversion record;
38 IF ( select coa from defaults ) ~ 'DATEV' THEN
41 --delete from taxkeys where startdate >= '2020-01-01';
43 -- create temp table temp_taxkey_conversions (taxkey int, old_rate numeric, new_rate numeric, tax_chart_skr03 text, tax_chart_skr04 text);
44 -- insert into temp_taxkey_conversions (taxkey, old_rate, new_rate, tax_chart_skr03, tax_chart_skr04) values
45 ---- (2, 0.07, 0.05, '1773', '3803'), -- 5% case is handled by skr03 case -> needs different automatic chart: 1773 Umsatzsteuer 5% (SKR03, instead of 1771 Umsatzsteuer 7%) or 3803 Umsatzsteuer 5%
46 -- -- (8, 0.07, 0.05, null, null),
47 -- -- (3, 0.19, 0.16, null, null),
48 -- -- (9, 0.19, 0.16, null, null),
49 -- (13, 0.19, 0.16, null, null);
52 create temp table temp_taxkey_conversions (taxkey int, old_rate numeric, old_chart text, new_rate numeric, new_chart text);
54 IF ( select coa from defaults ) = 'Germany-DATEV-SKR03EU' THEN
55 insert into temp_taxkey_conversions (taxkey, old_rate, old_chart, new_rate, new_chart)
56 values (9, 0.19, '1576', 0.16, '1575'),
57 (8, 0.07, '1571', 0.05, '1568'),
58 (3, 0.19, '1776', 0.16, '1575'),
59 (2, 0.07, '1771', 0.05, '1775');
71 ELSE -- Germany-DATEV-SKR04EU
72 insert into temp_taxkey_conversions (taxkey, old_rate, old_chart, new_rate, new_chart)
73 values (9, 0.19, '1406', 0.16, '1405'),
74 (8, 0.07, '1401', 0.05, '1403'),
75 (3, 0.19, '3806', 0.16, '3805'),
76 (2, 0.07, '3801', 0.05, '3803');
79 FOR _chart_id, _accno, _description, _startdates, _tax_ids, _taxkeyentry_id, _taxkey_ids, _rates, _taxcharts IN
81 select c.id as chart_id,
84 array_agg(t.startdate order by t.startdate desc) as startdates,
85 array_agg(t.tax_id order by t.startdate desc) as tax_ids,
86 array_agg(t.id order by t.startdate desc) as taxkeyentry_id,
87 array_agg(t.taxkey_id order by t.startdate desc) as taxkey_ids,
88 array_agg(tax.rate order by t.startdate desc) as rates,
89 array_agg(tc.accno order by t.startdate desc) as taxcharts
91 left join chart c on (c.id = t.chart_id)
92 left join tax on (tax.id = t.tax_id)
93 left join chart tc on (tax.chart_id = tc.id)
94 where t.taxkey_id in (select taxkey from temp_taxkey_conversions) -- 2, 3, 8, 9
95 -- and (c.accno = '8400') -- debug
96 -- you can't filter for valid taxrates 19% or 7% here, as that would still leave the 16% rates as the current one
102 -- example output for human debugging:
103 -- chart_id | accno | description | startdates | tax_ids | taxkeyentry_id | taxkey_ids | rates | taxcharts
104 -- ----------+-------+---------------------+-------------------------+-----------+----------------+------------+-------------------+-------------
105 -- 184 | 8400 | Erlöse 16%/19% USt. | {2007-01-01,1970-01-01} | {777,379} | {793,676} | {3,3} | {0.19000,0.16000} | {1776,1775}
107 -- each chart with one of the applicable taxkeys should receive two new entries, one starting on 01.07.2020, the other on 01.01.2021
109 -- 1. create new taxkey entry on 2020-07-01, using the active taxkey on 2020-06-30 as a template, but linking to a tax with a different tax rate
110 -- 2. create new taxkey entry on 2021-01-01, using the active taxkey on 2020-06-30 as a template, but with the new date
113 -- fetch tax information for 2020-06-30, one day before the change, this should also be the first entry in the ordered array aggregates
114 -- this can be used as the template for the reset on 2021-01-01
116 -- raise notice 'looking up current taxkey for chart % and taxkey %', (select accno from chart where id = _chart_id), _taxkey_ids[1];
117 select into current_taxkey tk.*, t.rate, t.taxkey
119 left join tax t on (t.id = tk.tax_id)
120 where tk.taxkey_id = _taxkey_ids[1] -- assume taxkey never changed, use the first one
121 and tk.chart_id = _chart_id
122 and tk.startdate <= '2020-06-30'
123 order by tk.startdate desc
125 -- RAISE NOTICE 'found current_taxkey = %', current_taxkey;
126 IF current_taxkey is null then continue; end if;
127 -- RAISE NOTICE 'found chart % with current startdate % and taxkey % (current: %), rate = %', _accno, current_taxkey.startdate, _taxkey_ids[1], current_taxkey.taxkey, current_taxkey.rate;
129 -- RAISE NOTICE 'current_taxkey = %', current_taxkey;
130 -- RAISE NOTICE 'looking up tkc for chart_id % and taxkey %', _chart_id, current_taxkey.taxkey;
132 select into _taxkey, _old_rate, _old_chart, _new_chart, _new_rate
133 taxkey, old_rate, old_chart, new_chart, new_rate
134 from temp_taxkey_conversions tkc
135 where tkc.taxkey = current_taxkey.taxkey
136 and tkc.old_rate = current_taxkey.rate;
137 -- and tkc.new_chart = current_taxkey.new_chart;
139 -- raise notice '_old_rate = %, _new_rate = %', _old_rate, _new_rate;
141 -- don't do anything if current taxrate is 0, which might be the case for taxkey 13, if they were configured in that way
142 IF current_taxkey.rate != 0 THEN -- debug
146 -- IF current_taxkey.rate = 0.19 THEN _rate := 0.16; END IF;
147 -- IF current_taxkey.rate = 0.07 THEN _rate := 0.05; END IF;
148 IF _old_rate is NULL THEN
150 -- option A: ignore rates which don't make sense, useful for upgrade mode
151 -- option B: throw exception, useful for manually testing script
154 -- if the rate on 2020-06-30 is neither 19 or 7, simply ignore it, it is obviously not configured correctly
155 -- This is the case for SKR03 and chart 8315 (taxkey 13)
156 -- It might be better to throw an exception, however then the test cases don't run. Or just fix the chart via an upgrade script!
160 -- RAISE EXCEPTION 'illegal current taxrate % on 2020-06-30 (startdate = %) for chart % with taxkey %, should be either 0.19 or 0.07',
161 -- current_taxkey.rate, current_taxkey.startdate,
162 -- (select accno from chart where id = current_taxkey.chart_id),
163 -- current_taxkey.taxkey_id;
165 -- RAISE NOTICE 'current_taxkey.rate = %, desired rate = %, looking for taxkey_id %', current_taxkey.rate, _rate, _taxkey_ids[1];
167 -- if a chart was created way after 2007 and only ever configured for
168 -- 19%, never 16%, which is the case for SKR04 and taxkey 13, there will only be 3
169 -- taxkeys per chart after adding the two new ones
171 -- RAISE NOTICE 'searching for tax with taxkey % and rate %', _taxkey_ids[1], _rate;
175 where tax.rate = _old_rate
176 and tax.taxkey = _taxkey_ids[1]
178 limit 1; -- look up tax with same taxkey but corresponding rate. As there will now be two entries for e.g. taxkey 9 with rate of 0.16, the old pre-2007 entry and the new 2020-entry. They can only be differentiated by their (automatic tax) chart_id, or during this upgrade script, via itime, use the later one
179 -- this also assumes taxkeys never change
180 -- RAISE NOTICE 'tax = %', _tax;
182 -- insert into taxkeys (chart_id, tax_id, taxkey_id, pos_ustva, startdate)
183 -- values ( (select id from chart where accno = 'kkkkgtkttttkk current_taxkey.chart_id, _tax.id, _tax.taxkey, current_taxkey.pos_ustva, '2020-07-01');
186 -- raise notice 'inserting taxkey';
187 insert into taxkeys (chart_id, tax_id, taxkey_id, pos_ustva, startdate )
189 (select id from tax where taxkey = current_taxkey.taxkey and rate = _new_rate::numeric),
190 current_taxkey.taxkey, -- 2, 3, 8, 9
191 current_taxkey.pos_ustva, '2020-07-01');
193 -- finally insert a copy of the taxkey on 2020-06-30 with the new startdate 2021-01-01, thereby resetting the tax rates again
194 insert into taxkeys (chart_id, tax_id, taxkey_id, pos_ustva, startdate)
196 current_taxkey.tax_id,
197 current_taxkey.taxkey,
198 current_taxkey.pos_ustva, '2021-01-01');
200 -- RAISE NOTICE 'inserted 2 taxkeys for chart % with taxkey %', (select accno from chart where id = current_taxkey.chart_id), current_taxkey.taxkey_id;
203 drop table temp_taxkey_conversions;
209 -- select * from taxkeys where startdate >= '2020-01-01';