142 lines
6.3 KiB
SQL
142 lines
6.3 KiB
SQL
-- Safe Migration Script for LittleShop Database
|
|
-- This script can be safely run on an existing database
|
|
-- It will check for existing objects before creating them
|
|
|
|
-- Create the EF Migrations History table if it doesn't exist
|
|
CREATE TABLE IF NOT EXISTS "__EFMigrationsHistory" (
|
|
"MigrationId" TEXT NOT NULL CONSTRAINT "PK___EFMigrationsHistory" PRIMARY KEY,
|
|
"ProductVersion" TEXT NOT NULL
|
|
);
|
|
|
|
-- Check and fix any schema issues with existing tables
|
|
|
|
-- 1. Check if ProductMultiBuys table exists (from migration 20250922025753_AddProductMultiBuysTable)
|
|
CREATE TABLE IF NOT EXISTS "ProductMultiBuys" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_ProductMultiBuys" PRIMARY KEY,
|
|
"ProductId" TEXT NOT NULL,
|
|
"Quantity" INTEGER NOT NULL,
|
|
"Price" decimal(18,2) NOT NULL,
|
|
"Description" TEXT NOT NULL,
|
|
"IsActive" INTEGER NOT NULL DEFAULT 1,
|
|
CONSTRAINT "FK_ProductMultiBuys_Products_ProductId" FOREIGN KEY ("ProductId") REFERENCES "Products" ("Id") ON DELETE CASCADE
|
|
);
|
|
|
|
-- 2. Check if SystemSettings table exists (from migration 20250922040637_AddSystemSettingsTable)
|
|
CREATE TABLE IF NOT EXISTS "SystemSettings" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_SystemSettings" PRIMARY KEY,
|
|
"Key" TEXT NOT NULL,
|
|
"Value" TEXT NOT NULL,
|
|
"Type" TEXT NOT NULL,
|
|
"Description" TEXT NULL,
|
|
"IsReadOnly" INTEGER NOT NULL DEFAULT 0,
|
|
"CreatedAt" TEXT NOT NULL,
|
|
"UpdatedAt" TEXT NOT NULL
|
|
);
|
|
|
|
-- Create unique index if it doesn't exist
|
|
CREATE UNIQUE INDEX IF NOT EXISTS "IX_SystemSettings_Key" ON "SystemSettings" ("Key");
|
|
|
|
-- 3. Check if VariantCollections table exists (from migration 20250928014850_AddVariantCollectionsAndSalesLedger)
|
|
CREATE TABLE IF NOT EXISTS "VariantCollections" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_VariantCollections" PRIMARY KEY,
|
|
"Name" TEXT NOT NULL,
|
|
"Description" TEXT NULL,
|
|
"CreatedAt" TEXT NOT NULL,
|
|
"UpdatedAt" TEXT NOT NULL,
|
|
"IsActive" INTEGER NOT NULL DEFAULT 1
|
|
);
|
|
|
|
-- 4. Check if ProductVariants table exists
|
|
CREATE TABLE IF NOT EXISTS "ProductVariants" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_ProductVariants" PRIMARY KEY,
|
|
"CollectionId" TEXT NOT NULL,
|
|
"Sku" TEXT NOT NULL,
|
|
"Options" TEXT NOT NULL,
|
|
"PriceAdjustment" decimal(18,2) NOT NULL DEFAULT 0,
|
|
"QuantityInStock" INTEGER NOT NULL DEFAULT 0,
|
|
"Weight" TEXT NULL,
|
|
"WeightUnit" INTEGER NULL,
|
|
"CreatedAt" TEXT NOT NULL,
|
|
"UpdatedAt" TEXT NOT NULL,
|
|
"IsActive" INTEGER NOT NULL DEFAULT 1,
|
|
CONSTRAINT "FK_ProductVariants_VariantCollections_CollectionId" FOREIGN KEY ("CollectionId") REFERENCES "VariantCollections" ("Id") ON DELETE CASCADE
|
|
);
|
|
|
|
-- 5. Check if SalesLedger table exists
|
|
CREATE TABLE IF NOT EXISTS "SalesLedger" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_SalesLedger" PRIMARY KEY,
|
|
"OrderId" TEXT NOT NULL,
|
|
"TransactionType" INTEGER NOT NULL,
|
|
"PaymentMethod" TEXT NULL,
|
|
"Amount" decimal(18,2) NOT NULL,
|
|
"Tax" decimal(18,2) NOT NULL DEFAULT 0,
|
|
"Discount" decimal(18,2) NOT NULL DEFAULT 0,
|
|
"NetAmount" decimal(18,2) NOT NULL,
|
|
"Currency" TEXT NOT NULL DEFAULT 'GBP',
|
|
"ExchangeRate" decimal(18,8) NOT NULL DEFAULT 1,
|
|
"TransactionDate" TEXT NOT NULL,
|
|
"RecordedAt" TEXT NOT NULL,
|
|
"Description" TEXT NULL,
|
|
"Reference" TEXT NULL,
|
|
"Status" INTEGER NOT NULL,
|
|
"ReconciledAt" TEXT NULL,
|
|
"ReconciledBy" TEXT NULL,
|
|
"Notes" TEXT NULL,
|
|
CONSTRAINT "FK_SalesLedger_Orders_OrderId" FOREIGN KEY ("OrderId") REFERENCES "Orders" ("Id") ON DELETE CASCADE
|
|
);
|
|
|
|
-- 6. Add Weight columns to ProductVariants if they don't exist (migration 20250928155814_AddWeightToProductVariants)
|
|
-- SQLite doesn't support conditional column addition, so we need to handle this differently
|
|
-- This would need to be done programmatically or by checking the schema first
|
|
|
|
-- 7. Check if PushSubscriptions table exists
|
|
CREATE TABLE IF NOT EXISTS "PushSubscriptions" (
|
|
"Id" TEXT NOT NULL CONSTRAINT "PK_PushSubscriptions" PRIMARY KEY,
|
|
"UserId" TEXT NOT NULL,
|
|
"Endpoint" TEXT NOT NULL,
|
|
"P256dh" TEXT NOT NULL,
|
|
"Auth" TEXT NOT NULL,
|
|
"CreatedAt" TEXT NOT NULL,
|
|
"UpdatedAt" TEXT NOT NULL,
|
|
"IsActive" INTEGER NOT NULL DEFAULT 1,
|
|
CONSTRAINT "FK_PushSubscriptions_Users_UserId" FOREIGN KEY ("UserId") REFERENCES "Users" ("Id") ON DELETE CASCADE
|
|
);
|
|
|
|
-- Insert migration history records if they don't exist
|
|
INSERT OR IGNORE INTO "__EFMigrationsHistory" ("MigrationId", "ProductVersion")
|
|
VALUES ('20250922025753_AddProductMultiBuysTable', '9.0.9');
|
|
|
|
INSERT OR IGNORE INTO "__EFMigrationsHistory" ("MigrationId", "ProductVersion")
|
|
VALUES ('20250922040637_AddSystemSettingsTable', '9.0.9');
|
|
|
|
INSERT OR IGNORE INTO "__EFMigrationsHistory" ("MigrationId", "ProductVersion")
|
|
VALUES ('20250928014850_AddVariantCollectionsAndSalesLedger', '9.0.9');
|
|
|
|
INSERT OR IGNORE INTO "__EFMigrationsHistory" ("MigrationId", "ProductVersion")
|
|
VALUES ('20250928155814_AddWeightToProductVariants', '9.0.9');
|
|
|
|
-- Add any missing columns to existing tables
|
|
-- Note: SQLite has limitations with ALTER TABLE, so some changes may require table recreation
|
|
|
|
-- Ensure all necessary indexes exist
|
|
CREATE INDEX IF NOT EXISTS "IX_ProductMultiBuys_ProductId" ON "ProductMultiBuys" ("ProductId");
|
|
CREATE UNIQUE INDEX IF NOT EXISTS "IX_ProductMultiBuys_ProductId_Quantity" ON "ProductMultiBuys" ("ProductId", "Quantity");
|
|
CREATE INDEX IF NOT EXISTS "IX_ProductVariants_CollectionId" ON "ProductVariants" ("CollectionId");
|
|
CREATE UNIQUE INDEX IF NOT EXISTS "IX_ProductVariants_Sku" ON "ProductVariants" ("Sku");
|
|
CREATE INDEX IF NOT EXISTS "IX_SalesLedger_OrderId" ON "SalesLedger" ("OrderId");
|
|
CREATE INDEX IF NOT EXISTS "IX_SalesLedger_TransactionDate" ON "SalesLedger" ("TransactionDate");
|
|
CREATE INDEX IF NOT EXISTS "IX_PushSubscriptions_UserId" ON "PushSubscriptions" ("UserId");
|
|
|
|
-- Verify core tables exist
|
|
SELECT CASE
|
|
WHEN (SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name='Products') = 0
|
|
THEN RAISE(ABORT, 'Products table missing - database may need initialization')
|
|
WHEN (SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name='Orders') = 0
|
|
THEN RAISE(ABORT, 'Orders table missing - database may need initialization')
|
|
WHEN (SELECT COUNT(*) FROM sqlite_master WHERE type='table' AND name='Users') = 0
|
|
THEN RAISE(ABORT, 'Users table missing - database may need initialization')
|
|
ELSE 'Schema verification passed'
|
|
END;
|
|
|
|
-- Output success message
|
|
SELECT 'Migration completed successfully' AS Result; |