Add area_commitment_parcel table
This commit is contained in:
@ -343,6 +343,7 @@ CREATE TABLE contract (
|
|||||||
|
|
||||||
year_from INTEGER NOT NULL CHECK (year_from >= 1000 AND year_from <= 9999),
|
year_from INTEGER NOT NULL CHECK (year_from >= 1000 AND year_from <= 9999),
|
||||||
year_to INTEGER CHECK (year_to >= 1000 AND year_to <= 9999) DEFAULT NULL,
|
year_to INTEGER CHECK (year_to >= 1000 AND year_to <= 9999) DEFAULT NULL,
|
||||||
|
comment TEXT DEFAULT NULL,
|
||||||
|
|
||||||
CONSTRAINT pk_contract PRIMARY KEY (vnr),
|
CONSTRAINT pk_contract PRIMARY KEY (vnr),
|
||||||
CONSTRAINT fk_contract_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
|
CONSTRAINT fk_contract_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
|
||||||
@ -352,16 +353,11 @@ CREATE TABLE contract (
|
|||||||
|
|
||||||
CREATE TABLE area_commitment (
|
CREATE TABLE area_commitment (
|
||||||
vnr INTEGER NOT NULL,
|
vnr INTEGER NOT NULL,
|
||||||
kgnr INTEGER NOT NULL,
|
|
||||||
gstnr TEXT NOT NULL CHECK (gstnr REGEXP '^\.?[1-9][0-9]*(/[1-9][0-9]*)*$'),
|
|
||||||
|
|
||||||
rdnr INTEGER,
|
|
||||||
area INTEGER NOT NULL,
|
|
||||||
|
|
||||||
sortid TEXT NOT NULL,
|
sortid TEXT NOT NULL,
|
||||||
cultid TEXT NOT NULL,
|
cultid TEXT NOT NULL,
|
||||||
|
area INTEGER NOT NULL,
|
||||||
|
|
||||||
CONSTRAINT pk_area_commitment PRIMARY KEY (vnr, kgnr, gstnr),
|
CONSTRAINT pk_area_commitment PRIMARY KEY (vnr),
|
||||||
CONSTRAINT fk_area_commitment_contract FOREIGN KEY (vnr) REFERENCES contract (vnr)
|
CONSTRAINT fk_area_commitment_contract FOREIGN KEY (vnr) REFERENCES contract (vnr)
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE,
|
ON DELETE CASCADE,
|
||||||
@ -370,7 +366,21 @@ CREATE TABLE area_commitment (
|
|||||||
ON DELETE RESTRICT,
|
ON DELETE RESTRICT,
|
||||||
CONSTRAINT fk_area_commitment_wine_cultivation FOREIGN KEY (cultid) REFERENCES wine_cultivation (cultid)
|
CONSTRAINT fk_area_commitment_wine_cultivation FOREIGN KEY (cultid) REFERENCES wine_cultivation (cultid)
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE RESTRICT,
|
ON DELETE RESTRICT
|
||||||
|
) STRICT;
|
||||||
|
|
||||||
|
CREATE TABLE area_commitment_parcel (
|
||||||
|
vnr INTEGER NOT NULL,
|
||||||
|
kgnr INTEGER NOT NULL,
|
||||||
|
gstnr TEXT NOT NULL CHECK (gstnr REGEXP '^\.?[1-9][0-9]*(/[1-9][0-9]*)*$'),
|
||||||
|
|
||||||
|
rdnr INTEGER,
|
||||||
|
area INTEGER,
|
||||||
|
|
||||||
|
CONSTRAINT pk_area_commitment_parcel PRIMARY KEY (vnr, kgnr, gstnr),
|
||||||
|
CONSTRAINT fk_area_commitment_parcel_area_commitment FOREIGN KEY (vnr) REFERENCES area_commitment (vnr)
|
||||||
|
ON UPDATE CASCADE
|
||||||
|
ON DELETE CASCADE,
|
||||||
CONSTRAINT fk_area_commitment_wb_rd FOREIGN KEY (kgnr, rdnr) REFERENCES wb_rd (kgnr, rdnr)
|
CONSTRAINT fk_area_commitment_wb_rd FOREIGN KEY (kgnr, rdnr) REFERENCES wb_rd (kgnr, rdnr)
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE RESTRICT
|
ON DELETE RESTRICT
|
||||||
@ -378,12 +388,10 @@ CREATE TABLE area_commitment (
|
|||||||
|
|
||||||
CREATE TABLE area_commitment_attribute (
|
CREATE TABLE area_commitment_attribute (
|
||||||
vnr INTEGER NOT NULL,
|
vnr INTEGER NOT NULL,
|
||||||
kgnr INTEGER NOT NULL,
|
|
||||||
gstnr TEXT NOT NULL,
|
|
||||||
attrid TEXT NOT NULL,
|
attrid TEXT NOT NULL,
|
||||||
|
|
||||||
CONSTRAINT pk_area_commitment_attribute PRIMARY KEY (vnr, kgnr, gstnr, attrid),
|
CONSTRAINT pk_area_commitment_attribute PRIMARY KEY (vnr, attrid),
|
||||||
CONSTRAINT fk_area_commitment_attribute_area_commitment FOREIGN KEY (vnr, kgnr, gstnr) REFERENCES area_commitment (vnr, kgnr, gstnr)
|
CONSTRAINT fk_area_commitment_attribute_area_commitment FOREIGN KEY (vnr) REFERENCES area_commitment (vnr)
|
||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE CASCADE,
|
ON DELETE CASCADE,
|
||||||
CONSTRAINT fk_area_commitment_attribute_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
CONSTRAINT fk_area_commitment_attribute_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
||||||
|
@ -5,6 +5,20 @@ FROM AT_gem g
|
|||||||
JOIN AT_ort o ON o.gkz = g.gkz
|
JOIN AT_ort o ON o.gkz = g.gkz
|
||||||
JOIN AT_plz_dest p ON p.okz = o.okz;
|
JOIN AT_plz_dest p ON p.okz = o.okz;
|
||||||
|
|
||||||
|
CREATE VIEW v_contract AS
|
||||||
|
SELECT v.vnr, v.mgnr, v.year_from, v.year_to,
|
||||||
|
GROUP_CONCAT(DISTINCT p.kgnr || '-' || p.gstnr) AS gstnrs,
|
||||||
|
f.area, f.sortid,
|
||||||
|
GROUP_CONCAT(DISTINCT a.attrid) AS attributes,
|
||||||
|
f.cultid,
|
||||||
|
v.comment
|
||||||
|
FROM contract v
|
||||||
|
LEFT JOIN area_commitment f ON f.vnr = v.vnr
|
||||||
|
LEFT JOIN area_commitment_parcel p ON p.vnr = f.vnr
|
||||||
|
LEFT JOIN area_commitment_attribute a ON a.vnr = f.vnr
|
||||||
|
GROUP BY v.vnr
|
||||||
|
ORDER BY v.vnr;
|
||||||
|
|
||||||
CREATE VIEW v_delivery AS
|
CREATE VIEW v_delivery AS
|
||||||
SELECT p.year, p.did, p.dpnr,
|
SELECT p.year, p.did, p.dpnr,
|
||||||
d.date, d.time, d.zwstid, d.lnr, d.lsnr,
|
d.date, d.time, d.zwstid, d.lnr, d.lsnr,
|
||||||
|
@ -14,7 +14,8 @@ import csv
|
|||||||
DIR: str
|
DIR: str
|
||||||
|
|
||||||
TABLES = ['branch', 'wb_gl', 'wb_kg', 'wb_rd', 'wine_attribute', 'wine_cultivation',
|
TABLES = ['branch', 'wb_gl', 'wb_kg', 'wb_rd', 'wine_attribute', 'wine_cultivation',
|
||||||
'member', 'member_billing_address', 'contract', 'area_commitment', 'area_commitment_attribute',
|
'member', 'member_billing_address', 'contract',
|
||||||
|
'area_commitment', 'area_commitment_parcel', 'area_commitment_attribute',
|
||||||
'season', 'modifier', 'delivery', 'delivery_part', 'delivery_part_attribute', 'delivery_part_modifier', ]
|
'season', 'modifier', 'delivery', 'delivery_part', 'delivery_part_attribute', 'delivery_part_modifier', ]
|
||||||
# 'payment_variant', 'delivery_payment', 'member_payment']
|
# 'payment_variant', 'delivery_payment', 'member_payment']
|
||||||
|
|
||||||
|
@ -652,10 +652,12 @@ def migrate_contracts(in_dir: str, out_dir: str) -> None:
|
|||||||
|
|
||||||
with open(f'{out_dir}/contract.csv', 'w+') as f_c, \
|
with open(f'{out_dir}/contract.csv', 'w+') as f_c, \
|
||||||
open(f'{out_dir}/area_commitment.csv', 'w+') as f_fb, \
|
open(f'{out_dir}/area_commitment.csv', 'w+') as f_fb, \
|
||||||
|
open(f'{out_dir}/area_commitment_parcel.csv', 'w+') as f_parc, \
|
||||||
open(f'{out_dir}/area_commitment_attribute.csv', 'w+') as f_attr:
|
open(f'{out_dir}/area_commitment_attribute.csv', 'w+') as f_attr:
|
||||||
f_c.write('vnr;mgnr;year_from;year_to\n')
|
f_c.write('vnr;mgnr;year_from;year_to;comment\n')
|
||||||
f_fb.write('vnr;kgnr;gstnr;rdnr;area;sortid;cultid\n')
|
f_fb.write('vnr;sortid;cultid;area\n')
|
||||||
f_attr.write('vnr;kgnr;gstnr;attrid\n')
|
f_parc.write('vnr;kgnr;gstnr;rdnr;area\n')
|
||||||
|
f_attr.write('vnr;attrid\n')
|
||||||
|
|
||||||
for fb in csv.parse_dict(f'{in_dir}/TFlaechenbindungen.csv'):
|
for fb in csv.parse_dict(f'{in_dir}/TFlaechenbindungen.csv'):
|
||||||
if fb['Von'] is None and fb['Bis'] is None:
|
if fb['Von'] is None and fb['Bis'] is None:
|
||||||
@ -668,28 +670,26 @@ def migrate_contracts(in_dir: str, out_dir: str) -> None:
|
|||||||
if mgnr not in MEMBER_MAP:
|
if mgnr not in MEMBER_MAP:
|
||||||
continue
|
continue
|
||||||
|
|
||||||
f_c.write(csv.format_row(
|
|
||||||
vnr, mgnr, fb['Von'], fb['Bis'] if fb['Bis'] and fb['Bis'] < 3000 else None
|
|
||||||
))
|
|
||||||
gstnrs = parse_gstnrs(parz, kgnr, fb['MGNR'])
|
|
||||||
|
|
||||||
area = int(fb['Flaeche'])
|
area = int(fb['Flaeche'])
|
||||||
gst_area = int(area / (len(gstnrs) or 1))
|
gstnrs = parse_gstnrs(parz, kgnr, fb['MGNR'])
|
||||||
|
comment = None
|
||||||
if parz is None or parz == '0000':
|
if parz is None or parz == '0000':
|
||||||
invalid(mgnr, 'GstNr.', f'{kgnr or 0:05}-{parz}')
|
invalid(mgnr, 'GstNr.', f'{kgnr or 0:05}-{parz}')
|
||||||
gstnrs = ['99999']
|
gstnrs = []
|
||||||
elif len(gstnrs) > 1 or (len(gstnrs) == 1 and gstnrs[0] != parz):
|
elif len(gstnrs) > 1 or (len(gstnrs) == 1 and gstnrs[0] != parz):
|
||||||
convert(mgnr, 'GstNr.', f'{kgnr or 0:05}-{parz or ""}', ', '.join(gstnrs))
|
convert(mgnr, 'GstNr.', f'{kgnr or 0:05}-{parz or ""}', ', '.join(gstnrs))
|
||||||
|
if len(gstnrs) == 0:
|
||||||
|
comment = f'KG {kgnr}: {parz}'
|
||||||
|
|
||||||
for i, gstnr in enumerate(gstnrs):
|
to = fb['Bis'] if fb['Bis'] and fb['Bis'] < 3000 else None
|
||||||
a = area - gst_area * (len(gstnrs) - 1) if i == 0 else gst_area
|
f_c.write(csv.format_row(vnr, mgnr, fb['Von'], to, comment))
|
||||||
rdnr = REED_MAP[fb['RNR']][1] if fb['RNR'] else None
|
|
||||||
f_fb.write(csv.format_row(
|
f_fb.write(csv.format_row(vnr, fb['SNR'], CULTIVATION_MAP[fb['BANR']], area))
|
||||||
vnr, kgnr, gstnr, rdnr, a, fb['SNR'], CULTIVATION_MAP[fb['BANR']]
|
|
||||||
))
|
|
||||||
if fb['SANR']:
|
if fb['SANR']:
|
||||||
f_attr.write(csv.format_row(vnr, kgnr, gstnr, fb['SANR']))
|
f_attr.write(csv.format_row(vnr, fb['SANR']))
|
||||||
|
for i, gstnr in enumerate(gstnrs):
|
||||||
|
rdnr = REED_MAP[fb['RNR']][1] if fb['RNR'] else None
|
||||||
|
f_parc.write(csv.format_row(vnr, kgnr, gstnr, rdnr, area if len(gstnrs) == 1 else None))
|
||||||
|
|
||||||
|
|
||||||
def fix_deliveries(deliveries: Iterable[Dict[str, Any]]) -> Iterable[Tuple[str, List[int], datetime.date]]:
|
def fix_deliveries(deliveries: Iterable[Dict[str, Any]]) -> Iterable[Tuple[str, List[int], datetime.date]]:
|
||||||
|
Reference in New Issue
Block a user