From 922957d72d28ac506c95ecdc198b9ac863f1f93c Mon Sep 17 00:00:00 2001 From: Lorenz Stechauner Date: Tue, 31 Oct 2023 22:15:48 +0100 Subject: [PATCH] database: remove delivery_part_attribute table --- sql/v01/11.create.client.sql | 12 ++---- sql/v01/12.create.season.sql | 19 ++------- sql/v01/20.create.timestamp-trigger.sql | 20 --------- sql/v01/30.create.view.sql | 54 ++++++++++++------------- sql/v01/99.schema_version.sql | 2 +- wgmaster/import.py | 2 +- wgmaster/migrate.py | 22 +++++----- 7 files changed, 47 insertions(+), 84 deletions(-) diff --git a/sql/v01/11.create.client.sql b/sql/v01/11.create.client.sql index bbe03f7..5595e5b 100644 --- a/sql/v01/11.create.client.sql +++ b/sql/v01/11.create.client.sql @@ -36,10 +36,9 @@ CREATE TABLE wine_attribute ( ) STRICT; CREATE TABLE area_commitment_type ( - vtrgid TEXT NOT NULL CHECK (vtrgid LIKE sortid || attrid_1 || attrid_2 || disc), + vtrgid TEXT NOT NULL CHECK (vtrgid = sortid || COALESCE(attrid, '') || disc), sortid TEXT NOT NULL, - attrid_1 TEXT, - attrid_2 TEXT, + attrid TEXT, disc TEXT DEFAULT NULL CHECK (disc REGEXP '^[A-Z0-9]+$'), min_kg_per_ha INTEGER, @@ -47,14 +46,11 @@ CREATE TABLE area_commitment_type ( penalty_amount INTEGER, CONSTRAINT pk_area_commitment_type PRIMARY KEY (vtrgid), - CONSTRAINT sk_area_commitment_type_sort_attr UNIQUE (sortid, attrid_1, attrid_2, disc), + CONSTRAINT sk_area_commitment_type_sort_attr UNIQUE (sortid, attrid, disc), CONSTRAINT fk_area_commitment_type_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid) ON UPDATE CASCADE ON DELETE RESTRICT, - CONSTRAINT fk_area_commitment_type_wine_attribute FOREIGN KEY (attrid_1) REFERENCES wine_attribute (attrid) - ON UPDATE CASCADE - ON DELETE RESTRICT, - CONSTRAINT fk_area_commitment_type_wine_attribute FOREIGN KEY (attrid_2) REFERENCES wine_attribute (attrid) + CONSTRAINT fk_area_commitment_type_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; diff --git a/sql/v01/12.create.season.sql b/sql/v01/12.create.season.sql index 4e26152..54ec618 100644 --- a/sql/v01/12.create.season.sql +++ b/sql/v01/12.create.season.sql @@ -77,6 +77,7 @@ CREATE TABLE delivery_part ( dpnr INTEGER NOT NULL, sortid TEXT NOT NULL, + attrid TEXT, weight INTEGER NOT NULL, kmw REAL NOT NULL, qualid TEXT NOT NULL, @@ -111,6 +112,9 @@ CREATE TABLE delivery_part ( CONSTRAINT fk_delivery_part_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid) ON UPDATE CASCADE ON DELETE RESTRICT, + CONSTRAINT fk_delivery_part_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid) + ON UPDATE CASCADE + ON DELETE RESTRICT, CONSTRAINT fk_delivery_part_wine_quality_level FOREIGN KEY (qualid) REFERENCES wine_quality_level (qualid) ON UPDATE CASCADE ON DELETE RESTRICT, @@ -157,21 +161,6 @@ BEGIN WHERE wk.kgnr = NEW.kgnr AND NEW.hkid IN (wo1.hkid, wo2.hkid, wo3.hkid, wo4.hkid)); END; -CREATE TABLE delivery_part_attribute ( - year INTEGER NOT NULL, - did INTEGER NOT NULL, - dpnr INTEGER NOT NULL, - attrid TEXT NOT NULL, - - CONSTRAINT pk_delivery_part_attribute PRIMARY KEY (year, did, dpnr, attrid), - CONSTRAINT fk_delivery_part_attribute_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr) - ON UPDATE CASCADE - ON DELETE CASCADE, - CONSTRAINT fk_delivery_part_attribute_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid) - ON UPDATE CASCADE - ON DELETE RESTRICT -) STRICT; - CREATE TABLE delivery_part_modifier ( year INTEGER NOT NULL, did INTEGER NOT NULL, diff --git a/sql/v01/20.create.timestamp-trigger.sql b/sql/v01/20.create.timestamp-trigger.sql index fb2b951..1d105c3 100644 --- a/sql/v01/20.create.timestamp-trigger.sql +++ b/sql/v01/20.create.timestamp-trigger.sql @@ -177,26 +177,6 @@ END; ---------------------------------------------------------------- -CREATE TRIGGER t_delivery_part_attribute_i_mtime_delivery_part - AFTER INSERT ON delivery_part_attribute FOR EACH ROW -BEGIN - UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); -END; - -CREATE TRIGGER t_delivery_part_attribute_u_mtime_delivery_part - AFTER UPDATE ON delivery_part_attribute FOR EACH ROW -BEGIN - UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr) OR (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); -END; - -CREATE TRIGGER t_delivery_part_attribute_d_mtime_delivery_part - AFTER DELETE ON delivery_part_attribute FOR EACH ROW -BEGIN - UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); -END; - ----------------------------------------------------------------- - CREATE TRIGGER t_delivery_part_modifier_i_mtime_delivery_part AFTER INSERT ON delivery_part_modifier FOR EACH ROW BEGIN diff --git a/sql/v01/30.create.view.sql b/sql/v01/30.create.view.sql index 4a5c850..9ed30ad 100644 --- a/sql/v01/30.create.view.sql +++ b/sql/v01/30.create.view.sql @@ -19,31 +19,29 @@ GROUP BY c.fbnr ORDER BY c.fbnr; CREATE VIEW v_delivery AS -SELECT s.*, GROUP_CONCAT(o.modid) AS modifiers -FROM (SELECT p.year, p.did, p.dpnr, - d.date, d.time, d.zwstid, d.lnr, d.lsnr, - m.mgnr, m.family_name, m.given_name, - p.sortid, p.weight, p.kmw, ROUND(p.kmw * (4.54 + 0.022 * p.kmw), 0) AS oe, p.qualid, p.hkid, p.kgnr, p.rdnr, - 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, - GROUP_CONCAT(a.attrid) AS attributes, - COALESCE(SUM(a.fill_lower_bins), 0) AS attribute_prio, - d.comment, p.comment AS part_comment - FROM delivery_part p - JOIN delivery d ON (d.year, d.did) = (p.year, p.did) - JOIN member m ON m.mgnr = d.mgnr - LEFT JOIN delivery_part_attribute pa ON (pa.year, pa.did, pa.dpnr) = (p.year, p.did, p.dpnr) - LEFT JOIN wine_attribute a ON a.attrid = pa.attrid - GROUP BY p.year, p.did, p.dpnr - ORDER BY p.year, p.did, p.dpnr, a.attrid) s -LEFT JOIN delivery_part_modifier o ON (o.year, o.did, o.dpnr) = (s.year, s.did, s.dpnr) -GROUP BY s.year, s.lsnr, s.dpnr -ORDER BY s.year, s.lsnr, s.dpnr, o.modid; +SELECT p.year, p.did, p.dpnr, + d.date, d.time, d.zwstid, d.lnr, d.lsnr, + m.mgnr, m.family_name, m.given_name, + p.sortid, a.attrid, + p.weight, p.kmw, ROUND(p.kmw * (4.54 + 0.022 * p.kmw), 0) AS oe, p.qualid, + p.hkid, p.kgnr, p.rdnr, + 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, + GROUP_CONCAT(o.modid) AS modifiers, + d.comment, p.comment AS part_comment +FROM delivery_part p + JOIN delivery d ON (d.year, d.did) = (p.year, p.did) + JOIN member m ON m.mgnr = d.mgnr + LEFT JOIN wine_attribute a ON a.attrid = p.attrid + LEFT JOIN delivery_part_modifier o ON (o.year, o.did, o.dpnr) = (p.year, p.did, p.dpnr) +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, REPLACE(COALESCE(attributes, ''), ',', ''), '_') AS bin, + sortid || IIF(min_quw, COALESCE(attrid, ''), '_') AS bin, SUM(weight) AS weight FROM v_delivery GROUP BY year, mgnr, bin @@ -94,26 +92,26 @@ GROUP BY year, sortid ORDER BY year, sortid; CREATE VIEW v_stat_attr AS -SELECT year, attributes, +SELECT year, attrid, SUM(weight) as sum, ROUND(SUM(kmw * weight) / SUM(weight), 2) AS kmw, ROUND(SUM(oe * weight) / SUM(weight), 1) AS oe, COUNT(DISTINCT did) AS lieferungen, COUNT(DISTINCT mgnr) AS mitglieder FROM v_delivery -GROUP BY year, attributes -ORDER BY year, LENGTH(attributes) DESC, attributes; +GROUP BY year, attrid +ORDER BY year, attrid; CREATE VIEW v_stat_sort_attr AS -SELECT year, sortid, attributes, +SELECT year, sortid, attrid, SUM(weight) as sum, ROUND(SUM(kmw * weight) / SUM(weight), 2) AS kmw, ROUND(SUM(oe * weight) / SUM(weight), 1) AS oe, COUNT(DISTINCT did) AS lieferungen, COUNT(DISTINCT mgnr) AS mitglieder FROM v_delivery -GROUP BY year, sortid, attributes -ORDER BY year, sortid, LENGTH(attributes) DESC, attributes; +GROUP BY year, sortid, attrid +ORDER BY year, sortid, attrid; CREATE VIEW v_bki_member AS SELECT s.year, m.mgnr, m.lfbis_nr, m.family_name, diff --git a/sql/v01/99.schema_version.sql b/sql/v01/99.schema_version.sql index b56dbe2..0c37a76 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 = 400; +PRAGMA schema_version = 500; diff --git a/wgmaster/import.py b/wgmaster/import.py index a02639a..a56c5a1 100755 --- a/wgmaster/import.py +++ b/wgmaster/import.py @@ -14,7 +14,7 @@ DIR: str 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_attribute', 'delivery_part_modifier', + 'season', 'modifier', 'delivery', 'delivery_part', 'delivery_part_modifier', 'delivery_part_bin', 'payment_variant', 'payment_delivery_part'] diff --git a/wgmaster/migrate.py b/wgmaster/migrate.py index 37b6477..7d8ce60 100755 --- a/wgmaster/migrate.py +++ b/wgmaster/migrate.py @@ -630,23 +630,23 @@ def migrate_cultivations(in_dir: str, out_dir: str) -> 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_1', 'attrid_2', 'disc', + f.header('vtrgid', 'sortid', 'attrid', 'disc', 'min_kg_per_ha', 'max_kg_per_ha', 'penalty_amount') 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, None, + f.row(sortid + (t['SANR'] or ''), sortid[:2], t['SANR'] or sortid[2:] or None, None, menge, menge, None) bio = [] if CLIENT == WG.MATZEN: bio = ['GV', 'ZW', 'MT'] - f.row('BM', 'BM', None, None, None, None, None, None) + f.row('BM', 'BM', 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, None) + f.row(f'{sortid}B', sortid, 'B', 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]]: @@ -1356,13 +1356,11 @@ def migrate_deliveries(in_dir: str, out_dir: str) -> None: updated_varieties = {} with utils.csv_open(f'{out_dir}/delivery.csv') as f_delivery, \ - utils.csv_open(f'{out_dir}/delivery_part.csv') as f_part, \ - utils.csv_open(f'{out_dir}/delivery_part_attribute.csv') as f_attr: + utils.csv_open(f'{out_dir}/delivery_part.csv') as f_part: f_delivery.header('year', 'did', 'date', 'time', 'zwstid', 'lnr', 'lsnr', 'mgnr', 'comment') - f_part.header('year', 'did', 'dpnr', 'sortid', 'weight', 'kmw', 'qualid', 'hkid', 'kgnr', 'rdnr', + f_part.header('year', 'did', 'dpnr', 'sortid', 'attrid', 'weight', 'kmw', 'qualid', 'hkid', 'kgnr', 'rdnr', 'gerebelt', 'manual_weighing', 'spl_check', 'hand_picked', 'lesewagen', 'gebunden', 'temperature', 'acid', 'scale_id', 'weighing_id', 'weighing_reason', 'comment') - f_attr.header('year', 'did', 'dpnr', 'attrid') for lsnr, linrs, date in fixed: if date.year not in seasons: @@ -1416,6 +1414,7 @@ def migrate_deliveries(in_dir: str, out_dir: str) -> None: if sortid == 'HU': # Gr.Veltliner (Huber) sortid = 'GV' + attributes.remove('B') attributes.add('HU') elif sortid == 'SV': sortid = 'SW' @@ -1500,13 +1499,14 @@ def migrate_deliveries(in_dir: str, out_dir: str) -> None: comments.append(comment) gerebelt = True if CLIENT == WG.MATZEN or (CLIENT == WG.WINZERKELLER and zwstid == 'W') else d['Gerebelt'] or False gebunden = None if CLIENT in (WG.MATZEN, WG.WINZERKELLER) else d['Gebunden'] + if len(attributes) > 1: + print("ERROR: ", attributes) + attrid = attributes.pop() if len(attributes) == 1 else None f_part.row( - date.year, snr, dpnr, sortid, int(d['Gewicht']), kmw, qualid, hkid, kgnr, rdnr, + date.year, snr, dpnr, sortid, attrid, int(d['Gewicht']), kmw, qualid, hkid, kgnr, rdnr, gerebelt, handwiegung, d['Spaetlese-Ueberpruefung'] or False, hand, lesewagen, gebunden, d['Temperatur'], acid, scale_id, weighing_id, None, comment ) - for attrid in attributes: - f_attr.row(date.year, snr, dpnr, attrid) f_delivery.row(date.year, snr, date, d['Uhrzeit'], zwstid, lnr, lsnr, mgnr, '; '.join(comments) or None) for k, v in updated_varieties.items(): print(k + (f' ({v} times)' if v > 1 else ''))