-- Migration 004: Anvil Product Tables -- Creates tables for Anvil-branded cloud products -- ============================================================ -- Table: anvil_regions -- Purpose: Anvil-branded regional datacenters mapped to source providers -- ============================================================ CREATE TABLE IF NOT EXISTS anvil_regions ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL UNIQUE, -- "anvil-tyo1", "anvil-sel1" display_name TEXT NOT NULL, -- "Tokyo 1", "Seoul 1" country_code TEXT NOT NULL, -- "JP", "KR" source_provider TEXT NOT NULL, -- "linode", "vultr" source_region_code TEXT NOT NULL, -- "jp-tyo-3", "nrt" source_region_id INTEGER NOT NULL, -- FK to regions.id active INTEGER NOT NULL DEFAULT 1, -- 0/1 boolean created_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (source_region_id) REFERENCES regions(id) ON DELETE RESTRICT ); -- Index for fast lookup by source region CREATE INDEX IF NOT EXISTS idx_anvil_regions_source ON anvil_regions(source_region_id); -- Index for active regions lookup CREATE INDEX IF NOT EXISTS idx_anvil_regions_active ON anvil_regions(active); -- ============================================================ -- Table: anvil_instances -- Purpose: Anvil-branded instance specifications -- ============================================================ CREATE TABLE IF NOT EXISTS anvil_instances ( id INTEGER PRIMARY KEY AUTOINCREMENT, name TEXT NOT NULL UNIQUE, -- "anvil-1g-1c" display_name TEXT NOT NULL, -- "Basic 1GB" category TEXT NOT NULL DEFAULT 'vm', -- "vm", "gpu", "g8", "vpu" vcpus INTEGER NOT NULL, memory_gb REAL NOT NULL, disk_gb INTEGER NOT NULL, transfer_tb REAL, network_gbps REAL, gpu_model TEXT, -- GPU-specific gpu_vram_gb INTEGER, -- GPU-specific active INTEGER NOT NULL DEFAULT 1, -- 0/1 boolean created_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP ); -- Index for category-based queries CREATE INDEX IF NOT EXISTS idx_anvil_instances_category ON anvil_instances(category); -- Index for active instances lookup CREATE INDEX IF NOT EXISTS idx_anvil_instances_active ON anvil_instances(active); -- ============================================================ -- Table: anvil_pricing -- Purpose: Anvil retail pricing with cost tracking -- ============================================================ CREATE TABLE IF NOT EXISTS anvil_pricing ( id INTEGER PRIMARY KEY AUTOINCREMENT, anvil_instance_id INTEGER NOT NULL, anvil_region_id INTEGER NOT NULL, hourly_price REAL NOT NULL, -- Retail price (USD) monthly_price REAL NOT NULL, -- Retail price (USD) hourly_price_krw REAL, -- Retail price (KRW) monthly_price_krw REAL, -- Retail price (KRW) cost_hourly REAL, -- Wholesale cost (USD) cost_monthly REAL, -- Wholesale cost (USD) source_instance_id INTEGER, -- FK to source tables (instance_types, gpu_instances, etc) active INTEGER NOT NULL DEFAULT 1, -- 0/1 boolean created_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (anvil_instance_id) REFERENCES anvil_instances(id) ON DELETE CASCADE, FOREIGN KEY (anvil_region_id) REFERENCES anvil_regions(id) ON DELETE CASCADE, UNIQUE(anvil_instance_id, anvil_region_id) ); -- Index for instance-based queries CREATE INDEX IF NOT EXISTS idx_anvil_pricing_instance ON anvil_pricing(anvil_instance_id); -- Index for region-based queries CREATE INDEX IF NOT EXISTS idx_anvil_pricing_region ON anvil_pricing(anvil_region_id); -- Index for active pricing lookup CREATE INDEX IF NOT EXISTS idx_anvil_pricing_active ON anvil_pricing(active); -- ============================================================ -- Table: anvil_transfer_pricing -- Purpose: Data transfer pricing per region -- ============================================================ CREATE TABLE IF NOT EXISTS anvil_transfer_pricing ( id INTEGER PRIMARY KEY AUTOINCREMENT, anvil_region_id INTEGER NOT NULL, price_per_gb REAL NOT NULL, -- USD/GB price_per_gb_krw REAL, -- KRW/GB included_tb REAL NOT NULL DEFAULT 0, -- Reference only active INTEGER NOT NULL DEFAULT 1, -- 0/1 boolean created_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, updated_at TEXT NOT NULL DEFAULT CURRENT_TIMESTAMP, FOREIGN KEY (anvil_region_id) REFERENCES anvil_regions(id) ON DELETE CASCADE, UNIQUE(anvil_region_id) ); -- Index for active transfer pricing lookup CREATE INDEX IF NOT EXISTS idx_anvil_transfer_pricing_active ON anvil_transfer_pricing(active); -- ============================================================ -- Triggers: Auto-update updated_at timestamps -- ============================================================ CREATE TRIGGER IF NOT EXISTS trigger_anvil_regions_updated_at AFTER UPDATE ON anvil_regions FOR EACH ROW BEGIN UPDATE anvil_regions SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; CREATE TRIGGER IF NOT EXISTS trigger_anvil_instances_updated_at AFTER UPDATE ON anvil_instances FOR EACH ROW BEGIN UPDATE anvil_instances SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; CREATE TRIGGER IF NOT EXISTS trigger_anvil_pricing_updated_at AFTER UPDATE ON anvil_pricing FOR EACH ROW BEGIN UPDATE anvil_pricing SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; CREATE TRIGGER IF NOT EXISTS trigger_anvil_transfer_pricing_updated_at AFTER UPDATE ON anvil_transfer_pricing FOR EACH ROW BEGIN UPDATE anvil_transfer_pricing SET updated_at = CURRENT_TIMESTAMP WHERE id = NEW.id; END; -- ============================================================ -- Initial Data: anvil_regions -- ============================================================ INSERT INTO anvil_regions (name, display_name, country_code, source_provider, source_region_code, source_region_id) VALUES ('anvil-tyo1', 'Tokyo 1', 'JP', 'linode', 'ap-northeast', 26), ('anvil-tyo2', 'Tokyo 2', 'JP', 'linode', 'jp-tyo-3', 3), ('anvil-tyo3', 'Tokyo 3', 'JP', 'vultr', 'nrt', 323), ('anvil-osa1', 'Osaka 1', 'JP', 'linode', 'jp-osa', 13), ('anvil-osa2', 'Osaka 2', 'JP', 'vultr', 'itm', 314), ('anvil-sel1', 'Seoul 1', 'KR', 'vultr', 'icn', 313) ON CONFLICT(name) DO UPDATE SET display_name = excluded.display_name, country_code = excluded.country_code, source_provider = excluded.source_provider, source_region_code = excluded.source_region_code, source_region_id = excluded.source_region_id;