545 lines
29 KiB
C#
545 lines
29 KiB
C#
using Microsoft.Data.Sqlite;
|
|
using System;
|
|
|
|
namespace Elwig.Helpers {
|
|
public static class AppDbUpdater {
|
|
|
|
public static readonly int RequiredSchemaVersion = 7;
|
|
|
|
private static int _versionOffset = 0;
|
|
private static readonly Action<SqliteConnection>[] _updaters = new[] {
|
|
UpdateDbSchema_1_To_2, UpdateDbSchema_2_To_3, UpdateDbSchema_3_To_4, UpdateDbSchema_4_To_5,
|
|
UpdateDbSchema_5_To_6, UpdateDBSchema_6_To_7
|
|
};
|
|
|
|
private static void ExecuteNonQuery(SqliteConnection cnx, string sql) {
|
|
using var cmd = cnx.CreateCommand();
|
|
cmd.CommandText = sql;
|
|
cmd.ExecuteNonQuery();
|
|
}
|
|
|
|
private static object? ExecuteScalar(SqliteConnection cnx, string sql) {
|
|
using var cmd = cnx.CreateCommand();
|
|
cmd.CommandText = sql;
|
|
return cmd.ExecuteScalar();
|
|
}
|
|
|
|
public static string CheckDb() {
|
|
using var cnx = AppDbContext.Connect();
|
|
|
|
var applId = (long?)ExecuteScalar(cnx, "PRAGMA application_id") ?? 0;
|
|
if (applId != 0x454C5747) throw new Exception("Invalid application_id of database");
|
|
|
|
var schemaVers = (long?)ExecuteScalar(cnx, "PRAGMA schema_version") ?? 0;
|
|
_versionOffset = (int)(schemaVers % 100);
|
|
if (_versionOffset != 0) {
|
|
// schema was modified manually/externally
|
|
// TODO issue warning
|
|
}
|
|
UpdateDbSchema(cnx, (int)(schemaVers / 100), RequiredSchemaVersion);
|
|
|
|
var userVers = (long?)ExecuteScalar(cnx, "PRAGMA user_version") ?? 0;
|
|
var major = userVers >> 24;
|
|
var minor = (userVers >> 16) & 0xFF;
|
|
var patch = userVers & 0xFFFF;
|
|
|
|
if (App.VersionMajor > major ||
|
|
(App.VersionMajor == major && App.VersionMinor > minor) ||
|
|
(App.VersionMajor == major && App.VersionMinor == minor && App.VersionPatch > patch))
|
|
{
|
|
long vers = (App.VersionMajor << 24) | (App.VersionMinor << 16) | App.VersionPatch;
|
|
ExecuteNonQuery(cnx, $"PRAGMA user_version = {vers}");
|
|
}
|
|
|
|
return $"{major}.{minor}.{patch}";
|
|
}
|
|
|
|
private static void UpdateDbSchema(SqliteConnection cnx, int fromVersion, int toVersion) {
|
|
if (fromVersion == toVersion) {
|
|
return;
|
|
} else if (fromVersion > toVersion) {
|
|
throw new Exception("schema_version of database is too new");
|
|
} else if (toVersion - 1 > _updaters.Length) {
|
|
throw new Exception("Unable to update database schema: Updater not implemented");
|
|
} else if (fromVersion <= 0) {
|
|
throw new Exception("schema_version of database is invalid");
|
|
}
|
|
|
|
ExecuteNonQuery(cnx, "PRAGMA locking_mode = EXCLUSIVE");
|
|
ExecuteNonQuery(cnx, "PRAGMA foreign_keys = OFF");
|
|
ExecuteNonQuery(cnx, "BEGIN EXCLUSIVE");
|
|
for (int i = fromVersion; i < toVersion; i++) {
|
|
_updaters[i - 1](cnx);
|
|
}
|
|
ExecuteNonQuery(cnx, "PRAGMA foreign_key_check");
|
|
ExecuteNonQuery(cnx, "COMMIT");
|
|
ExecuteNonQuery(cnx, "PRAGMA foreign_keys = ON");
|
|
ExecuteNonQuery(cnx, "VACUUM");
|
|
ExecuteNonQuery(cnx, $"PRAGMA schema_version = {toVersion * 100 + _versionOffset}");
|
|
}
|
|
|
|
private static void UpdateDbSchema_1_To_2(SqliteConnection cnx) {
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_area_commitment");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE delivery_part DROP COLUMN weighing_reason");
|
|
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) {
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE TABLE delivery_part_bin (
|
|
year INTEGER NOT NULL,
|
|
did INTEGER NOT NULL,
|
|
dpnr INTEGER NOT NULL,
|
|
binnr 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)
|
|
ON UPDATE CASCADE
|
|
ON DELETE CASCADE
|
|
) STRICT;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
INSERT INTO delivery_part_bin (year, did, dpnr, binnr, discr, value)
|
|
SELECT year, did, dpnr, 0, '_', bucket_2 + bucket_3
|
|
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, """
|
|
INSERT INTO delivery_part_bin (year, did, dpnr, binnr, discr, value)
|
|
SELECT d.year, d.did, d.dpnr, 1, COALESCE(attributes, ''), bucket_1
|
|
FROM payment_delivery_part p
|
|
JOIN v_delivery d ON (d.year, d.did, d.dpnr) = (p.year, p.did, p.dpnr)
|
|
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, "ALTER TABLE delivery_part ADD COLUMN gebunden INTEGER CHECK (gebunden IN (TRUE, FALSE)) DEFAULT NULL");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_delivery");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_bucket");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_delivery_bin AS
|
|
SELECT year, mgnr,
|
|
sortid || IIF(min_quw, REPLACE(COALESCE(attributes, ''), ',', ''), '_') AS bin,
|
|
SUM(weight) AS weight
|
|
FROM v_delivery
|
|
GROUP BY year, mgnr, bin
|
|
ORDER BY year, mgnr, LENGTH(bin) DESC, bin;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, "ALTER TABLE wine_attribute ADD COLUMN fill_lower_bins INTEGER NOT NULL CHECK (fill_lower_bins IN (0, 1, 2)) DEFAULT 0");
|
|
}
|
|
|
|
private static void UpdateDbSchema_3_To_4(SqliteConnection cnx) {
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_payment_bin");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
}
|
|
|
|
private static void UpdateDbSchema_4_To_5(SqliteConnection cnx) {
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE TABLE _area_commitment_type (
|
|
vtrgid TEXT NOT NULL CHECK (vtrgid = sortid || COALESCE(attrid, '') || disc),
|
|
sortid TEXT NOT NULL,
|
|
attrid TEXT,
|
|
disc TEXT DEFAULT NULL CHECK (disc REGEXP '^[A-Z0-9]+$'),
|
|
|
|
min_kg_per_ha INTEGER,
|
|
max_kg_per_ha INTEGER,
|
|
penalty_amount INTEGER,
|
|
|
|
CONSTRAINT pk_area_commitment_type PRIMARY KEY (vtrgid),
|
|
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) REFERENCES wine_attribute (attrid)
|
|
ON UPDATE CASCADE
|
|
ON DELETE RESTRICT
|
|
) STRICT;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
INSERT INTO _area_commitment_type (vtrgid, sortid, attrid, disc, min_kg_per_ha, max_kg_per_ha, penalty_amount)
|
|
SELECT vtrgid, sortid, attrid_1, disc, min_kg_per_ha, max_kg_per_ha, penalty_amount FROM area_commitment_type
|
|
""");
|
|
ExecuteNonQuery(cnx, "PRAGMA writable_schema = ON");
|
|
ExecuteNonQuery(cnx, "DROP TABLE area_commitment_type");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE _area_commitment_type RENAME TO area_commitment_type");
|
|
ExecuteNonQuery(cnx, "PRAGMA writable_schema = OFF");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
ALTER TABLE delivery_part ADD COLUMN attrid TEXT DEFAULT NULL
|
|
REFERENCES wine_attribute (attrid)
|
|
ON UPDATE CASCADE
|
|
ON DELETE RESTRICT
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
UPDATE delivery_part
|
|
SET attrid = (SELECT attrid
|
|
FROM delivery_part_attribute a
|
|
WHERE (delivery_part.year, delivery_part.did, delivery_part.dpnr) = (a.year, a.did, a.dpnr)
|
|
ORDER BY attrid DESC
|
|
LIMIT 1)
|
|
""");
|
|
ExecuteNonQuery(cnx, "DROP TRIGGER t_delivery_part_attribute_i_mtime_delivery_part");
|
|
ExecuteNonQuery(cnx, "DROP TRIGGER t_delivery_part_attribute_u_mtime_delivery_part");
|
|
ExecuteNonQuery(cnx, "DROP TRIGGER t_delivery_part_attribute_d_mtime_delivery_part");
|
|
ExecuteNonQuery(cnx, "DROP TABLE delivery_part_attribute");
|
|
|
|
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, 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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_delivery_bin");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_stat_attr");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_stat_attr AS
|
|
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, attrid
|
|
ORDER BY year, attrid;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_stat_sort_attr");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_stat_sort_attr AS
|
|
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, attrid
|
|
ORDER BY year, sortid, attrid;
|
|
""");
|
|
}
|
|
|
|
private static void UpdateDbSchema_5_To_6(SqliteConnection cnx) {
|
|
ExecuteNonQuery(cnx, "DROP VIEW IF EXISTS v_area_commitment");
|
|
|
|
ExecuteNonQuery(cnx, "PRAGMA writable_schema = ON");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE wine_attribute DROP COLUMN fill_lower_bins");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE wine_attribute ADD COLUMN strict INTEGER NOT NULL CHECK (strict IN (TRUE, FALSE)) DEFAULT FALSE");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE wine_attribute ADD COLUMN fill_lower INTEGER NOT NULL CHECK (fill_lower IN (0, 1, 2)) DEFAULT 0");
|
|
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, 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,
|
|
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
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, "PRAGMA writable_schema = OFF");
|
|
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_area_commitment_bin");
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_delivery_bin");
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_payment_bin");
|
|
|
|
ExecuteNonQuery(cnx, "ALTER TABLE area_commitment_type DROP COLUMN max_kg_per_ha");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE area_commitment_type ADD COLUMN penalty_per_kg INTEGER DEFAULT NULL");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE area_commitment_type ADD COLUMN penalty_none INTEGER DEFAULT NULL");
|
|
|
|
ExecuteNonQuery(cnx, "ALTER TABLE wine_cultivation ADD COLUMN description TEXT DEFAULT NULL");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE member ADD COLUMN organic INTEGER NOT NULL CHECK (organic IN (TRUE, FALSE)) DEFAULT FALSE");
|
|
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN max_kg_per_ha INTEGER NOT NULL DEFAULT 10000");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN vat_normal REAL NOT NULL DEFAULT 0.10");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN vat_flatrate REAL NOT NULL DEFAULT 0.13");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN min_kg_per_bs INTEGER NOT NULL DEFAULT 750");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN max_kg_per_bs INTEGER NOT NULL DEFAULT 3000");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN penalty_per_kg INTEGER DEFAULT NULL");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN penalty_amount INTEGER DEFAULT NULL");
|
|
ExecuteNonQuery(cnx, "ALTER TABLE season ADD COLUMN penalty_none INTEGER DEFAULT NULL");
|
|
|
|
ExecuteNonQuery(cnx, "DELETE FROM client_parameter WHERE param IN ('DELIVERY_RIGHT', 'DELIVERY_OBLIGATION', 'VAT_NORMAL', 'VAT_REDUCED', 'VAT_FLATRATE')");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE TABLE delivery_part_bucket (
|
|
year INTEGER NOT NULL,
|
|
did INTEGER NOT NULL,
|
|
dpnr INTEGER NOT NULL,
|
|
bktnr INTEGER NOT NULL,
|
|
|
|
discr TEXT NOT NULL,
|
|
value INTEGER NOT NULL,
|
|
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
INSERT INTO delivery_part_bucket (year, did, dpnr, bktnr, discr, value)
|
|
SELECT year, did, dpnr, binnr, discr, value
|
|
FROM delivery_part_bin
|
|
""");
|
|
ExecuteNonQuery(cnx, "DROP TABLE delivery_part_bin");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
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) * MIN(COALESCE(a.max_kg_per_ha, s.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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
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;
|
|
""");
|
|
}
|
|
|
|
private static void UpdateDBSchema_6_To_7(SqliteConnection cnx) {
|
|
ExecuteNonQuery(cnx, "DROP VIEW v_area_commitment_bucket_strict");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_area_commitment_bucket_strict AS
|
|
SELECT s.year, c.mgnr,
|
|
t.sortid || COALESCE(a.attrid, '') AS bucket,
|
|
t.sortid, a.attrid,
|
|
SUM(area) AS area,
|
|
CAST(ROUND(SUM(area) * COALESCE(t.min_kg_per_ha, 0) / 10000.0, 0) AS INTEGER) AS min_kg,
|
|
CAST(ROUND(SUM(area) * MIN(COALESCE(a.max_kg_per_ha, s.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;
|
|
""");
|
|
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_under_delivery_bucket_strict AS
|
|
SELECT c.year, c.mgnr, c.bucket, c.min_kg, COALESCE(p.weight, 0) AS weight
|
|
FROM v_area_commitment_bucket_strict c
|
|
LEFT JOIN v_payment_bucket_strict p ON (p.year, p.mgnr, p.bucket) = (c.year, c.mgnr, c.bucket)
|
|
ORDER BY c.year, c.mgnr, c.bucket;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_under_delivery_bucket AS
|
|
SELECT u.year, u.mgnr, u.bucket, u.min_kg,
|
|
u.weight + SUM(MAX(COALESCE(p.weight - s.min_kg, 0), 0)) AS weight
|
|
FROM v_under_delivery_bucket_strict u
|
|
LEFT JOIN v_payment_bucket_strict p ON (p.year, p.mgnr, p.sortid) = (u.year, u.mgnr, u.bucket) AND p.attrid IS NOT NULL
|
|
LEFT JOIN wine_attribute a ON a.attrid = p.attrid
|
|
LEFT JOIN v_area_commitment_bucket_strict s ON (s.year, s.mgnr, s.bucket) = (p.year, p.mgnr, p.bucket)
|
|
WHERE (p.gebunden IS NULL OR p.gebunden) AND (a.strict IS NULL OR a.strict = FALSE)
|
|
GROUP BY u.year, u.mgnr, u.bucket
|
|
ORDER BY u.year, u.mgnr, u.bucket;
|
|
""");
|
|
ExecuteNonQuery(cnx, """
|
|
CREATE VIEW v_under_delivery AS
|
|
SELECT year, mgnr, bucket, min_kg, weight, weight - min_kg AS diff
|
|
FROM v_under_delivery_bucket
|
|
WHERE diff < 0;
|
|
""");
|
|
}
|
|
}
|
|
}
|