Add database migrations
This commit is contained in:
@ -0,0 +1,7 @@
|
||||
CREATE TABLE IF NOT EXISTS items (
|
||||
item_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
updated_at timestamptz NOT NULL DEFAULT current_timestamp,
|
||||
brand text NOT NULL,
|
||||
name text NOT NULL,
|
||||
UNIQUE (brand, name)
|
||||
);
|
12
Groceries.Data/Migrations/20210627010245_create_stores.sql
Normal file
12
Groceries.Data/Migrations/20210627010245_create_stores.sql
Normal file
@ -0,0 +1,12 @@
|
||||
CREATE TABLE IF NOT EXISTS retailers (
|
||||
retailer_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
name text NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS stores (
|
||||
store_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
retailer_id uuid NOT NULL REFERENCES retailers,
|
||||
name text NOT NULL,
|
||||
address text,
|
||||
UNIQUE (retailer_id, name)
|
||||
);
|
@ -0,0 +1,13 @@
|
||||
CREATE TABLE IF NOT EXISTS transactions (
|
||||
transaction_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
created_at timestamptz NOT NULL DEFAULT current_timestamp,
|
||||
store_id uuid NOT NULL REFERENCES stores
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS transaction_items (
|
||||
transaction_id uuid NOT NULL REFERENCES transactions ON DELETE CASCADE,
|
||||
item_id uuid NOT NULL REFERENCES items,
|
||||
price numeric(5, 2) NOT NULL CHECK (price >= 0),
|
||||
quantity integer NOT NULL CHECK (quantity > 0),
|
||||
PRIMARY KEY (transaction_id, item_id)
|
||||
);
|
@ -0,0 +1,13 @@
|
||||
CREATE TABLE IF NOT EXISTS transaction_promotions (
|
||||
transaction_promotion_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
transaction_id uuid NOT NULL REFERENCES transactions ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
amount numeric(5, 2) NOT NULL CHECK (amount > 0),
|
||||
UNIQUE (transaction_id, name)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS transaction_promotion_items (
|
||||
transaction_promotion_id uuid NOT NULL REFERENCES transaction_promotions ON DELETE CASCADE,
|
||||
item_id uuid NOT NULL REFERENCES items,
|
||||
PRIMARY KEY (transaction_promotion_id, item_id)
|
||||
);
|
@ -0,0 +1,10 @@
|
||||
CREATE OR REPLACE VIEW transaction_totals AS
|
||||
SELECT transaction_id, sum(amount) AS total
|
||||
FROM (
|
||||
SELECT transaction_id, price * quantity AS amount
|
||||
FROM transaction_items
|
||||
UNION ALL
|
||||
SELECT transaction_id, -amount
|
||||
FROM transaction_promotions
|
||||
) AS transaction_amounts
|
||||
GROUP BY transaction_id;
|
@ -0,0 +1,4 @@
|
||||
CREATE OR REPLACE VIEW item_purchases AS
|
||||
SELECT item_id, transaction_id, created_at, store_id, price, quantity
|
||||
FROM transaction_items
|
||||
JOIN transactions USING (transaction_id);
|
13
Groceries.Data/Migrations/20210627134014_create_lists.sql
Normal file
13
Groceries.Data/Migrations/20210627134014_create_lists.sql
Normal file
@ -0,0 +1,13 @@
|
||||
CREATE TABLE IF NOT EXISTS lists (
|
||||
list_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
updated_at timestamptz NOT NULL DEFAULT current_timestamp,
|
||||
name text NOT NULL UNIQUE
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS list_items (
|
||||
list_item_id uuid NOT NULL DEFAULT gen_random_uuid() PRIMARY KEY,
|
||||
list_id uuid NOT NULL REFERENCES lists ON DELETE CASCADE,
|
||||
name text NOT NULL,
|
||||
completed boolean NOT NULL,
|
||||
UNIQUE (list_id, name)
|
||||
);
|
@ -0,0 +1,6 @@
|
||||
CREATE TABLE IF NOT EXISTS item_barcodes (
|
||||
item_id uuid NOT NULL REFERENCES items ON DELETE CASCADE,
|
||||
barcode_data bigint NOT NULL,
|
||||
format text NOT NULL DEFAULT 'unknown',
|
||||
PRIMARY KEY (item_id, barcode_data)
|
||||
);
|
@ -0,0 +1,10 @@
|
||||
ALTER TABLE items
|
||||
ADD COLUMN IF NOT EXISTS tags text[] NOT NULL DEFAULT '{}';
|
||||
|
||||
CREATE TABLE IF NOT EXISTS item_tags (
|
||||
tag text NOT NULL PRIMARY KEY,
|
||||
unit_name text NOT NULL
|
||||
);
|
||||
|
||||
INSERT INTO item_tags VALUES ('bacon', 'rashers')
|
||||
ON CONFLICT DO NOTHING;
|
@ -0,0 +1,32 @@
|
||||
CREATE OR REPLACE FUNCTION item_quantity(name text) RETURNS jsonb
|
||||
LANGUAGE SQL
|
||||
IMMUTABLE
|
||||
RETURNS NULL ON NULL INPUT
|
||||
PARALLEL SAFE
|
||||
AS $$
|
||||
SELECT jsonb_build_object(
|
||||
'amount',
|
||||
CASE matches[2]
|
||||
WHEN 'k' THEN matches[1]::numeric * 1000
|
||||
WHEN 'c' THEN matches[1]::numeric * 100
|
||||
WHEN 'm' THEN matches[1]::numeric / 1000
|
||||
ELSE matches[1]::numeric
|
||||
END,
|
||||
'unit',
|
||||
CASE matches[3]
|
||||
WHEN 'pk' THEN NULL
|
||||
ELSE matches[3]
|
||||
END,
|
||||
'is_metric',
|
||||
CASE
|
||||
WHEN matches[3] = ANY (ARRAY['g', 'l']) THEN true
|
||||
ELSE false
|
||||
END,
|
||||
'is_divisible',
|
||||
CASE
|
||||
WHEN matches[3] = ANY (ARRAY['pk', 'sl']) THEN false
|
||||
ELSE true
|
||||
END
|
||||
)
|
||||
FROM regexp_matches(name, '(\d*\.?\d+)\s*(c|k|m)?(g|l|pk|pt|sl)', 'i') AS matches;
|
||||
$$;
|
@ -0,0 +1,8 @@
|
||||
INSERT INTO retailers VALUES
|
||||
(DEFAULT, 'ALDI'),
|
||||
(DEFAULT, 'ASDA'),
|
||||
(DEFAULT, 'Lidl'),
|
||||
(DEFAULT, 'Morrisons'),
|
||||
(DEFAULT, 'Sainsbury''s'),
|
||||
(DEFAULT, 'Tesco')
|
||||
ON CONFLICT DO NOTHING;
|
Reference in New Issue
Block a user