Database: change bins and so on...

This commit is contained in:
2023-10-15 22:43:05 +02:00
parent 2143bf66e5
commit 192b3a3846
3 changed files with 47 additions and 43 deletions

View File

@ -445,16 +445,6 @@ CREATE TABLE season (
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])$'), 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])$'), 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])$'),
bin_1_name TEXT DEFAULT NULL,
bin_2_name TEXT DEFAULT NULL,
bin_3_name TEXT DEFAULT NULL,
bin_4_name TEXT DEFAULT NULL,
bin_5_name TEXT DEFAULT NULL,
bin_6_name TEXT DEFAULT NULL,
bin_7_name TEXT DEFAULT NULL,
bin_8_name TEXT DEFAULT NULL,
bin_9_name TEXT DEFAULT NULL,
CONSTRAINT pk_season PRIMARY KEY (year), CONSTRAINT pk_season PRIMARY KEY (year),
CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code) CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code)
ON UPDATE CASCADE ON UPDATE CASCADE
@ -639,18 +629,12 @@ CREATE TABLE delivery_part_bin (
year INTEGER NOT NULL, year INTEGER NOT NULL,
did INTEGER NOT NULL, did INTEGER NOT NULL,
dpnr INTEGER NOT NULL, dpnr INTEGER NOT NULL,
binnr INTEGER NOT NULL,
bin_1 INTEGER DEFAULT NULL, discr TEXT NOT NULL,
bin_2 INTEGER DEFAULT NULL, value INTEGER NOT NULL,
bin_3 INTEGER DEFAULT NULL,
bin_4 INTEGER DEFAULT NULL,
bin_5 INTEGER DEFAULT NULL,
bin_6 INTEGER DEFAULT NULL,
bin_7 INTEGER DEFAULT NULL,
bin_8 INTEGER DEFAULT NULL,
bin_9 INTEGER DEFAULT NULL,
CONSTRAINT pk_delivery_part_bin PRIMARY KEY (year, did, dpnr), 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 fk_delivery_part_bin_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
ON UPDATE CASCADE ON UPDATE CASCADE
ON DELETE CASCADE ON DELETE CASCADE
@ -683,17 +667,6 @@ CREATE TABLE payment_delivery_part (
mod_abs INTEGER NOT NULL DEFAULT 0, mod_abs INTEGER NOT NULL DEFAULT 0,
mod_rel REAL NOT NULL DEFAULT 0, mod_rel REAL NOT NULL DEFAULT 0,
price_1 INTEGER DEFAULT NULL,
price_2 INTEGER DEFAULT NULL,
price_3 INTEGER DEFAULT NULL,
price_4 INTEGER DEFAULT NULL,
price_5 INTEGER DEFAULT NULL,
price_6 INTEGER DEFAULT NULL,
price_7 INTEGER DEFAULT NULL,
price_8 INTEGER DEFAULT NULL,
price_9 INTEGER DEFAULT NULL,
amount INTEGER NOT NULL, amount INTEGER NOT NULL,
CONSTRAINT pk_payment_delivery_part PRIMARY KEY (year, did, dpnr, avnr), CONSTRAINT pk_payment_delivery_part PRIMARY KEY (year, did, dpnr, avnr),
@ -710,7 +683,7 @@ CREATE TRIGGER t_payment_delivery_part_i
BEGIN BEGIN
INSERT INTO payment_member (year, avnr, mgnr, amount) INSERT INTO payment_member (year, avnr, mgnr, amount)
VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount) VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount)
ON CONFLICT DO UPDATE SET amount = amount + NEW.amount; ON CONFLICT DO UPDATE SET amount = amount + excluded.amount;
END; END;
CREATE TRIGGER t_payment_delivery_part_u CREATE TRIGGER t_payment_delivery_part_u
@ -729,6 +702,26 @@ BEGIN
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did))); WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
END; END;
-- all values in the table are stored with season-precision!
CREATE TABLE payment_delivery_part_bin (
year INTEGER NOT NULL,
did INTEGER NOT NULL,
dpnr INTEGER NOT NULL,
binnr 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)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_payment_delivery_part_bin_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
-- all values in the table are stored with season-precision! -- all values in the table are stored with season-precision!
CREATE TABLE payment_member ( CREATE TABLE payment_member (
year INTEGER NOT NULL, year INTEGER NOT NULL,
@ -763,8 +756,8 @@ CREATE TABLE credit (
prev_modifiers INTEGER, prev_modifiers INTEGER,
amount INTEGER NOT NULL GENERATED ALWAYS AS (gross_amount + COALESCE(modifiers, 0) - COALESCE(prev_modifiers, 0)) STORED, amount INTEGER NOT NULL GENERATED ALWAYS AS (gross_amount + COALESCE(modifiers, 0) - COALESCE(prev_modifiers, 0)) STORED,
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
CONSTRAINT pk_credit PRIMARY KEY (year, tgnr), CONSTRAINT pk_credit PRIMARY KEY (year, tgnr),
CONSTRAINT sk_credit_payment_member UNIQUE (year, avnr, mgnr), CONSTRAINT sk_credit_payment_member UNIQUE (year, avnr, mgnr),

View File

@ -35,10 +35,11 @@ FROM (SELECT p.year, p.did, p.dpnr,
JOIN member m ON m.mgnr = d.mgnr 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 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 LEFT JOIN wine_attribute a ON a.attrid = pa.attrid
GROUP BY p.year, p.did, p.dpnr) s 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) 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 GROUP BY s.year, s.lsnr, s.dpnr
ORDER BY s.year, s.lsnr, s.dpnr; ORDER BY s.year, s.lsnr, s.dpnr, o.modid;
CREATE VIEW v_delivery_bin AS CREATE VIEW v_delivery_bin AS
SELECT year, mgnr, SELECT year, mgnr,
@ -48,6 +49,16 @@ FROM v_delivery
GROUP BY year, mgnr, bin GROUP BY year, mgnr, bin
ORDER BY year, mgnr, LENGTH(bin) DESC, 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, bin;
CREATE VIEW v_stat_season AS CREATE VIEW v_stat_season AS
SELECT year, SELECT year,
SUM(weight) AS sum, SUM(weight) AS sum,

View File

@ -1511,11 +1511,10 @@ def migrate_deliveries(in_dir: str, out_dir: str) -> None:
with utils.csv_open(f'{out_dir}/season.csv') as f_season, \ with utils.csv_open(f'{out_dir}/season.csv') as f_season, \
utils.csv_open(f'{out_dir}/modifier.csv') as f_mod: 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', 'start_date', 'end_date')
'bin_1_name', 'bin_2_name')
f_mod.header('year', 'modid', 'ordering', 'name', 'abs', 'rel', 'standard', 'quick_select') f_mod.header('year', 'modid', 'ordering', 'name', 'abs', 'rel', 'standard', 'quick_select')
for y, s in seasons.items(): for y, s in seasons.items():
f_season.row(y, s['currency'], s['precision'], s['start'], s['end'], 'gebunden', 'ungebunden') f_season.row(y, s['currency'], s['precision'], s['start'], s['end'])
for m in modifiers.values(): for m in modifiers.values():
abs_v = round(m['AZAS'] * pow(10, s['precision'])) if m['AZAS'] is not None else None 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 rel_v = m['AZASProzent'] / 100.0 if m['AZASProzent'] is not None else None
@ -1670,16 +1669,17 @@ def migrate_payments(in_dir: str, out_dir: str) -> None:
with utils.csv_open(f'{out_dir}/payment_delivery_part.csv') as f_del_pay, \ 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_bin.csv') as f_bin:
f_del_pay.header('year', 'did', 'dpnr', 'avnr', 'amount') f_del_pay.header('year', 'did', 'dpnr', 'avnr', 'amount')
f_bin.header('year', 'did', 'dpnr', 'bin_1', 'bin_2') f_bin.header('year', 'did', 'dpnr', 'binnr', 'discr', 'value')
deliveries = {d['LINR']: d for d in utils.csv_parse_dict(f'{in_dir}/TLieferungen.csv')} 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(): for linr, (y, did, dpnr) in DELIVERY_MAP.items():
p = deliveries[linr] p = deliveries[linr]
if y not in variant_year_map: if y not in variant_year_map:
continue continue
gew, geb_gew = int(p['Gewicht']), int(p['BGewichtGebunden']) gew, geb_gew = int(p['Gewicht']), int(p['BGewichtGebunden'])
b2 = gew - geb_gew b1 = gew - geb_gew
b1 = geb_gew b2 = geb_gew
f_bin.row(y, did, dpnr, b1, b2) f_bin.row(y, did, dpnr, 1, '_', b1)
f_bin.row(y, did, dpnr, 2, p['SANR'] or '', b2)
for aznr, avnr, tznr in variant_year_map[y]: for aznr, avnr, tznr in variant_year_map[y]:
val = p[f'BTeilzahlung{tznr}' if tznr < 6 else 'BEndauszahlung'] val = p[f'BTeilzahlung{tznr}' if tznr < 6 else 'BEndauszahlung']
val = round(val * pow(10, WGMASTER_PRECISION)) val = round(val * pow(10, WGMASTER_PRECISION))