diff --git a/Groceries.Data/Groceries.Data.csproj b/Groceries.Data/Groceries.Data.csproj
index bafd69e..1e71fa8 100644
--- a/Groceries.Data/Groceries.Data.csproj
+++ b/Groceries.Data/Groceries.Data.csproj
@@ -9,8 +9,13 @@
+
+
+
+
+
diff --git a/Groceries.Data/Migrations/20210627005915_create_items.sql b/Groceries.Data/Migrations/20210627005915_create_items.sql
new file mode 100644
index 0000000..827cbae
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627005915_create_items.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20210627010245_create_stores.sql b/Groceries.Data/Migrations/20210627010245_create_stores.sql
new file mode 100644
index 0000000..48944e4
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627010245_create_stores.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20210627010626_create_transactions.sql b/Groceries.Data/Migrations/20210627010626_create_transactions.sql
new file mode 100644
index 0000000..3dff228
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627010626_create_transactions.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20210627011117_create_transaction_promotions.sql b/Groceries.Data/Migrations/20210627011117_create_transaction_promotions.sql
new file mode 100644
index 0000000..15261a3
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627011117_create_transaction_promotions.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20210627011651_create_transaction_totals.sql b/Groceries.Data/Migrations/20210627011651_create_transaction_totals.sql
new file mode 100644
index 0000000..8d1a33d
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627011651_create_transaction_totals.sql
@@ -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;
diff --git a/Groceries.Data/Migrations/20210627012216_create_item_purchases.sql b/Groceries.Data/Migrations/20210627012216_create_item_purchases.sql
new file mode 100644
index 0000000..cb3d8bb
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627012216_create_item_purchases.sql
@@ -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);
diff --git a/Groceries.Data/Migrations/20210627134014_create_lists.sql b/Groceries.Data/Migrations/20210627134014_create_lists.sql
new file mode 100644
index 0000000..29ac22e
--- /dev/null
+++ b/Groceries.Data/Migrations/20210627134014_create_lists.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20211115174755_create_item_barcodes.sql b/Groceries.Data/Migrations/20211115174755_create_item_barcodes.sql
new file mode 100644
index 0000000..f257803
--- /dev/null
+++ b/Groceries.Data/Migrations/20211115174755_create_item_barcodes.sql
@@ -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)
+);
diff --git a/Groceries.Data/Migrations/20230723215632_create_item_tags.sql b/Groceries.Data/Migrations/20230723215632_create_item_tags.sql
new file mode 100644
index 0000000..7426a0c
--- /dev/null
+++ b/Groceries.Data/Migrations/20230723215632_create_item_tags.sql
@@ -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;
diff --git a/Groceries.Data/Migrations/20230723220201_create_item_quantity.sql b/Groceries.Data/Migrations/20230723220201_create_item_quantity.sql
new file mode 100644
index 0000000..dd829c5
--- /dev/null
+++ b/Groceries.Data/Migrations/20230723220201_create_item_quantity.sql
@@ -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;
+$$;
diff --git a/Groceries.Data/Migrations/20230723221913_seed_retailers.sql b/Groceries.Data/Migrations/20230723221913_seed_retailers.sql
new file mode 100644
index 0000000..122e268
--- /dev/null
+++ b/Groceries.Data/Migrations/20230723221913_seed_retailers.sql
@@ -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;
diff --git a/Groceries/Program.cs b/Groceries/Program.cs
index 17f2ebd..ee1486f 100644
--- a/Groceries/Program.cs
+++ b/Groceries/Program.cs
@@ -1,3 +1,4 @@
+using DbUp;
using Groceries.Common;
using Groceries.Data;
using Microsoft.AspNetCore.DataProtection;
@@ -8,12 +9,28 @@ using Microsoft.EntityFrameworkCore;
var builder = WebApplication.CreateBuilder(args);
var env = builder.Environment;
-var dataDir = builder.Configuration.GetValue("data") ?? env.ContentRootPath;
+var dataDir = builder.Configuration["data"] ?? env.ContentRootPath;
builder.Configuration
.AddIniFile(Path.Combine(dataDir, "config.ini"), optional: true, reloadOnChange: true)
.AddIniFile(Path.Combine(dataDir, $"config_{env.EnvironmentName}.ini"), optional: true, reloadOnChange: true);
+var dbConn = builder.Configuration["Database"]!;
+EnsureDatabase.For.PostgresqlDatabase(dbConn);
+
+var dbUpgradeResult = DeployChanges.To
+ .PostgresqlDatabase(dbConn)
+ .JournalToPostgresqlTable("public", "__dbup_migrations")
+ .WithScriptsEmbeddedInAssembly(typeof(AppDbContext).Assembly)
+ .WithTransactionPerScript()
+ .Build()
+ .PerformUpgrade();
+
+if (!dbUpgradeResult.Successful)
+{
+ return -1;
+}
+
var dataProtection = builder.Services.AddDataProtection();
if (env.IsProduction())
{
@@ -45,7 +62,7 @@ builder.Services.AddDbContextPool(options => options
.EnableSensitiveDataLogging(env.IsDevelopment())
.UseQueryTrackingBehavior(QueryTrackingBehavior.NoTracking)
.UseSnakeCaseNamingConvention()
- .UseNpgsql(builder.Configuration["Database"]!));
+ .UseNpgsql(dbConn));
var app = builder.Build();
@@ -56,3 +73,5 @@ app.UseSession();
app.MapControllers();
app.Run();
+
+return 0;