From 462513f2a410763ad4cc463f08ed6f13b1697019 Mon Sep 17 00:00:00 2001 From: Lorenz Stechauner Date: Thu, 2 Nov 2023 11:56:42 +0100 Subject: [PATCH] database: fix billing calculcation --- sql/v01/11.create.client.sql | 28 ++++++---- sql/v01/12.create.season.sql | 20 +++++-- sql/v01/13.create.payment.sql | 18 +++---- sql/v01/30.create.view.sql | 45 +--------------- sql/v01/31.create.bucket-view.sql | 79 ++++++++++++++++++++++++++++ sql/v01/99.schema_version.sql | 2 +- sqlite.bat | 2 +- sqlite.sh | 1 + wgmaster/import.py | 5 +- wgmaster/migrate.py | 86 ++++++++++++++++--------------- 10 files changed, 173 insertions(+), 113 deletions(-) create mode 100644 sql/v01/31.create.bucket-view.sql diff --git a/sql/v01/11.create.client.sql b/sql/v01/11.create.client.sql index 5595e5b..5e52570 100644 --- a/sql/v01/11.create.client.sql +++ b/sql/v01/11.create.client.sql @@ -19,22 +19,26 @@ CREATE TABLE branch ( mobile_nr TEXT DEFAULT NULL CHECK (mobile_nr REGEXP '^\+[0-9]{1,3}( [0-9]+)+(-[0-9]+)?$'), CONSTRAINT pk_branch PRIMARY KEY (zwstid), + CONSTRAINT sk_branch_name UNIQUE (name), CONSTRAINT fk_branch_postal_dest FOREIGN KEY (country, postal_dest) REFERENCES postal_dest (country, id) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; CREATE TABLE wine_attribute ( - attrid TEXT NOT NULL CHECK (attrid REGEXP '^[A-Z]+$'), - name TEXT NOT NULL, + attrid TEXT NOT NULL CHECK (attrid REGEXP '^[A-Z]+$'), + name TEXT NOT NULL, + active INTEGER NOT NULL CHECK (active IN (TRUE, FALSE)) DEFAULT TRUE, - max_kg_per_ha INTEGER, - fill_lower_bins INTEGER NOT NULL CHECK (fill_lower_bins IN (0, 1, 2)) DEFAULT 0, - active INTEGER NOT NULL CHECK (active IN (TRUE, FALSE)) DEFAULT TRUE, + max_kg_per_ha INTEGER, + strict INTEGER NOT NULL CHECK (strict IN (TRUE, FALSE)) DEFAULT FALSE, + fill_lower INTEGER NOT NULL CHECK (fill_lower IN (0, 1, 2)) DEFAULT 0, - CONSTRAINT pk_wine_attribute PRIMARY KEY (attrid) + CONSTRAINT pk_wine_attribute PRIMARY KEY (attrid), + CONSTRAINT sk_wine_attribute_name UNIQUE (name) ) STRICT; +-- all values in the table are stored with precision 4! CREATE TABLE area_commitment_type ( vtrgid TEXT NOT NULL CHECK (vtrgid = sortid || COALESCE(attrid, '') || disc), sortid TEXT NOT NULL, @@ -42,8 +46,9 @@ CREATE TABLE area_commitment_type ( disc TEXT DEFAULT NULL CHECK (disc REGEXP '^[A-Z0-9]+$'), min_kg_per_ha INTEGER, - max_kg_per_ha INTEGER, + penalty_per_kg INTEGER, penalty_amount INTEGER, + penalty_none INTEGER, CONSTRAINT pk_area_commitment_type PRIMARY KEY (vtrgid), CONSTRAINT sk_area_commitment_type_sort_attr UNIQUE (sortid, attrid, disc), @@ -56,10 +61,12 @@ CREATE TABLE area_commitment_type ( ) STRICT; CREATE TABLE wine_cultivation ( - cultid TEXT NOT NULL CHECK (cultid REGEXP '^[A-Z]+$'), - name TEXT NOT NULL, + cultid TEXT NOT NULL CHECK (cultid REGEXP '^[A-Z]+$'), + name TEXT NOT NULL, + description TEXT DEFAULT NULL, - CONSTRAINT pk_wine_cultivation PRIMARY KEY (cultid) + CONSTRAINT pk_wine_cultivation PRIMARY KEY (cultid), + CONSTRAINT sk_wine_cultivation_name UNIQUE (name) ) STRICT; CREATE TABLE member ( @@ -84,6 +91,7 @@ CREATE TABLE member ( ustid_nr TEXT CHECK (ustid_nr REGEXP '^[A-Z]{2}[A-Z0-9]{2,12}$') DEFAULT NULL, volllieferant INTEGER NOT NULL CHECK (volllieferant IN (TRUE, FALSE)) DEFAULT FALSE, buchführend INTEGER NOT NULL CHECK (buchführend IN (TRUE, FALSE)) DEFAULT FALSE, + organic INTEGER NOT NULL CHECK (organic IN (TRUE, FALSE)) DEFAULT FALSE, funktionär INTEGER NOT NULL CHECK (funktionär IN (TRUE, FALSE)) DEFAULT FALSE, active INTEGER NOT NULL CHECK (active IN (TRUE, FALSE)) DEFAULT TRUE, deceased INTEGER NOT NULL CHECK (deceased IN (TRUE, FALSE)) DEFAULT FALSE, diff --git a/sql/v01/12.create.season.sql b/sql/v01/12.create.season.sql index 54ec618..70b9198 100644 --- a/sql/v01/12.create.season.sql +++ b/sql/v01/12.create.season.sql @@ -1,11 +1,21 @@ CREATE TABLE season ( - year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999), - currency TEXT NOT NULL, - precision INTEGER NOT NULL DEFAULT 4, + year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999), + currency TEXT NOT NULL, + precision INTEGER NOT NULL DEFAULT 4, - start_date TEXT CHECK (start_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'), - end_date TEXT CHECK (end_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'), + max_kg_per_ha INTEGER NOT NULL DEFAULT 10000, + vat_normal REAL NOT NULL DEFAULT 0.10, + vat_flatrate REAL NOT NULL DEFAULT 0.13, + + min_kg_per_bs INTEGER NOT NULL, + max_kg_per_bs INTEGER NOT NULL, + penalty_per_kg INTEGER, + penalty_amount INTEGER, + penalty_none INTEGER, + + start_date TEXT CHECK (start_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'), + end_date TEXT CHECK (end_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'), CONSTRAINT pk_season PRIMARY KEY (year), CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code) diff --git a/sql/v01/13.create.payment.sql b/sql/v01/13.create.payment.sql index 8a3565e..5b2745c 100644 --- a/sql/v01/13.create.payment.sql +++ b/sql/v01/13.create.payment.sql @@ -1,15 +1,15 @@ -CREATE TABLE delivery_part_bin ( +CREATE TABLE delivery_part_bucket ( year INTEGER NOT NULL, did INTEGER NOT NULL, dpnr INTEGER NOT NULL, - binnr INTEGER NOT NULL, + bktnr INTEGER NOT NULL, discr TEXT NOT NULL, value INTEGER NOT NULL, - CONSTRAINT pk_delivery_part_bin PRIMARY KEY (year, did, dpnr, binnr), - CONSTRAINT fk_delivery_part_bin_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr) + CONSTRAINT pk_delivery_part_bucket PRIMARY KEY (year, did, dpnr, bktnr), + CONSTRAINT fk_delivery_part_bucket_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr) ON UPDATE CASCADE ON DELETE CASCADE ) STRICT; @@ -77,21 +77,21 @@ BEGIN END; -- all values in the table are stored with season-precision! -CREATE TABLE payment_delivery_part_bin ( +CREATE TABLE payment_delivery_part_bucket ( year INTEGER NOT NULL, did INTEGER NOT NULL, dpnr INTEGER NOT NULL, - binnr INTEGER NOT NULL, + bktnr INTEGER NOT NULL, avnr INTEGER NOT NULL, price INTEGER NOT NULL, amount INTEGER NOT NULL, - CONSTRAINT pk_payment_delivery_part_bin PRIMARY KEY (year, did, dpnr, binnr, avnr), - CONSTRAINT fk_payment_delivery_part_bin_delivery_part_bin FOREIGN KEY (year, did, dpnr, binnr) REFERENCES delivery_part_bin (year, did, dpnr, binnr) + CONSTRAINT pk_payment_delivery_part_bucket PRIMARY KEY (year, did, dpnr, bktnr, avnr), + CONSTRAINT fk_payment_delivery_part_bucket_delivery_part_bucket FOREIGN KEY (year, did, dpnr, bktnr) REFERENCES delivery_part_bucket (year, did, dpnr, bktnr) ON UPDATE CASCADE ON DELETE CASCADE, - CONSTRAINT fk_payment_delivery_part_bin_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr) + CONSTRAINT fk_payment_delivery_part_bucket_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr) ON UPDATE CASCADE ON DELETE CASCADE ) STRICT; diff --git a/sql/v01/30.create.view.sql b/sql/v01/30.create.view.sql index 9ed30ad..13818a2 100644 --- a/sql/v01/30.create.view.sql +++ b/sql/v01/30.create.view.sql @@ -5,19 +5,6 @@ FROM AT_gem g JOIN AT_ort o ON o.gkz = g.gkz JOIN AT_plz_dest p ON p.okz = o.okz; -CREATE VIEW v_area_commitment AS -SELECT c.fbnr, m.mgnr, m.family_name, m.given_name, - c.sortid, c.cultid, c.area, - c.kgnr, c.gstnr, c.rdnr, - c.year_from, c.year_to, - GROUP_CONCAT(DISTINCT a.attrid) AS attributes, - c.comment -FROM area_commitment c - JOIN member m ON m.mgnr = c.mgnr - LEFT JOIN area_commitment_attribute a ON a.fbnr = c.fbnr -GROUP BY c.fbnr -ORDER BY c.fbnr; - CREATE VIEW v_delivery AS SELECT p.year, p.did, p.dpnr, d.date, d.time, d.zwstid, d.lnr, d.lsnr, @@ -28,7 +15,7 @@ SELECT p.year, p.did, p.dpnr, p.gerebelt, p.gebunden, p.qualid IN (SELECT l.qualid FROM wine_quality_level l WHERE NOT l.predicate AND (p.kmw >= l.min_kmw OR l.min_kmw IS NULL) ORDER BY l.min_kmw DESC LIMIT 1,100) AS abgewertet, p.qualid NOT IN ('WEI', 'RSW', 'LDW') AS min_quw, - COALESCE(a.fill_lower_bins, 0) AS attribute_prio, + IIF(a.strict, COALESCE(a.fill_lower, 0), 0) AS attribute_prio, GROUP_CONCAT(o.modid) AS modifiers, d.comment, p.comment AS part_comment FROM delivery_part p @@ -39,36 +26,6 @@ FROM delivery_part p GROUP BY p.year, p.did, p.dpnr ORDER BY p.year, p.did, p.dpnr, o.modid; -CREATE VIEW v_delivery_bin AS -SELECT year, mgnr, - sortid || IIF(min_quw, COALESCE(attrid, ''), '_') AS bin, - SUM(weight) AS weight -FROM v_delivery -GROUP BY year, mgnr, bin -ORDER BY year, mgnr, LENGTH(bin) DESC, bin; - -CREATE VIEW v_payment_bin AS -SELECT d.year, d.mgnr, - sortid || discr AS bin, - SUM(value) AS weight -FROM v_delivery d - JOIN delivery_part_bin b ON (b.year, b.did, b.dpnr) = (d.year, d.did, d.dpnr) -GROUP BY d.year, d.mgnr, bin -HAVING SUM(value) > 0 -ORDER BY d.year, d.mgnr, LENGTH(bin) DESC, bin; - -CREATE VIEW v_area_commitment_bin AS -SELECT s.year, c.mgnr, - c.vtrgid AS bin, - CAST(ROUND(SUM(COALESCE(area * min_kg_per_ha, 0)) / 10000.0, 0) AS INTEGER) AS min_kg, - CAST(ROUND(SUM(COALESCE(area * max_kg_per_ha, 0)) / 10000.0, 0) AS INTEGER) AS max_kg -FROM area_commitment c, season s - JOIN area_commitment_type t ON t.vtrgid = c.vtrgid -WHERE (year_from IS NULL OR year_from <= s.year) AND - (year_to IS NULL OR year_to >= s.year) -GROUP BY s.year, c.mgnr, c.vtrgid -ORDER BY s.year, c.mgnr, LENGTH(c.vtrgid) DESC, c.vtrgid; - CREATE VIEW v_stat_season AS SELECT year, SUM(weight) AS sum, diff --git a/sql/v01/31.create.bucket-view.sql b/sql/v01/31.create.bucket-view.sql new file mode 100644 index 0000000..a030b0f --- /dev/null +++ b/sql/v01/31.create.bucket-view.sql @@ -0,0 +1,79 @@ + +CREATE VIEW v_area_commitment_bucket_strict AS +SELECT s.year, c.mgnr, + t.sortid || COALESCE(a.attrid, '') AS bucket, + t.sortid, a.attrid, + CAST(ROUND(SUM(area) * COALESCE(t.min_kg_per_ha, 0) / 10000.0, 0) AS INTEGER) AS min_kg, + CAST(ROUND(SUM(area) * COALESCE(a.max_kg_per_ha, s.max_kg_per_ha) / 10000.0, 0) AS INTEGER) AS max_kg, + CAST(ROUND(SUM(area) * s.max_kg_per_ha / 10000.0, 0) AS INTEGER) AS upper_max_kg +FROM season s, area_commitment c + JOIN area_commitment_type t ON t.vtrgid = c.vtrgid + LEFT JOIN wine_attribute a ON a.attrid = t.attrid +WHERE (year_from IS NULL OR year_from <= s.year) AND + (year_to IS NULL OR year_to >= s.year) +GROUP BY s.year, c.mgnr, bucket +ORDER BY s.year, c.mgnr, bucket; + +CREATE VIEW v_area_commitment_bucket AS +SELECT year, mgnr, bucket, min_kg, max_kg +FROM v_area_commitment_bucket_strict +WHERE attrid IS NOT NULL +UNION ALL +SELECT b.year, b.mgnr, b.sortid, + SUM(b.min_kg) AS min_kg, + SUM(b.upper_max_kg) AS max_kg +FROM v_area_commitment_bucket_strict b + LEFT JOIN wine_attribute a ON a.attrid = b.attrid +WHERE a.strict IS NULL OR a.strict = FALSE +GROUP BY b.year, b.mgnr, b.sortid +ORDER BY year, mgnr, bucket; + + +CREATE VIEW v_delivery_bucket_strict AS +SELECT year, mgnr, + sortid || IIF(min_quw, COALESCE(attrid, ''), '_') AS bucket, + sortid, IIF(min_quw, attrid, NULL) AS attrid, + SUM(weight) AS weight, + min_quw +FROM v_delivery +GROUP BY year, mgnr, bucket +ORDER BY year, mgnr, bucket; + +CREATE VIEW v_delivery_bucket AS +SELECT year, mgnr, bucket, weight +FROM v_delivery_bucket_strict +WHERE attrid IS NOT NULL OR NOT min_quw +UNION ALL +SELECT b.year, b.mgnr, b.sortid, + SUM(b.weight) AS weight +FROM v_delivery_bucket_strict b + LEFT JOIN wine_attribute a ON a.attrid = b.attrid +WHERE min_quw AND (a.strict IS NULL OR a.strict = FALSE) +GROUP BY b.year, b.mgnr, b.sortid +ORDER BY year, mgnr, bucket; + + +CREATE VIEW v_payment_bucket_strict AS +SELECT d.year, d.mgnr, + d.sortid || b.discr AS bucket, + d.sortid, IIF(b.discr IN ('', '_'), NULL, b.discr) AS attrid, + SUM(b.value) AS weight, + b.discr != '_' AS gebunden +FROM v_delivery d + LEFT JOIN delivery_part_bucket b ON (b.year, b.did, b.dpnr) = (d.year, d.did, d.dpnr) +GROUP BY d.year, d.mgnr, bucket +HAVING SUM(b.value) > 0 +ORDER BY d.year, d.mgnr, bucket; + +CREATE VIEW v_payment_bucket AS +SELECT year, mgnr, bucket, weight +FROM v_payment_bucket_strict +WHERE attrid IS NOT NULL OR NOT gebunden +UNION ALL +SELECT b.year, b.mgnr, b.sortid, + SUM(b.weight) AS weight +FROM v_payment_bucket_strict b + LEFT JOIN wine_attribute a ON a.attrid = b.attrid +WHERE gebunden AND (a.strict IS NULL OR a.strict = FALSE) +GROUP BY b.year, b.mgnr, b.sortid +ORDER BY year, mgnr, bucket; diff --git a/sql/v01/99.schema_version.sql b/sql/v01/99.schema_version.sql index 0c37a76..4f3d264 100644 --- a/sql/v01/99.schema_version.sql +++ b/sql/v01/99.schema_version.sql @@ -1,3 +1,3 @@ -- This value MUST NOT be changed while other connections are open! -PRAGMA schema_version = 500; +PRAGMA schema_version = 600; diff --git a/sqlite.bat b/sqlite.bat index 405a931..a8e1e15 100644 --- a/sqlite.bat +++ b/sqlite.bat @@ -1,5 +1,4 @@ @echo off - SET dir=. sqlite3 -box^ -cmd ".read %dir%/sql/v01/00.setup.sql"^ @@ -9,6 +8,7 @@ sqlite3 -box^ -cmd ".read %dir%/sql/v01/13.create.payment.sql"^ -cmd ".read %dir%/sql/v01/20.create.timestamp-trigger.sql"^ -cmd ".read %dir%/sql/v01/30.create.view.sql"^ + -cmd ".read %dir%/sql/v01/31.create.bucket-view.sql"^ -cmd ".read %dir%/sql/v01/50.insert.base.sql"^ -cmd ".read %dir%/data/90.plz.sql"^ -cmd ".read %dir%/sql/91.plz-fix.sql"^ diff --git a/sqlite.sh b/sqlite.sh index 1103d4b..d154e04 100755 --- a/sqlite.sh +++ b/sqlite.sh @@ -8,6 +8,7 @@ sqlite3 -box \ -cmd ".read $dir/sql/v01/13.create.payment.sql" \ -cmd ".read $dir/sql/v01/20.create.timestamp-trigger.sql" \ -cmd ".read $dir/sql/v01/30.create.view.sql" \ + -cmd ".read $dir/sql/v01/31.create.bucket-view.sql" \ -cmd ".read $dir/sql/v01/50.insert.base.sql" \ -cmd ".read $dir/data/90.plz.sql" \ -cmd ".read $dir/sql/91.plz-fix.sql" \ diff --git a/wgmaster/import.py b/wgmaster/import.py index a56c5a1..fd0f987 100755 --- a/wgmaster/import.py +++ b/wgmaster/import.py @@ -12,10 +12,11 @@ import utils DIR: str -TABLES = ['client_parameter', 'branch', 'wb_gl', 'wb_kg', 'wb_rd', 'wine_attribute', 'wine_cultivation', 'area_commitment_type', +TABLES = ['client_parameter', 'branch', 'wb_gl', 'wb_kg', 'wb_rd', + 'wine_attribute', 'wine_cultivation', 'area_commitment_type', 'member', 'member_billing_address', 'member_telephone_number', 'member_email_address', 'area_commitment', 'season', 'modifier', 'delivery', 'delivery_part', 'delivery_part_modifier', - 'delivery_part_bin', 'payment_variant', 'payment_delivery_part'] + 'delivery_part_bucket', 'payment_variant', 'payment_delivery_part'] def get_sql_files() -> List[str]: diff --git a/wgmaster/migrate.py b/wgmaster/migrate.py index 7d8ce60..3435377 100755 --- a/wgmaster/migrate.py +++ b/wgmaster/migrate.py @@ -44,6 +44,7 @@ MEMBER_MAP: Optional[Dict[int, Dict[str, Any]]] = None GROSSLAGE_KG_MAP: Optional[Dict[int, int]] = None DELIVERY_MAP: Optional[Dict[int, Tuple[int, int, int]]] = None MODIFIER_MAP: Optional[Dict[str, Dict]] = None +PARAMETERS: Optional[Dict[str, str]] = None AUSTRIA = 40 WGMASTER_PRECISION = 4 @@ -601,14 +602,17 @@ def migrate_reeds(in_dir: str, out_dir: str) -> None: def migrate_attributes(in_dir: str, out_dir: str) -> None: with utils.csv_open(f'{out_dir}/wine_attribute.csv') as f: - f.header('attrid', 'name', 'max_kg_per_ha', 'fill_lower_bins', 'active') + f.header('attrid', 'name', 'active', 'max_kg_per_ha', 'strict', 'fill_lower') for a in utils.csv_parse_dict(f'{in_dir}/TSortenAttribute.csv'): if a['SANR'] is None: continue - f.row(a['SANR'], a['Attribut'], int(a['KgProHa']) if a['KgProHa'] is not None else None, 0, True) + max_kg = int(a['KgProHa']) if a['KgProHa'] is not None else None + if max_kg == 10_000: + max_kg = None + f.row(a['SANR'], a['Attribut'], True, max_kg, False, 0) if CLIENT == WG.MATZEN: - f.row('M', 'Matzen', None, 0, False) - f.row('HU', 'Huber', None, 0, False) + f.row('M', 'Matzen', False, None, False, 0) + f.row('HU', 'Huber', False, None, False, 0) def migrate_cultivations(in_dir: str, out_dir: str) -> None: @@ -616,7 +620,7 @@ def migrate_cultivations(in_dir: str, out_dir: str) -> None: CULTIVATION_MAP = {} with utils.csv_open(f'{out_dir}/wine_cultivation.csv') as f: - f.header('cultid', 'name') + f.header('cultid', 'name', 'description') for c in utils.csv_parse_dict(f'{in_dir}/TBewirtschaftungsarten.csv'): name: str = c['Bezeichnung'] cultid = name[0].upper() @@ -625,28 +629,28 @@ def migrate_cultivations(in_dir: str, out_dir: str) -> None: elif 'biolog' in name.lower(): cultid = 'BIO' CULTIVATION_MAP[c['BANR']] = cultid - f.row(cultid, name) + f.row(cultid, name, None) def migrate_area_commitment_types(in_dir: str, out_dir: str) -> None: with utils.csv_open(f'{out_dir}/area_commitment_type.csv') as f: - f.header('vtrgid', 'sortid', 'attrid', 'disc', - 'min_kg_per_ha', 'max_kg_per_ha', 'penalty_amount') + f.header('vtrgid', 'sortid', 'attrid', 'disc', 'min_kg_per_ha', + 'penalty_per_kg', 'penalty_amount', 'penalty_none') for t in utils.csv_parse_dict(f'{in_dir}/TLiefermengen.csv'): sortid: str = t['SNR'] if not sortid or sortid == 'SV': continue menge = int(t['ErwarteteLiefermengeProHa']) - f.row(sortid + (t['SANR'] or ''), sortid[:2], t['SANR'] or sortid[2:] or None, None, - menge, menge, None) + f.row(sortid + (t['SANR'] or ''), sortid[:2], t['SANR'] or sortid[2:] or None, None, menge, + None, None, None) bio = [] if CLIENT == WG.MATZEN: bio = ['GV', 'ZW', 'MT'] - f.row('BM', 'BM', None, None, None, None, None) + f.row('BM', 'BM', None, None, None, None, None, None) elif CLIENT == WG.WINZERKELLER: bio = ['GV', 'ZW', 'WR', 'MT', 'RR', 'WB', 'CH', 'MU'] for sortid in bio: - f.row(f'{sortid}B', sortid, 'B', None, None, None, None) + f.row(f'{sortid}B', sortid, 'B', None, None, None, None, None) def normalize_name(family_name: str, given_name: str) -> Tuple[Optional[str], Optional[str], Optional[str], Optional[str], Optional[str], Optional[str]]: @@ -767,7 +771,7 @@ def migrate_members(in_dir: str, out_dir: str) -> None: f_m.header( 'mgnr', 'predecessor_mgnr', 'prefix', 'given_name', 'middle_names', 'family_name', 'suffix', 'birthday', 'entry_date', 'exit_date', 'business_shares', 'accounting_nr', 'zwstid', - 'lfbis_nr', 'ustid_nr', 'volllieferant', 'buchführend', 'funktionär', 'active', 'deceased', + 'lfbis_nr', 'ustid_nr', 'volllieferant', 'buchführend', 'organic', 'funktionär', 'active', 'deceased', 'iban', 'bic', 'country', 'postal_dest', 'address', 'default_kgnr', 'comment') f_mba.header('mgnr', 'name', 'country', 'postal_dest', 'address') f_tel.header('mgnr', 'nr', 'type', 'number', 'comment') @@ -952,7 +956,7 @@ def migrate_members(in_dir: str, out_dir: str) -> None: mgnr, pred, prefix, given_name, middle_names, family_name, suffix, m['Geburtsjahr'], m['Eintrittsdatum'], m['Austrittsdatum'], m['Geschäftsanteile1'] or 0, m['BHKontonummer'], zwstid, bnr, ustid_nr, - m['Volllieferant'] or False, m['Buchführend'] or False, funktionaer, active, deceased, + m['Volllieferant'] or False, m['Buchführend'] or False, False, funktionaer, active, deceased, iban, bic, AUSTRIA, postal_dest, address or '-', kgnr, m['Anmerkung'] ) @@ -1521,10 +1525,14 @@ def migrate_deliveries(in_dir: str, out_dir: str) -> None: with utils.csv_open(f'{out_dir}/season.csv') as f_season, \ utils.csv_open(f'{out_dir}/modifier.csv') as f_mod: - f_season.header('year', 'currency', 'precision', 'start_date', 'end_date') + f_season.header('year', 'currency', 'precision', 'max_kg_per_ha', 'vat_normal', 'vat_flatrate', + 'min_kg_per_bs', 'max_kg_per_bs', 'penalty_per_kg', 'penalty_amount', 'penalty_none', + 'start_date', 'end_date') f_mod.header('year', 'modid', 'ordering', 'name', 'abs', 'rel', 'standard', 'quick_select') for y, s in seasons.items(): - f_season.row(y, s['currency'], s['precision'], s['start'], s['end']) + f_season.row(y, s['currency'], s['precision'], 10_000, 0.10, 0.13, + PARAMETERS['LIEFERPFLICHT/GA1'], PARAMETERS['LIEFERRECHT/GA1'], + None, None, None, s['start'], s['end']) for m in modifiers.values(): abs_v = round(m['AZAS'] * pow(10, s['precision'])) if m['AZAS'] is not None else None rel_v = m['AZASProzent'] / 100.0 if m['AZASProzent'] is not None else None @@ -1677,9 +1685,9 @@ def migrate_payments(in_dir: str, out_dir: str) -> None: # TODO database migration with utils.csv_open(f'{out_dir}/payment_delivery_part.csv') as f_del_pay, \ - utils.csv_open(f'{out_dir}/delivery_part_bin.csv') as f_bin: + utils.csv_open(f'{out_dir}/delivery_part_bucket.csv') as f_bucket: f_del_pay.header('year', 'did', 'dpnr', 'avnr', 'amount') - f_bin.header('year', 'did', 'dpnr', 'binnr', 'discr', 'value') + f_bucket.header('year', 'did', 'dpnr', 'bktnr', 'discr', 'value') deliveries = {d['LINR']: d for d in utils.csv_parse_dict(f'{in_dir}/TLieferungen.csv')} for linr, (y, did, dpnr) in DELIVERY_MAP.items(): p = deliveries[linr] @@ -1688,8 +1696,8 @@ def migrate_payments(in_dir: str, out_dir: str) -> None: gew, geb_gew = int(p['Gewicht']), int(p['BGewichtGebunden']) b1 = gew - geb_gew b2 = geb_gew - f_bin.row(y, did, dpnr, 1, '_', b1) - f_bin.row(y, did, dpnr, 2, p['SANR'] or '', b2) + f_bucket.row(y, did, dpnr, 0, '_', b1) + f_bucket.row(y, did, dpnr, 1, p['SANR'] or '', b2) for aznr, avnr, tznr in variant_year_map[y]: val = p[f'BTeilzahlung{tznr}' if tznr < 6 else 'BEndauszahlung'] val = round(val * pow(10, WGMASTER_PRECISION)) @@ -1709,9 +1717,10 @@ def migrate_payments(in_dir: str, out_dir: str) -> None: def migrate_parameters(in_dir: str, out_dir: str) -> None: - params: Dict[str, str] = {p['Bezeichnung']: p['Wert'] for p in utils.csv_parse_dict(f'{in_dir}/TParameter.csv')} - name = params['MANDANTENNAME1'].title().replace('F.', 'für').replace('U.', 'und').replace(' Im ', ' im ') - suffix = params['MANDANTENNAME2'].lower().replace(' ', '').replace('.', '') + global PARAMETERS + PARAMETERS = {p['Bezeichnung']: p['Wert'] for p in utils.csv_parse_dict(f'{in_dir}/TParameter.csv')} + name = PARAMETERS['MANDANTENNAME1'].title().replace('F.', 'für').replace('U.', 'und').replace(' Im ', ' im ') + suffix = PARAMETERS['MANDANTENNAME2'].lower().replace(' ', '').replace('.', '') types = { 'reggenmbh': 'reg. Gen.m.b.H.' } @@ -1720,32 +1729,27 @@ def migrate_parameters(in_dir: str, out_dir: str) -> None: WG.WINZERKELLER: ('WKW', 'Winzerkeller') }.get(CLIENT, (None, None)) - ort = params['MANDANTENORT'].title() + ort = PARAMETERS['MANDANTENORT'].title() new_params: Dict[str, Optional[str]] = { 'CLIENT_NAME_TOKEN': tokens[0], 'CLIENT_NAME_SHORT': tokens[1], 'CLIENT_NAME': name, 'CLIENT_NAME_SUFFIX': None, 'CLIENT_NAME_TYPE': types[suffix], - 'CLIENT_PLZ': params['MANDANTENPLZ'], + 'CLIENT_PLZ': PARAMETERS['MANDANTENPLZ'], 'CLIENT_ORT': ort, - 'CLIENT_ADDRESS': params['MANDANTENSTRASSE'], + 'CLIENT_ADDRESS': PARAMETERS['MANDANTENSTRASSE'], 'CLIENT_IBAN': None, 'CLIENT_BIC': None, - 'CLIENT_USTIDNR': params['MANDANTENUID'].replace(' ', ''), - 'CLIENT_LFBISNR': params['MANDANTENBETRIEBSNUMMER'], - 'CLIENT_PHONE': normalize_phone_nr(params['MANDANTENTELEFON'], ort), - 'CLIENT_FAX': normalize_phone_nr(params['MANDANTENTELEFAX'], ort), - 'CLIENT_EMAIL': params['MANDANTENEMAIL'], - 'CLIENT_WEBSITE': params.get('MANDANTENHOMEPAGE', None), - 'DELIVERY_OBLIGATION': params.get('LIEFERPFLICHT/GA1', None), - 'DELIVERY_RIGHT': params.get('LIEFERRECHT/GA1', None), - 'VAT_NORMAL': '0.20', - 'VAT_REDUCED': '0.10', - 'VAT_FLATRATE': '0.13', - 'DOCUMENT_SENDER': params.get('ABSENDERTEXT2', None), - 'TEXT_DELIVERYNOTE': params.get('LIEFERSCHEINTEXT', None).replace(' daß ', ' dass ').replace('obige Angaben maßgeblicher Veränderungen', 'maßgeblichen Veränderungen obiger Angaben'), - 'TEXT_DELIVERYCONFIRMATION': params.get('ANLIEFTEXT', None), + 'CLIENT_USTIDNR': PARAMETERS['MANDANTENUID'].replace(' ', ''), + 'CLIENT_LFBISNR': PARAMETERS['MANDANTENBETRIEBSNUMMER'], + 'CLIENT_PHONE': normalize_phone_nr(PARAMETERS['MANDANTENTELEFON'], ort), + 'CLIENT_FAX': normalize_phone_nr(PARAMETERS['MANDANTENTELEFAX'], ort), + 'CLIENT_EMAIL': PARAMETERS['MANDANTENEMAIL'], + 'CLIENT_WEBSITE': PARAMETERS.get('MANDANTENHOMEPAGE', None), + 'DOCUMENT_SENDER': PARAMETERS.get('ABSENDERTEXT2', None), + 'TEXT_DELIVERYNOTE': PARAMETERS.get('LIEFERSCHEINTEXT', None).replace(' daß ', ' dass ').replace('obige Angaben maßgeblicher Veränderungen', 'maßgeblichen Veränderungen obiger Angaben'), + 'TEXT_DELIVERYCONFIRMATION': PARAMETERS.get('ANLIEFTEXT', None), } with utils.csv_open(f'{out_dir}/client_parameter.csv') as f: @@ -1777,6 +1781,7 @@ def main() -> None: DB_CNX = sqlite3.connect(args.database) + migrate_parameters(args.in_dir, args.out_dir) migrate_gradation(args.in_dir, args.out_dir) migrate_branches(args.in_dir, args.out_dir) migrate_grosslagen(args.in_dir, args.out_dir) @@ -1789,7 +1794,6 @@ def main() -> None: migrate_area_commitments(args.in_dir, args.out_dir) migrate_deliveries(args.in_dir, args.out_dir) migrate_payments(args.in_dir, args.out_dir) - migrate_parameters(args.in_dir, args.out_dir) DB_CNX.close()