Billing: Add feature to calculate member/delivery bins
This commit is contained in:
@ -4,7 +4,7 @@ using System;
|
||||
namespace Elwig.Helpers {
|
||||
public static class AppDbUpdater {
|
||||
|
||||
public static readonly int RequiredSchemaVersion = 2;
|
||||
public static readonly int RequiredSchemaVersion = 3;
|
||||
|
||||
private static int _versionOffset = 0;
|
||||
private static readonly Action<SqliteConnection>[] _updaters = new[] {
|
||||
@ -80,6 +80,99 @@ namespace Elwig.Helpers {
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE delivery_part ADD COLUMN weighing_reason TEXT CHECK(NOT (manual_weighing = FALSE AND weighing_reason IS NOT NULL))");
|
||||
}
|
||||
|
||||
private static void UpdateDbSchema_2_To_3(SqliteConnection cnx) { }
|
||||
private static void UpdateDbSchema_2_To_3(SqliteConnection cnx) {
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_1_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_2_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_3_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_4_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_5_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_6_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_7_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_8_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN bin_9_name TEXT DEFAULT NULL");
|
||||
ExecuteNonQuery(cnx, """
|
||||
UPDATE season
|
||||
SET bin_1_name = n.bucket_1_name,
|
||||
bin_2_name = n.bucket_2_name,
|
||||
bin_3_name = n.bucket_3_name,
|
||||
bin_4_name = n.bucket_4_name,
|
||||
bin_5_name = n.bucket_5_name,
|
||||
bin_6_name = n.bucket_6_name,
|
||||
bin_7_name = n.bucket_7_name,
|
||||
bin_8_name = n.bucket_8_name,
|
||||
bin_9_name = n.bucket_9_name
|
||||
FROM (SELECT year, bucket_1_name, bucket_2_name, bucket_3_name, bucket_4_name, bucket_5_name, bucket_6_name, bucket_7_name, bucket_8_name, bucket_9_name
|
||||
FROM payment_variant GROUP BY year HAVING avnr = MAX(avnr)) AS n
|
||||
WHERE season.year = n.year
|
||||
""");
|
||||
ExecuteNonQuery(cnx, """
|
||||
CREATE TABLE delivery_part_bin (
|
||||
year INTEGER NOT NULL,
|
||||
did INTEGER NOT NULL,
|
||||
dpnr INTEGER NOT NULL,
|
||||
|
||||
bin_1 INTEGER DEFAULT NULL,
|
||||
bin_2 INTEGER DEFAULT 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 fk_delivery_part_bin_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE
|
||||
) STRICT;
|
||||
""");
|
||||
ExecuteNonQuery(cnx, """
|
||||
INSERT INTO delivery_part_bin
|
||||
(year, did, dpnr, bin_1, bin_2, bin_3, bin_4, bin_5, bin_6, bin_7, bin_8, bin_9)
|
||||
SELECT year, did, dpnr, bucket_1, bucket_2, bucket_3, bucket_4, bucket_5, bucket_6, bucket_7, bucket_8, bucket_9
|
||||
FROM payment_delivery_part
|
||||
WHERE COALESCE(bucket_1, bucket_2, bucket_3, bucket_4, bucket_5, bucket_6, bucket_7, bucket_8, bucket_9) IS NOT NULL
|
||||
ON CONFLICT DO NOTHING;
|
||||
""");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_1");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_2");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_3");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_4");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_5");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_6");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_7");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_8");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_delivery_part DROP COLUMN bucket_9");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_1_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_2_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_3_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_4_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_5_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_6_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_7_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_8_name");
|
||||
ExecuteNonQuery(cnx, "ALTER TABLE payment_variant DROP COLUMN bucket_9_name");
|
||||
|
||||
ExecuteNonQuery(cnx, "DROP VIEW v_delivery");
|
||||
ExecuteNonQuery(cnx, """
|
||||
CREATE VIEW v_delivery AS
|
||||
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.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(DISTINCT a.attrid) as attributes, GROUP_CONCAT(DISTINCT 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 delivery_part_attribute a ON (a.year, a.did, a.dpnr) = (p.year, p.did, p.dpnr)
|
||||
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;
|
||||
""");
|
||||
}
|
||||
}
|
||||
}
|
||||
|
Reference in New Issue
Block a user