Initial commit: Cloud Instances API
Multi-cloud VM instance database with Cloudflare Workers - Linode, Vultr, AWS connector integration - D1 database with regions, instances, pricing - Query API with filtering, caching, pagination - Cron-based auto-sync (daily + 6-hourly) - Health monitoring endpoint Co-Authored-By: Claude Opus 4.5 <noreply@anthropic.com>
This commit is contained in:
177
schema.sql
Normal file
177
schema.sql
Normal file
@@ -0,0 +1,177 @@
|
||||
-- Cloud Server Pricing Database Schema
|
||||
-- SQLite/Cloudflare D1 Compatible
|
||||
-- ISO 8601 datetime format: YYYY-MM-DD HH:MM:SS
|
||||
|
||||
-- ============================================================
|
||||
-- Table: providers
|
||||
-- Description: Cloud provider information
|
||||
-- ============================================================
|
||||
CREATE TABLE IF NOT EXISTS providers (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
name TEXT NOT NULL UNIQUE, -- linode, vultr, aws, etc.
|
||||
display_name TEXT NOT NULL,
|
||||
api_base_url TEXT,
|
||||
last_sync_at TEXT, -- ISO 8601: YYYY-MM-DD HH:MM:SS
|
||||
sync_status TEXT NOT NULL DEFAULT 'pending' CHECK (sync_status IN ('pending', 'syncing', 'success', 'error')),
|
||||
sync_error TEXT,
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now'))
|
||||
);
|
||||
|
||||
-- Index for status queries
|
||||
CREATE INDEX IF NOT EXISTS idx_providers_sync_status ON providers(sync_status);
|
||||
CREATE INDEX IF NOT EXISTS idx_providers_name ON providers(name);
|
||||
|
||||
-- ============================================================
|
||||
-- Table: regions
|
||||
-- Description: Provider regions and availability zones
|
||||
-- ============================================================
|
||||
CREATE TABLE IF NOT EXISTS regions (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
provider_id INTEGER NOT NULL,
|
||||
region_code TEXT NOT NULL, -- e.g., us-east, ap-south
|
||||
region_name TEXT NOT NULL, -- e.g., "US East (Newark)"
|
||||
country_code TEXT, -- ISO 3166-1 alpha-2
|
||||
latitude REAL,
|
||||
longitude REAL,
|
||||
available INTEGER NOT NULL DEFAULT 1, -- boolean: 1=true, 0=false
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (provider_id) REFERENCES providers(id) ON DELETE CASCADE,
|
||||
UNIQUE(provider_id, region_code)
|
||||
);
|
||||
|
||||
-- Indexes for foreign key and queries
|
||||
CREATE INDEX IF NOT EXISTS idx_regions_provider_id ON regions(provider_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_regions_available ON regions(available);
|
||||
CREATE INDEX IF NOT EXISTS idx_regions_country_code ON regions(country_code);
|
||||
|
||||
-- ============================================================
|
||||
-- Table: instance_types
|
||||
-- Description: VM instance specifications across providers
|
||||
-- ============================================================
|
||||
CREATE TABLE IF NOT EXISTS instance_types (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
provider_id INTEGER NOT NULL,
|
||||
instance_id TEXT NOT NULL, -- provider's instance identifier
|
||||
instance_name TEXT NOT NULL, -- display name
|
||||
vcpu INTEGER NOT NULL,
|
||||
memory_mb INTEGER NOT NULL,
|
||||
storage_gb INTEGER NOT NULL,
|
||||
transfer_tb REAL, -- data transfer limit
|
||||
network_speed_gbps REAL,
|
||||
gpu_count INTEGER DEFAULT 0,
|
||||
gpu_type TEXT, -- e.g., "NVIDIA A100"
|
||||
instance_family TEXT CHECK (instance_family IN ('general', 'compute', 'memory', 'storage', 'gpu')),
|
||||
metadata TEXT, -- JSON for additional provider-specific data
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (provider_id) REFERENCES providers(id) ON DELETE CASCADE,
|
||||
UNIQUE(provider_id, instance_id)
|
||||
);
|
||||
|
||||
-- Indexes for filtering and sorting
|
||||
CREATE INDEX IF NOT EXISTS idx_instance_types_provider_id ON instance_types(provider_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_instance_types_vcpu ON instance_types(vcpu);
|
||||
CREATE INDEX IF NOT EXISTS idx_instance_types_memory_mb ON instance_types(memory_mb);
|
||||
CREATE INDEX IF NOT EXISTS idx_instance_types_instance_family ON instance_types(instance_family);
|
||||
CREATE INDEX IF NOT EXISTS idx_instance_types_gpu_count ON instance_types(gpu_count);
|
||||
|
||||
-- ============================================================
|
||||
-- Table: pricing
|
||||
-- Description: Region-specific pricing for instance types
|
||||
-- ============================================================
|
||||
CREATE TABLE IF NOT EXISTS pricing (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
instance_type_id INTEGER NOT NULL,
|
||||
region_id INTEGER NOT NULL,
|
||||
hourly_price REAL NOT NULL,
|
||||
monthly_price REAL NOT NULL,
|
||||
currency TEXT NOT NULL DEFAULT 'USD',
|
||||
available INTEGER NOT NULL DEFAULT 1, -- boolean: 1=true, 0=false
|
||||
created_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
updated_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (instance_type_id) REFERENCES instance_types(id) ON DELETE CASCADE,
|
||||
FOREIGN KEY (region_id) REFERENCES regions(id) ON DELETE CASCADE,
|
||||
UNIQUE(instance_type_id, region_id)
|
||||
);
|
||||
|
||||
-- Indexes for price queries and filtering
|
||||
CREATE INDEX IF NOT EXISTS idx_pricing_instance_type_id ON pricing(instance_type_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_pricing_region_id ON pricing(region_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_pricing_hourly_price ON pricing(hourly_price);
|
||||
CREATE INDEX IF NOT EXISTS idx_pricing_monthly_price ON pricing(monthly_price);
|
||||
CREATE INDEX IF NOT EXISTS idx_pricing_available ON pricing(available);
|
||||
|
||||
-- ============================================================
|
||||
-- Table: price_history
|
||||
-- Description: Historical price tracking for trend analysis
|
||||
-- ============================================================
|
||||
CREATE TABLE IF NOT EXISTS price_history (
|
||||
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
||||
pricing_id INTEGER NOT NULL,
|
||||
hourly_price REAL NOT NULL,
|
||||
monthly_price REAL NOT NULL,
|
||||
recorded_at TEXT NOT NULL DEFAULT (datetime('now')),
|
||||
FOREIGN KEY (pricing_id) REFERENCES pricing(id) ON DELETE CASCADE
|
||||
);
|
||||
|
||||
-- Indexes for time-series queries
|
||||
CREATE INDEX IF NOT EXISTS idx_price_history_pricing_id ON price_history(pricing_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_price_history_recorded_at ON price_history(recorded_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_price_history_pricing_recorded ON price_history(pricing_id, recorded_at DESC);
|
||||
|
||||
-- ============================================================
|
||||
-- Triggers: Auto-update updated_at timestamp
|
||||
-- ============================================================
|
||||
|
||||
CREATE TRIGGER IF NOT EXISTS update_providers_updated_at
|
||||
AFTER UPDATE ON providers
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE providers SET updated_at = datetime('now') WHERE id = NEW.id;
|
||||
END;
|
||||
|
||||
CREATE TRIGGER IF NOT EXISTS update_regions_updated_at
|
||||
AFTER UPDATE ON regions
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE regions SET updated_at = datetime('now') WHERE id = NEW.id;
|
||||
END;
|
||||
|
||||
CREATE TRIGGER IF NOT EXISTS update_instance_types_updated_at
|
||||
AFTER UPDATE ON instance_types
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE instance_types SET updated_at = datetime('now') WHERE id = NEW.id;
|
||||
END;
|
||||
|
||||
CREATE TRIGGER IF NOT EXISTS update_pricing_updated_at
|
||||
AFTER UPDATE ON pricing
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE pricing SET updated_at = datetime('now') WHERE id = NEW.id;
|
||||
END;
|
||||
|
||||
-- ============================================================
|
||||
-- Triggers: Price history tracking
|
||||
-- ============================================================
|
||||
|
||||
-- Record price changes automatically
|
||||
CREATE TRIGGER IF NOT EXISTS track_price_changes
|
||||
AFTER UPDATE OF hourly_price, monthly_price ON pricing
|
||||
FOR EACH ROW
|
||||
WHEN OLD.hourly_price != NEW.hourly_price OR OLD.monthly_price != NEW.monthly_price
|
||||
BEGIN
|
||||
INSERT INTO price_history (pricing_id, hourly_price, monthly_price, recorded_at)
|
||||
VALUES (NEW.id, NEW.hourly_price, NEW.monthly_price, datetime('now'));
|
||||
END;
|
||||
|
||||
-- Record initial price on creation
|
||||
CREATE TRIGGER IF NOT EXISTS track_initial_price
|
||||
AFTER INSERT ON pricing
|
||||
FOR EACH ROW
|
||||
BEGIN
|
||||
INSERT INTO price_history (pricing_id, hourly_price, monthly_price, recorded_at)
|
||||
VALUES (NEW.id, NEW.hourly_price, NEW.monthly_price, datetime('now'));
|
||||
END;
|
||||
Reference in New Issue
Block a user