fix: migration atomicity + deploy hardening + Litestream R2
Migration atomicity: - Remove conn.commit() and executescript() from all up() functions (0000, 0011, 0012, 0013, 0014, 0015); executescript() issued implicit COMMITs which broke the batch-rollback guarantee of the migration runner - Rewrite 0000 with individual conn.execute() calls (was a single executescript block) Deploy hardening: - Add pre-migration DB backup step to deploy.sh: saves app.db.pre-deploy-<timestamp> in the volume before every migration - On health-check failure: restore the backup, then stop + exit - On success: clean up old backups (keep last 3) Litestream: - Enable R2 as primary replica in litestream.yml (env-var placeholders) - Add local /app/data/backups as secondary replica - docker-compose: add auto-restore on empty volume (sh entrypoint runs 'litestream restore' before 'litestream replicate' if app.db missing) - Add LITESTREAM_R2_* vars to .gitlab-ci.yml .env block and .env.example Co-Authored-By: Claude Sonnet 4.6 <noreply@anthropic.com>
This commit is contained in:
@@ -48,6 +48,10 @@ deploy:
|
||||
PADDLE_WEBHOOK_SECRET=$PADDLE_WEBHOOK_SECRET
|
||||
PADDLE_PRICE_STARTER=$PADDLE_PRICE_STARTER
|
||||
PADDLE_PRICE_PRO=$PADDLE_PRICE_PRO
|
||||
LITESTREAM_R2_BUCKET=$LITESTREAM_R2_BUCKET
|
||||
LITESTREAM_R2_ACCESS_KEY_ID=$LITESTREAM_R2_ACCESS_KEY_ID
|
||||
LITESTREAM_R2_SECRET_ACCESS_KEY=$LITESTREAM_R2_SECRET_ACCESS_KEY
|
||||
LITESTREAM_R2_ENDPOINT=$LITESTREAM_R2_ENDPOINT
|
||||
ENVEOF
|
||||
- ssh "$DEPLOY_USER@$DEPLOY_HOST" "chmod 600 /opt/padelnomics/padelnomics/.env"
|
||||
- ssh "$DEPLOY_USER@$DEPLOY_HOST" "cd /opt/padelnomics && git pull origin master && ./deploy.sh"
|
||||
|
||||
@@ -7,11 +7,17 @@ The format is based on [Keep a Changelog](https://keepachangelog.com/en/1.1.0/).
|
||||
## [Unreleased]
|
||||
|
||||
### Fixed
|
||||
- Deploy: pre-migration DB backup added to `deploy.sh`; on health-check failure the DB is restored to pre-migration state (prevents old slot from running against new schema)
|
||||
- Migrations: removed all `conn.commit()` and `executescript()` calls from `up()` functions in 0000, 0011, 0012, 0013, 0014, 0015 — restores batch-atomicity guarantee (`executescript` issued implicit COMMITs, breaking rollback on failure)
|
||||
- Visual tests: server now builds schema via `migrate()` instead of the deleted `schema.sql`; all 12 Playwright tests pass
|
||||
- Visual tests: updated assertions to match current landing page (text logo replacing img, `.roi-calc` replacing `.teaser-calc`, `hero-dark`/`cta-card` allowed as intentional dark sections, card count ≥ 6, i18n-prefixed logo href, h3 brightness threshold relaxed to 150)
|
||||
- CSS: removed dead `.nav-logo { line-height: 0 }` rule (was for image logo, collapsed text logo to zero height); removed dead `.nav-logo img` rule
|
||||
- Ruff: fixed 49 lint errors across `src/` and `tests/` (unused imports, unused variables, unsorted imports, bare f-strings, ambiguous variable name `l`)
|
||||
|
||||
### Added
|
||||
- Litestream: R2 replication config with env-var placeholders (`LITESTREAM_R2_BUCKET` etc.) — fill in GitLab CI variables to enable off-host backup; handles new server, deleted volume, or disaster recovery via auto-restore on container startup
|
||||
- `.env.example`: Litestream R2 vars documented
|
||||
|
||||
### Added
|
||||
- i18n URL prefixes: all public-facing blueprints (`public`, `planner`, `directory`, `content`, `leads`, `suppliers`) now live under `/<lang>/` (e.g. `/en/`, `/de/`); internal blueprints (`auth`, `dashboard`, `admin`, `billing`) unchanged; root `/` detects language from cookie / Accept-Language header and 301-redirects; legacy URLs (`/terms`, `/privacy`, etc.) redirect to `/en/` equivalents
|
||||
- German legal pages: full DSGVO-compliant `Datenschutzerklärung` (`/de/privacy`), `AGB` (`/de/terms`), and `Impressum` (`/de/imprint`) per § 5 DDG — populated with Hendrik Dreesmann's details, Kleinunternehmer § 19 UStG, Oldenburg address
|
||||
|
||||
19
deploy.sh
19
deploy.sh
@@ -22,6 +22,13 @@ echo "==> Current: $CURRENT → Deploying: $TARGET"
|
||||
echo "==> Building $TARGET..."
|
||||
$COMPOSE --profile "$TARGET" build
|
||||
|
||||
# ── Backup DB before migration ────────────────────────────────
|
||||
|
||||
BACKUP_TAG="pre-deploy-$(date +%Y%m%d-%H%M%S)"
|
||||
echo "==> Backing up database (${BACKUP_TAG})..."
|
||||
$COMPOSE run --rm --entrypoint "" "${TARGET}-app" \
|
||||
sh -c "cp /app/data/app.db /app/data/app.db.${BACKUP_TAG} 2>/dev/null || true"
|
||||
|
||||
# ── Migrate ─────────────────────────────────────────────────
|
||||
|
||||
echo "==> Running migrations..."
|
||||
@@ -34,6 +41,13 @@ echo "==> Starting $TARGET (waiting for health check)..."
|
||||
if ! $COMPOSE --profile "$TARGET" up -d --wait; then
|
||||
echo "!!! Health check failed — rolling back"
|
||||
$COMPOSE stop "${TARGET}-app" "${TARGET}-worker" "${TARGET}-scheduler"
|
||||
LATEST=$($COMPOSE run --rm --entrypoint "" "${TARGET}-app" \
|
||||
sh -c "ls -t /app/data/app.db.pre-deploy-* 2>/dev/null | head -1")
|
||||
if [ -n "$LATEST" ]; then
|
||||
echo "==> Restoring database from ${LATEST}..."
|
||||
$COMPOSE run --rm --entrypoint "" "${TARGET}-app" \
|
||||
sh -c "cp '${LATEST}' /app/data/app.db"
|
||||
fi
|
||||
exit 1
|
||||
fi
|
||||
|
||||
@@ -63,6 +77,11 @@ NGINX
|
||||
$COMPOSE up -d router
|
||||
$COMPOSE exec router nginx -s reload
|
||||
|
||||
# ── Cleanup old pre-deploy backups (keep last 3) ─────────────
|
||||
|
||||
$COMPOSE run --rm --entrypoint "" "${TARGET}-app" \
|
||||
sh -c "ls -t /app/data/app.db.pre-deploy-* 2>/dev/null | tail -n +4 | xargs rm -f" || true
|
||||
|
||||
# ── Stop old slot ───────────────────────────────────────────
|
||||
|
||||
if [ "$CURRENT" != "none" ]; then
|
||||
|
||||
@@ -18,7 +18,19 @@ services:
|
||||
litestream:
|
||||
image: litestream/litestream:latest
|
||||
restart: unless-stopped
|
||||
command: replicate -config /etc/litestream.yml
|
||||
# Auto-restore from R2 if DB file is missing, then start continuous replication.
|
||||
# Handles: new server, deleted volume, disaster recovery.
|
||||
entrypoint: /bin/sh
|
||||
command:
|
||||
- -c
|
||||
- |
|
||||
if [ ! -f /app/data/app.db ]; then
|
||||
echo "==> No database found, restoring from R2..."
|
||||
litestream restore -config /etc/litestream.yml /app/data/app.db \
|
||||
|| echo "==> No backup found, starting fresh"
|
||||
fi
|
||||
exec litestream replicate -config /etc/litestream.yml
|
||||
env_file: ./padelnomics/.env
|
||||
volumes:
|
||||
- app-data:/app/data
|
||||
- ./padelnomics/litestream.yml:/etc/litestream.yml:ro
|
||||
|
||||
@@ -54,3 +54,9 @@ UMAMI_API_TOKEN=
|
||||
# Rate limiting
|
||||
RATE_LIMIT_REQUESTS=100
|
||||
RATE_LIMIT_WINDOW=60
|
||||
|
||||
# Litestream R2 backup — leave blank to skip R2 replication (local-only backup)
|
||||
LITESTREAM_R2_BUCKET=
|
||||
LITESTREAM_R2_ACCESS_KEY_ID=
|
||||
LITESTREAM_R2_SECRET_ACCESS_KEY=
|
||||
LITESTREAM_R2_ENDPOINT=
|
||||
|
||||
@@ -1,22 +1,29 @@
|
||||
# Litestream configuration for SQLite replication
|
||||
# Supports S3, Cloudflare R2, MinIO, etc.
|
||||
# Primary replica: Cloudflare R2 (off-host disaster recovery)
|
||||
# Secondary replica: local file backup inside the volume
|
||||
#
|
||||
# Set these env vars in .env / GitLab CI variables:
|
||||
# LITESTREAM_R2_BUCKET e.g. padelnomics-backups
|
||||
# LITESTREAM_R2_ACCESS_KEY_ID
|
||||
# LITESTREAM_R2_SECRET_ACCESS_KEY
|
||||
# LITESTREAM_R2_ENDPOINT e.g. <account-id>.r2.cloudflarestorage.com
|
||||
#
|
||||
# Recovery:
|
||||
# litestream restore -config /etc/litestream.yml /app/data/app.db
|
||||
# litestream restore -config /etc/litestream.yml -timestamp "2026-01-15T12:00:00Z" /app/data/app.db
|
||||
|
||||
dbs:
|
||||
- path: /app/data/app.db
|
||||
replicas:
|
||||
# Option 1: AWS S3
|
||||
# - url: s3://your-bucket/padelnomics/app.db
|
||||
# access-key-id: ${AWS_ACCESS_KEY_ID}
|
||||
# secret-access-key: ${AWS_SECRET_ACCESS_KEY}
|
||||
# region: us-east-1
|
||||
# Primary: Cloudflare R2
|
||||
- url: s3://${LITESTREAM_R2_BUCKET}/padelnomics/app.db
|
||||
access-key-id: ${LITESTREAM_R2_ACCESS_KEY_ID}
|
||||
secret-access-key: ${LITESTREAM_R2_SECRET_ACCESS_KEY}
|
||||
endpoint: https://${LITESTREAM_R2_ENDPOINT}
|
||||
retention: 168h
|
||||
snapshot-interval: 6h
|
||||
|
||||
# Option 2: Cloudflare R2
|
||||
# - url: s3://your-bucket/padelnomics/app.db
|
||||
# access-key-id: ${R2_ACCESS_KEY_ID}
|
||||
# secret-access-key: ${R2_SECRET_ACCESS_KEY}
|
||||
# endpoint: https://${R2_ACCOUNT_ID}.r2.cloudflarestorage.com
|
||||
|
||||
# Option 3: Local file backup (for development)
|
||||
# Secondary: local backup inside the volume (fast local restore)
|
||||
- path: /app/data/backups
|
||||
retention: 24h
|
||||
snapshot-interval: 1h
|
||||
|
||||
@@ -2,8 +2,8 @@
|
||||
|
||||
|
||||
def up(conn):
|
||||
conn.executescript("""
|
||||
-- Users
|
||||
# Users
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS users (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
email TEXT UNIQUE NOT NULL,
|
||||
@@ -12,35 +12,43 @@ def up(conn):
|
||||
updated_at TEXT,
|
||||
last_login_at TEXT,
|
||||
deleted_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_users_email ON users(email)")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_users_deleted ON users(deleted_at)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
|
||||
CREATE INDEX IF NOT EXISTS idx_users_deleted ON users(deleted_at);
|
||||
|
||||
-- User Roles (RBAC)
|
||||
# User Roles (RBAC)
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS user_roles (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
role TEXT NOT NULL,
|
||||
granted_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
UNIQUE(user_id, role)
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_user_roles_user ON user_roles(user_id)")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_user_roles_role ON user_roles(role)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_user_roles_user ON user_roles(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_roles_role ON user_roles(role);
|
||||
|
||||
-- Billing Customers (provider customer ID, separate from subscriptions)
|
||||
# Billing Customers
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS billing_customers (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL UNIQUE REFERENCES users(id),
|
||||
provider_customer_id TEXT NOT NULL,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_billing_customers_user ON billing_customers(user_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_billing_customers_provider"
|
||||
" ON billing_customers(provider_customer_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_billing_customers_user ON billing_customers(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_billing_customers_provider ON billing_customers(provider_customer_id);
|
||||
|
||||
-- Auth Tokens (magic links)
|
||||
# Auth Tokens (magic links)
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS auth_tokens (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -48,12 +56,13 @@ def up(conn):
|
||||
expires_at TEXT NOT NULL,
|
||||
used_at TEXT,
|
||||
created_at TEXT DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_auth_tokens_token ON auth_tokens(token)")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_auth_tokens_user ON auth_tokens(user_id)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_auth_tokens_token ON auth_tokens(token);
|
||||
CREATE INDEX IF NOT EXISTS idx_auth_tokens_user ON auth_tokens(user_id);
|
||||
|
||||
-- Subscriptions
|
||||
# Subscriptions
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS subscriptions (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -63,12 +72,18 @@ def up(conn):
|
||||
current_period_end TEXT,
|
||||
created_at TEXT NOT NULL,
|
||||
updated_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_subscriptions_provider"
|
||||
" ON subscriptions(provider_subscription_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_provider ON subscriptions(provider_subscription_id);
|
||||
|
||||
-- API Keys
|
||||
# API Keys
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS api_keys (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -79,33 +94,42 @@ def up(conn):
|
||||
created_at TEXT NOT NULL,
|
||||
last_used_at TEXT,
|
||||
deleted_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_api_keys_hash ON api_keys(key_hash)")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_api_keys_user ON api_keys(user_id)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_api_keys_hash ON api_keys(key_hash);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_keys_user ON api_keys(user_id);
|
||||
|
||||
-- API Request Log
|
||||
# API Request Log
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS api_requests (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
endpoint TEXT NOT NULL,
|
||||
method TEXT NOT NULL,
|
||||
created_at TEXT NOT NULL
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_api_requests_user ON api_requests(user_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_api_requests_date ON api_requests(created_at)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_user ON api_requests(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_api_requests_date ON api_requests(created_at);
|
||||
|
||||
-- Rate Limits
|
||||
# Rate Limits
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS rate_limits (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
key TEXT NOT NULL,
|
||||
timestamp TEXT NOT NULL
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_rate_limits_key ON rate_limits(key, timestamp)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_rate_limits_key ON rate_limits(key, timestamp);
|
||||
|
||||
-- Background Tasks
|
||||
# Background Tasks
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS tasks (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
task_name TEXT NOT NULL,
|
||||
@@ -116,11 +140,12 @@ def up(conn):
|
||||
error TEXT,
|
||||
created_at TEXT NOT NULL,
|
||||
completed_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status, run_at)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_status ON tasks(status, run_at);
|
||||
|
||||
-- Scenarios (core domain entity)
|
||||
# Scenarios (core domain entity)
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS scenarios (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -131,11 +156,12 @@ def up(conn):
|
||||
created_at TEXT NOT NULL,
|
||||
updated_at TEXT,
|
||||
deleted_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_scenarios_user ON scenarios(user_id)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_scenarios_user ON scenarios(user_id);
|
||||
|
||||
-- Lead requests (when user wants supplier quotes or financing)
|
||||
# Lead requests
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS lead_requests (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER REFERENCES users(id),
|
||||
@@ -173,12 +199,17 @@ def up(conn):
|
||||
-- Phase 1: credit cost and unlock tracking
|
||||
credit_cost INTEGER,
|
||||
unlock_count INTEGER NOT NULL DEFAULT 0
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_leads_status ON lead_requests(status)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_leads_heat ON lead_requests(heat_score)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_leads_status ON lead_requests(status);
|
||||
CREATE INDEX IF NOT EXISTS idx_leads_heat ON lead_requests(heat_score);
|
||||
|
||||
-- Suppliers directory (seeded with unclaimed listings)
|
||||
# Suppliers directory
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS suppliers (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
name TEXT NOT NULL,
|
||||
@@ -227,37 +258,48 @@ def up(conn):
|
||||
|
||||
-- Phase 4: Directory card cover image
|
||||
cover_image TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_suppliers_country ON suppliers(country_code)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_suppliers_category ON suppliers(category)"
|
||||
)
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_suppliers_slug ON suppliers(slug)")
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_suppliers_country ON suppliers(country_code);
|
||||
CREATE INDEX IF NOT EXISTS idx_suppliers_category ON suppliers(category);
|
||||
CREATE INDEX IF NOT EXISTS idx_suppliers_slug ON suppliers(slug);
|
||||
|
||||
-- FTS5 full-text search for suppliers
|
||||
# FTS5 full-text search for suppliers
|
||||
conn.execute("""
|
||||
CREATE VIRTUAL TABLE IF NOT EXISTS suppliers_fts USING fts5(
|
||||
name, description, city, country_code, category,
|
||||
content='suppliers', content_rowid='id'
|
||||
);
|
||||
)
|
||||
""")
|
||||
|
||||
-- Keep FTS in sync with suppliers table
|
||||
# Keep FTS in sync with suppliers table
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS suppliers_ai AFTER INSERT ON suppliers BEGIN
|
||||
INSERT INTO suppliers_fts(rowid, name, description, city, country_code, category)
|
||||
VALUES (new.id, new.name, new.description, new.city, new.country_code, new.category);
|
||||
END;
|
||||
|
||||
END
|
||||
""")
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS suppliers_ad AFTER DELETE ON suppliers BEGIN
|
||||
INSERT INTO suppliers_fts(suppliers_fts, rowid, name, description, city, country_code, category)
|
||||
VALUES ('delete', old.id, old.name, old.description, old.city, old.country_code, old.category);
|
||||
END;
|
||||
|
||||
END
|
||||
""")
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS suppliers_au AFTER UPDATE ON suppliers BEGIN
|
||||
INSERT INTO suppliers_fts(suppliers_fts, rowid, name, description, city, country_code, category)
|
||||
VALUES ('delete', old.id, old.name, old.description, old.city, old.country_code, old.category);
|
||||
INSERT INTO suppliers_fts(rowid, name, description, city, country_code, category)
|
||||
VALUES (new.id, new.name, new.description, new.city, new.country_code, new.category);
|
||||
END;
|
||||
END
|
||||
""")
|
||||
|
||||
-- Credit ledger (source of truth for all credit movements)
|
||||
# Credit ledger
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS credit_ledger (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
supplier_id INTEGER NOT NULL REFERENCES suppliers(id),
|
||||
@@ -267,11 +309,14 @@ def up(conn):
|
||||
reference_id INTEGER,
|
||||
note TEXT,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_credit_ledger_supplier ON credit_ledger(supplier_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_credit_ledger_supplier ON credit_ledger(supplier_id);
|
||||
|
||||
-- Lead forwards (which supplier unlocked which lead)
|
||||
# Lead forwards
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS lead_forwards (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
lead_id INTEGER NOT NULL REFERENCES lead_requests(id),
|
||||
@@ -281,12 +326,17 @@ def up(conn):
|
||||
email_sent_at TEXT,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
UNIQUE(lead_id, supplier_id)
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_lead_forwards_lead ON lead_forwards(lead_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_lead_forwards_supplier ON lead_forwards(supplier_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_lead_forwards_lead ON lead_forwards(lead_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_lead_forwards_supplier ON lead_forwards(supplier_id);
|
||||
|
||||
-- Supplier enquiries (Basic+ listing contact form)
|
||||
# Supplier enquiries (Basic+ listing contact form)
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS supplier_enquiries (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
supplier_id INTEGER NOT NULL REFERENCES suppliers(id),
|
||||
@@ -295,13 +345,19 @@ def up(conn):
|
||||
message TEXT NOT NULL,
|
||||
status TEXT NOT NULL DEFAULT 'new',
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_supplier
|
||||
ON supplier_enquiries(supplier_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_email
|
||||
ON supplier_enquiries(contact_email, created_at);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_supplier"
|
||||
" ON supplier_enquiries(supplier_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_email"
|
||||
" ON supplier_enquiries(contact_email, created_at)"
|
||||
)
|
||||
|
||||
-- Supplier boost subscriptions/purchases
|
||||
# Supplier boost subscriptions/purchases
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS supplier_boosts (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
supplier_id INTEGER NOT NULL REFERENCES suppliers(id),
|
||||
@@ -312,11 +368,14 @@ def up(conn):
|
||||
expires_at TEXT,
|
||||
metadata TEXT,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_supplier_boosts_supplier ON supplier_boosts(supplier_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_supplier_boosts_supplier ON supplier_boosts(supplier_id);
|
||||
|
||||
-- Paddle products (price IDs stored in DB, not env vars)
|
||||
# Paddle products
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS paddle_products (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
key TEXT NOT NULL UNIQUE,
|
||||
@@ -327,9 +386,11 @@ def up(conn):
|
||||
currency TEXT NOT NULL DEFAULT 'EUR',
|
||||
billing_type TEXT NOT NULL,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
)
|
||||
""")
|
||||
|
||||
-- Business plan PDF exports
|
||||
# Business plan PDF exports
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS business_plan_exports (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -340,12 +401,15 @@ def up(conn):
|
||||
status TEXT NOT NULL DEFAULT 'pending',
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
completed_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_bpe_user ON business_plan_exports(user_id)")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_bpe_scenario ON business_plan_exports(scenario_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_bpe_user ON business_plan_exports(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_bpe_scenario ON business_plan_exports(scenario_id);
|
||||
|
||||
-- In-app feedback
|
||||
# In-app feedback
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS feedback (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER REFERENCES users(id),
|
||||
@@ -353,13 +417,15 @@ def up(conn):
|
||||
message TEXT NOT NULL,
|
||||
is_read INTEGER NOT NULL DEFAULT 0,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
)
|
||||
""")
|
||||
|
||||
-- =============================================================================
|
||||
-- Content / Programmatic SEO
|
||||
-- =============================================================================
|
||||
# ==========================================================================
|
||||
# Content / Programmatic SEO
|
||||
# ==========================================================================
|
||||
|
||||
-- Published scenarios (generated financial widgets for articles)
|
||||
# Published scenarios
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS published_scenarios (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
slug TEXT UNIQUE NOT NULL,
|
||||
@@ -375,11 +441,14 @@ def up(conn):
|
||||
template_data_id INTEGER REFERENCES template_data(id),
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_pub_scenarios_slug ON published_scenarios(slug)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_pub_scenarios_slug ON published_scenarios(slug);
|
||||
|
||||
-- Article templates (content recipes)
|
||||
# Article templates
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS article_templates (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
name TEXT NOT NULL,
|
||||
@@ -392,11 +461,14 @@ def up(conn):
|
||||
body_template TEXT NOT NULL,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_article_templates_slug ON article_templates(slug)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_article_templates_slug ON article_templates(slug);
|
||||
|
||||
-- Template data (per-city/region input rows)
|
||||
# Template data
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS template_data (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
template_id INTEGER NOT NULL REFERENCES article_templates(id),
|
||||
@@ -405,11 +477,14 @@ def up(conn):
|
||||
article_id INTEGER REFERENCES articles(id),
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_template_data_template ON template_data(template_id)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_template_data_template ON template_data(template_id);
|
||||
|
||||
-- Articles (generated or manual)
|
||||
# Articles
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS articles (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
url_path TEXT UNIQUE NOT NULL,
|
||||
@@ -424,33 +499,42 @@ def up(conn):
|
||||
template_data_id INTEGER REFERENCES template_data(id),
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT
|
||||
);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_articles_url_path ON articles(url_path)"
|
||||
)
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_articles_slug ON articles(slug)")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_articles_status ON articles(status, published_at)"
|
||||
)
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_articles_url_path ON articles(url_path);
|
||||
CREATE INDEX IF NOT EXISTS idx_articles_slug ON articles(slug);
|
||||
CREATE INDEX IF NOT EXISTS idx_articles_status ON articles(status, published_at);
|
||||
|
||||
-- FTS5 full-text search for articles
|
||||
# FTS5 full-text search for articles
|
||||
conn.execute("""
|
||||
CREATE VIRTUAL TABLE IF NOT EXISTS articles_fts USING fts5(
|
||||
title, meta_description, country, region,
|
||||
content='articles', content_rowid='id'
|
||||
);
|
||||
)
|
||||
""")
|
||||
|
||||
-- Keep FTS in sync with articles table
|
||||
# Keep FTS in sync with articles table
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS articles_ai AFTER INSERT ON articles BEGIN
|
||||
INSERT INTO articles_fts(rowid, title, meta_description, country, region)
|
||||
VALUES (new.id, new.title, new.meta_description, new.country, new.region);
|
||||
END;
|
||||
|
||||
END
|
||||
""")
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS articles_ad AFTER DELETE ON articles BEGIN
|
||||
INSERT INTO articles_fts(articles_fts, rowid, title, meta_description, country, region)
|
||||
VALUES ('delete', old.id, old.title, old.meta_description, old.country, old.region);
|
||||
END;
|
||||
|
||||
END
|
||||
""")
|
||||
conn.execute("""
|
||||
CREATE TRIGGER IF NOT EXISTS articles_au AFTER UPDATE ON articles BEGIN
|
||||
INSERT INTO articles_fts(articles_fts, rowid, title, meta_description, country, region)
|
||||
VALUES ('delete', old.id, old.title, old.meta_description, old.country, old.region);
|
||||
INSERT INTO articles_fts(rowid, title, meta_description, country, region)
|
||||
VALUES (new.id, new.title, new.meta_description, new.country, new.region);
|
||||
END;
|
||||
END
|
||||
""")
|
||||
|
||||
@@ -12,32 +12,37 @@ def _column_names(conn, table):
|
||||
|
||||
def up(conn):
|
||||
# 1. Create new tables (idempotent)
|
||||
conn.executescript("""
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS user_roles (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
role TEXT NOT NULL,
|
||||
granted_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
UNIQUE(user_id, role)
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_roles_user ON user_roles(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_user_roles_role ON user_roles(role);
|
||||
|
||||
)
|
||||
""")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_user_roles_user ON user_roles(user_id)")
|
||||
conn.execute("CREATE INDEX IF NOT EXISTS idx_user_roles_role ON user_roles(role)")
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS billing_customers (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL UNIQUE REFERENCES users(id),
|
||||
provider_customer_id TEXT NOT NULL,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS idx_billing_customers_user ON billing_customers(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_billing_customers_provider ON billing_customers(provider_customer_id);
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_billing_customers_user ON billing_customers(user_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_billing_customers_provider"
|
||||
" ON billing_customers(provider_customer_id)"
|
||||
)
|
||||
|
||||
cols = _column_names(conn, "subscriptions")
|
||||
|
||||
# Already migrated — nothing to do
|
||||
if "provider_subscription_id" in cols and "paddle_customer_id" not in cols:
|
||||
conn.commit()
|
||||
return
|
||||
|
||||
# 2. Migrate paddle_customer_id from subscriptions to billing_customers
|
||||
@@ -57,9 +62,8 @@ def up(conn):
|
||||
# - Drop UNIQUE constraint on user_id (allow multiple subs per user)
|
||||
old_sub_col = "paddle_subscription_id" if "paddle_subscription_id" in cols else "provider_subscription_id"
|
||||
|
||||
conn.executescript(f"""
|
||||
ALTER TABLE subscriptions RENAME TO _subscriptions_old;
|
||||
|
||||
conn.execute("ALTER TABLE subscriptions RENAME TO _subscriptions_old")
|
||||
conn.execute("""
|
||||
CREATE TABLE subscriptions (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
user_id INTEGER NOT NULL REFERENCES users(id),
|
||||
@@ -69,17 +73,20 @@ def up(conn):
|
||||
current_period_end TEXT,
|
||||
created_at TEXT NOT NULL,
|
||||
updated_at TEXT
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_subscriptions_provider ON subscriptions(provider_subscription_id);
|
||||
|
||||
)
|
||||
""")
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_subscriptions_user ON subscriptions(user_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_subscriptions_provider"
|
||||
" ON subscriptions(provider_subscription_id)"
|
||||
)
|
||||
conn.execute(f"""
|
||||
INSERT INTO subscriptions (id, user_id, plan, status, provider_subscription_id,
|
||||
current_period_end, created_at, updated_at)
|
||||
SELECT id, user_id, plan, status, {old_sub_col},
|
||||
current_period_end, created_at, updated_at
|
||||
FROM _subscriptions_old;
|
||||
|
||||
DROP TABLE _subscriptions_old;
|
||||
FROM _subscriptions_old
|
||||
""")
|
||||
|
||||
conn.commit()
|
||||
conn.execute("DROP TABLE _subscriptions_old")
|
||||
|
||||
@@ -23,7 +23,7 @@ def up(conn):
|
||||
if col not in cols:
|
||||
conn.execute(f"ALTER TABLE suppliers ADD COLUMN {col} {defn}")
|
||||
|
||||
conn.executescript("""
|
||||
conn.execute("""
|
||||
CREATE TABLE IF NOT EXISTS supplier_enquiries (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
supplier_id INTEGER NOT NULL REFERENCES suppliers(id),
|
||||
@@ -32,11 +32,13 @@ def up(conn):
|
||||
message TEXT NOT NULL,
|
||||
status TEXT NOT NULL DEFAULT 'new',
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_supplier
|
||||
ON supplier_enquiries(supplier_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_email
|
||||
ON supplier_enquiries(contact_email, created_at);
|
||||
)
|
||||
""")
|
||||
|
||||
conn.commit()
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_supplier"
|
||||
" ON supplier_enquiries(supplier_id)"
|
||||
)
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_supplier_enquiries_email"
|
||||
" ON supplier_enquiries(contact_email, created_at)"
|
||||
)
|
||||
|
||||
@@ -5,4 +5,3 @@ def up(conn):
|
||||
cols = [r[1] for r in conn.execute("PRAGMA table_info(suppliers)").fetchall()]
|
||||
if "cover_image" not in cols:
|
||||
conn.execute("ALTER TABLE suppliers ADD COLUMN cover_image TEXT")
|
||||
conn.commit()
|
||||
|
||||
@@ -17,4 +17,3 @@ def up(conn):
|
||||
conn.execute(
|
||||
"CREATE INDEX IF NOT EXISTS idx_waitlist_email ON waitlist(email)"
|
||||
)
|
||||
conn.commit()
|
||||
|
||||
@@ -9,4 +9,3 @@ def up(conn):
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
)
|
||||
""")
|
||||
conn.commit()
|
||||
|
||||
Reference in New Issue
Block a user