PRAGMA foreign_keys = ON; ---------------- Tables --------------------- CREATE TABLE household( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT UNIQUE NOT NULL, currency TEXT NOT NULL, password_hash TEXT NOT NULL, password_salt TEXT NOT NULL ); CREATE TABLE account( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL, household_id INTEGER NOT NULL, FOREIGN KEY(household_id) REFERENCES household(id), CONSTRAINT account_uk1 UNIQUE (household_id, name) ); CREATE TABLE category_group( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL, expense INTEGER NOT NULL, exclude INTEGER NOT NULL, household_id INTEGER NOT NULL, system INTEGER NOT NULL DEFAULT 0, FOREIGN KEY(household_id) REFERENCES household(id), CONSTRAINT category_group_uk1 UNIQUE (household_id, name) ); CREATE TABLE category( id INTEGER PRIMARY KEY AUTOINCREMENT, category_group_id INTEGER NOT NULL, name TEXT NOT NULL, FOREIGN KEY(category_group_id) REFERENCES category_group(id), CONSTRAINT category_uk1 UNIQUE (category_group_id, name) ); CREATE TABLE rule( id INTEGER PRIMARY KEY AUTOINCREMENT, category_id INTEGER NOT NULL, account_id INTEGER, regex TEXT NOT NULL, sort_order INTEGER, household_id INTEGER NOT NULL, FOREIGN KEY(category_id) REFERENCES category(id), FOREIGN KEY(account_id) REFERENCES account(id), FOREIGN KEY(household_id) REFERENCES household(id) ); CREATE TABLE record( id INTEGER PRIMARY KEY AUTOINCREMENT, category_id INTEGER NOT NULL, account_id INTEGER NOT NULL, year INTEGER NOT NULL, month INTEGER NOT NULL, day INTEGER NOT NULL, transaction_id TEXT, label TEXT, comment TEXT, amount INTEGER NOT NULL, expense INTEGER NOT NULL, FOREIGN KEY(category_id) REFERENCES category(id), FOREIGN KEY(account_id) REFERENCES account(id) ); ---------------- Views --------------------- CREATE VIEW account_ext AS SELECT a.id, a.household_id, a.name, (SELECT count(*) FROM record r WHERE r.account_id = a.id) AS record_count FROM account a ORDER BY a.name; CREATE VIEW category_ext AS SELECT c.id, c.name, c.category_group_id, g.name AS category_group_name, g.expense, g.exclude, g.household_id, g.system, (SELECT count(*) FROM record r WHERE r.category_id = c.id) AS record_count, (SELECT count(*) FROM rule r WHERE r.category_id = c.id) AS rule_count FROM category c, category_group g WHERE c.category_group_id = g.id ORDER BY g.name, c.name; CREATE VIEW category_group_rownum AS SELECT id, (SELECT count(*) FROM category_group g2 WHERE g2.id < g1.id) AS rownum FROM category_group g1 ORDER BY g1.id ASC; CREATE VIEW category_rownum AS SELECT id, (SELECT count(*) FROM category AS c2 WHERE c2.id < c1.id) AS rownum, category_group_id, (SELECT count(*) FROM category AS c2 WHERE c2.id < c1.id AND c2.category_group_id = c1.category_group_id) AS group_rownum FROM category c1 ORDER BY c1.id ASC; CREATE VIEW rule_sort AS SELECT r.*, ifnull(r.sort_order, g.rownum * (SELECT ((max(group_rownum) / 100) + 1) * 100 FROM category_rownum) + c.group_rownum) AS sort_order_auto FROM rule r, category_rownum c, category_group_rownum g WHERE r.category_id = c.id AND c.category_group_id = g.id ORDER BY sort_order_auto ASC, r.regex ASC; CREATE VIEW rule_ext AS SELECT r.id, r.regex, r.category_id, r.sort_order, r.sort_order_auto, r.household_id, c.name AS category_name, c.category_group_id, g.name AS category_group_name, g.expense, (SELECT count(*) FROM record_ext re WHERE re.label LIKE r.regex AND re.expense = g.expense AND re.system = 1 AND (r.account_id IS null OR re.account_id = r.account_id) AND re.household_id = r.household_id ) AS matches_default_category, (SELECT count(*) FROM record_ext re WHERE re.label LIKE r.regex AND re.expense = g.expense AND re.category_id = r.category_id AND (r.account_id IS null OR re.account_id = r.account_id) AND re.household_id = r.household_id ) AS matches_current_category, (SELECT count(*) FROM record_ext re WHERE re.label LIKE r.regex AND re.expense = g.expense AND re.system = 0 AND re.category_id != r.category_id AND (r.account_id IS null OR re.account_id = r.account_id) AND re.household_id = r.household_id ) AS matches_other_category FROM rule_sort r, category c, category_group g WHERE r.category_id = c.id AND c.category_group_id = g.id; CREATE VIEW record_ext AS SELECT r.*, datetime(year || '-' || (month/10) || (month%10) || '-' || (day/10) || (day%10) ) AS date, year || '-' || (month/10) || (month%10) AS period, a.name AS account_name, a.household_id, c.name AS category_name, c.category_group_id, g.name AS category_group_name, g.exclude, g.system FROM record r, account a, category_group g, category c WHERE r.account_id = a.id AND r.category_id = c.id AND c.category_group_id = g.id ORDER BY r.year DESC, r.month DESC, r.day DESC, r.label ASC; CREATE VIEW record_valid AS SELECT r.* FROM record_ext r WHERE r.exclude = 0; CREATE VIEW record_default_category AS SELECT r.label, count(*) AS occurences, min(r.amount) AS amount_min, max(r.amount) AS amount_max, avg(r.amount) AS amount_avg, sum(r.amount) AS amount_sum, r.expense, r.household_id FROM record_ext r WHERE r.system = 1 GROUP BY r.label, r.expense, r.household_id ORDER BY occurences DESC; CREATE VIEW stat_month_totals AS SELECT year, month, expense, account_name, sum(amount) AS amount, household_id FROM record_valid GROUP BY year, month, expense, account_id, household_id ORDER BY year, month, expense, account_name; CREATE VIEW stat_month_plus AS SELECT year, month, sum( ((expense - 1) * -amount) + (expense * -amount) ) AS amount, household_id FROM record_valid GROUP BY year, month, household_id ORDER BY year, month; CREATE VIEW stat_month_sum1 AS SELECT household_id, year, expense, sum(amount) AS amount FROM record_valid GROUP BY household_id, year, expense ORDER BY amount; CREATE VIEW stat_month_sum2 AS SELECT household_id, year, expense, category_group_id, category_group_name, sum(amount) AS amount FROM record_valid GROUP BY household_id, year, expense, category_group_id ORDER BY amount; CREATE VIEW stat_month_sum3 AS SELECT household_id, year, expense, category_group_id, category_group_name, category_id, category_name, sum(amount) AS amount FROM record_valid GROUP BY household_id, year, expense, category_group_id, category_id ORDER BY amount; CREATE VIEW stat_category_details AS SELECT year, month, category_group_id, category_group_name, category_id, category_name, sum(amount) AS amount, household_id FROM record_valid GROUP BY year, month, category_id ORDER BY year, month;