forked from brmlab/brmbar-github
Merge branch 'sql-refactor'
This commit is contained in:
commit
40f4abe37f
5 changed files with 188 additions and 10 deletions
|
@ -1,11 +1,11 @@
|
||||||
CREATE SEQUENCE currencies_id_seq START WITH 1 INCREMENT BY 1;
|
CREATE SEQUENCE currencies_id_seq START WITH 2 INCREMENT BY 1;
|
||||||
CREATE TABLE currencies (
|
CREATE TABLE currencies (
|
||||||
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('currencies_id_seq'::regclass),
|
id INTEGER PRIMARY KEY NOT NULL DEFAULT NEXTVAL('currencies_id_seq'::regclass),
|
||||||
name VARCHAR(128) NOT NULL,
|
name VARCHAR(128) NOT NULL,
|
||||||
UNIQUE(name)
|
UNIQUE(name)
|
||||||
);
|
);
|
||||||
-- Some code depends on the primary physical currency to have id 1.
|
-- Some code depends on the primary physical currency to have id 1.
|
||||||
INSERT INTO currencies (name) VALUES ('Kč');
|
INSERT INTO currencies (id, name) VALUES (1, 'Kč');
|
||||||
|
|
||||||
CREATE TYPE exchange_rate_direction AS ENUM ('source_to_target', 'target_to_source');
|
CREATE TYPE exchange_rate_direction AS ENUM ('source_to_target', 'target_to_source');
|
||||||
CREATE TABLE exchange_rates (
|
CREATE TABLE exchange_rates (
|
||||||
|
|
57
brmbar3/SQL-for-RO-access.sql
Normal file
57
brmbar3/SQL-for-RO-access.sql
Normal file
|
@ -0,0 +1,57 @@
|
||||||
|
CREATE OR REPLACE FUNCTION accounts_id_seq_value()
|
||||||
|
RETURNS bigint
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
result bigint;
|
||||||
|
BEGIN
|
||||||
|
SELECT last_value FROM accounts_id_seq
|
||||||
|
INTO result;
|
||||||
|
RETURN result;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION transactions_id_seq_value()
|
||||||
|
RETURNS bigint
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
result bigint;
|
||||||
|
BEGIN
|
||||||
|
SELECT last_value FROM transactions_id_seq
|
||||||
|
INTO result;
|
||||||
|
RETURN result;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION transaction_splits_id_seq_value()
|
||||||
|
RETURNS bigint
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
result bigint;
|
||||||
|
BEGIN
|
||||||
|
SELECT last_value FROM transaction_splits_id_seq
|
||||||
|
INTO result;
|
||||||
|
RETURN result;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION currencies_id_seq_value()
|
||||||
|
RETURNS bigint
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
SECURITY DEFINER
|
||||||
|
AS $$
|
||||||
|
DECLARE
|
||||||
|
result bigint;
|
||||||
|
BEGIN
|
||||||
|
SELECT last_value FROM currencies_id_seq
|
||||||
|
INTO result;
|
||||||
|
RETURN result;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
|
59
brmbar3/SQL-schema-v001.sql
Normal file
59
brmbar3/SQL-schema-v001.sql
Normal file
|
@ -0,0 +1,59 @@
|
||||||
|
--RESET search_path;
|
||||||
|
SELECT pg_catalog.set_config('search_path', '', false);
|
||||||
|
-- intoduce implementation schema
|
||||||
|
CREATE SCHEMA IF NOT EXISTS brmbar_implementation;
|
||||||
|
-- version table (with initialization)
|
||||||
|
CREATE TABLE IF NOT EXISTS brmbar_implementation.brmbar_schema (
|
||||||
|
ver INTEGER NOT NULL
|
||||||
|
);
|
||||||
|
DO $$
|
||||||
|
DECLARE v INTEGER;
|
||||||
|
BEGIN
|
||||||
|
SELECT ver FROM brmbar_implementation.brmbar_schema INTO v;
|
||||||
|
IF v IS NULL THEN
|
||||||
|
INSERT INTO brmbar_implementation.brmbar_schema (ver) VALUES (1);
|
||||||
|
END IF;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION brmbar_implementation.has_exact_schema_version(
|
||||||
|
IN i_ver INTEGER NOT NULL
|
||||||
|
) RETURNS INTEGER
|
||||||
|
VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $$
|
||||||
|
DECLARE
|
||||||
|
v_ver INTEGER;
|
||||||
|
BEGIN
|
||||||
|
SELECT ver INTO STRICT v_ver FROM brmbar_implementation.brmbar_schema;
|
||||||
|
IF v_ver IS NULL or v_ver <> i_ver THEN
|
||||||
|
RAISE EXCEPTION 'Invalid brmbar schema version';
|
||||||
|
END IF;
|
||||||
|
RETURN v_ver;
|
||||||
|
/*
|
||||||
|
EXCEPTION
|
||||||
|
WHEN NO_DATA_FOUND THEN
|
||||||
|
RAISE EXCEPTION 'PID % not found';
|
||||||
|
WHEN TOO_MANY_ROWS THEN
|
||||||
|
RAISE EXCEPTION 'PID % not unique';
|
||||||
|
*/
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION brmbar_implementation.upgrade_schema_version_to(
|
||||||
|
IN i_ver INTEGER NOT NULL
|
||||||
|
) RETURNS INTEGER
|
||||||
|
VOLATILE NOT LEAKPROOF LANGUAGE plpgsql AS $$
|
||||||
|
DECLARE
|
||||||
|
v_ver INTEGER;
|
||||||
|
BEGIN
|
||||||
|
SELECT brmbar_implementation.has_exact_schema_version(i_ver) INTO v_ver;
|
||||||
|
IF v_ver + 1 = i_ver THEN
|
||||||
|
UPDATE brmbar_implementation.brmbar_schema SET ver = i_ver;
|
||||||
|
ELSE
|
||||||
|
RAISE EXCEPTION 'Invalid brmbar schema version';
|
||||||
|
END IF;
|
||||||
|
RETURN i_ver;
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
-- vim: set ft=plsql :
|
||||||
|
|
61
brmbar3/SQL-schema-v002.sql
Normal file
61
brmbar3/SQL-schema-v002.sql
Normal file
|
@ -0,0 +1,61 @@
|
||||||
|
--RESET search_path
|
||||||
|
SELECT pg_catalog.set_config('search_path', '', false);
|
||||||
|
|
||||||
|
--- upgrade schema
|
||||||
|
DO $upgrade_block$
|
||||||
|
DECLARE
|
||||||
|
current_ver INTEGER;
|
||||||
|
BEGIN
|
||||||
|
|
||||||
|
-- confirm that we are upgrading from version 1
|
||||||
|
SELECT brmbar_implementation.has_exact_schema_version(1) INTO current_ver;
|
||||||
|
IF current_ver <> 1 THEN
|
||||||
|
RAISE EXCEPTION 'BrmBar schema version % cannot be upgraded to version 2.', current_ver;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- structural changes
|
||||||
|
|
||||||
|
-- TRADING ACCOUNTS
|
||||||
|
--START TRANSACTION ISOLATION LEVEL SERIALIZABLE;
|
||||||
|
|
||||||
|
-- currency trading accounts - account type
|
||||||
|
ALTER TYPE public.account_type ADD VALUE IF NOT EXISTS 'trading';
|
||||||
|
|
||||||
|
-- constraint needed for foreign key in currencies table
|
||||||
|
ALTER TABLE public.accounts ADD CONSTRAINT accounts_id_acctype_key UNIQUE(id, acctype);
|
||||||
|
|
||||||
|
-- add columns to currencies to record the trading account associated with the currency
|
||||||
|
ALTER TABLE public.currencies
|
||||||
|
ADD COLUMN IF NOT EXISTS trading_account integer,
|
||||||
|
ADD COLUMN IF NOT EXISTS trading_account_type account_type GENERATED ALWAYS AS ('trading'::public.account_type) STORED;
|
||||||
|
|
||||||
|
-- make trading accounts (without making duplicates)
|
||||||
|
INSERT INTO public.accounts ("name", "currency", acctype)
|
||||||
|
SELECT
|
||||||
|
'Currency Trading Account: ' || c."name",
|
||||||
|
c.id,
|
||||||
|
'trading'::public.account_type
|
||||||
|
FROM public.currencies AS c
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT 1
|
||||||
|
FROM public.accounts a
|
||||||
|
WHERE a.currency = c.id AND a.acctype = 'trading'::public.account_type
|
||||||
|
);
|
||||||
|
|
||||||
|
|
||||||
|
-- record the trading account IDs in currencies table
|
||||||
|
UPDATE public.currencies AS c SET (trading_account) = (SELECT a.id FROM public.accounts AS a WHERE a.currency = c.id AND c.acctype = 'trading'::public.account_type);
|
||||||
|
|
||||||
|
-- foreign key to check the validity of currency trading account reference
|
||||||
|
ALTER TABLE public.currencies
|
||||||
|
ADD CONSTRAINT currencies_trading_fkey FOREIGN KEY (trading_account, trading_account_type)
|
||||||
|
REFERENCES xaccounts(id,acctype) DEFERRABLE INITIALLY DEFERRED;
|
||||||
|
|
||||||
|
--COMMIT AND CHAIN;
|
||||||
|
|
||||||
|
SELECT brmbar_implementation.upgrade_schema_version_to(2) INTO current_ver;
|
||||||
|
-- end of upgrade do block
|
||||||
|
end
|
||||||
|
$upgrade_block$;
|
||||||
|
|
||||||
|
-- vim: set ft=plsql :
|
|
@ -219,14 +219,15 @@ class Shop:
|
||||||
self.db.commit()
|
self.db.commit()
|
||||||
|
|
||||||
def undo(self, oldtid):
|
def undo(self, oldtid):
|
||||||
description = self.db.execute_and_fetch("SELECT description FROM transactions WHERE id = %s", [oldtid])[0]
|
#description = self.db.execute_and_fetch("SELECT description FROM transactions WHERE id = %s", [oldtid])[0]
|
||||||
description = 'undo %d (%s)' % (oldtid, description)
|
#description = 'undo %d (%s)' % (oldtid, description)
|
||||||
|
|
||||||
transaction = self._transaction(description=description)
|
#transaction = self._transaction(description=description)
|
||||||
for split in self.db.execute_and_fetchall("SELECT id, side, account, amount, memo FROM transaction_splits WHERE transaction = %s", [oldtid]):
|
#for split in self.db.execute_and_fetchall("SELECT id, side, account, amount, memo FROM transaction_splits WHERE transaction = %s", [oldtid]):
|
||||||
splitid, side, account, amount, memo = split
|
# splitid, side, account, amount, memo = split
|
||||||
memo = 'undo %d (%s)' % (splitid, memo)
|
# memo = 'undo %d (%s)' % (splitid, memo)
|
||||||
amount = -amount
|
# amount = -amount
|
||||||
self.db.execute("INSERT INTO transaction_splits (transaction, side, account, amount, memo) VALUES (%s, %s, %s, %s, %s)", [transaction, side, account, amount, memo])
|
# self.db.execute("INSERT INTO transaction_splits (transaction, side, account, amount, memo) VALUES (%s, %s, %s, %s, %s)", [transaction, side, account, amount, memo])
|
||||||
|
transaction = self.db.execute_and_fetch("CALL undo_transaction(%s)",[oldtid])[0]
|
||||||
self.db.commit()
|
self.db.commit()
|
||||||
return transaction
|
return transaction
|
||||||
|
|
Loading…
Add table
Add a link
Reference in a new issue