-- ============================================================ -- God Mode Complete Schema - Valhalla Database Foundation -- Last Updated: 2025-12-15 -- ============================================================ -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Enable PostGIS for geospatial features CREATE EXTENSION IF NOT EXISTS postgis; -- ============================================================ -- 1. SITES Table (Multi-Tenant Root) -- ============================================================ CREATE TABLE IF NOT EXISTS sites ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4 (), domain VARCHAR(255) UNIQUE NOT NULL, name VARCHAR(255) NOT NULL, status VARCHAR(50) DEFAULT 'active', -- active, maintenance, archived config JSONB DEFAULT '{}', -- branding, SEO settings, API keys client_id VARCHAR(255), -- External client tracking created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_sites_domain ON sites (domain); CREATE INDEX IF NOT EXISTS idx_sites_status ON sites (status); CREATE INDEX IF NOT EXISTS idx_sites_client_id ON sites (client_id); -- Insert default admin site INSERT INTO sites (domain, name, status, config) VALUES ( 'spark.jumpstartscaling.com', 'Spark Platform Admin', 'active', '{"type": "admin", "role": "god-mode"}' ) ON CONFLICT (domain) DO NOTHING; -- ============================================================ -- 2. POSTS Table (Blog/Article Content) -- ============================================================ CREATE TABLE IF NOT EXISTS posts ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), site_id UUID NOT NULL REFERENCES sites(id) ON DELETE CASCADE, title VARCHAR(512) NOT NULL, slug VARCHAR(512) NOT NULL, content TEXT, excerpt TEXT, status VARCHAR(50) DEFAULT 'draft', -- draft, review, published, archived published_at TIMESTAMPTZ, -- SEO Fields meta_title VARCHAR(255), meta_description VARCHAR(512), -- Geospatial targeting target_city VARCHAR(255), target_state VARCHAR(50), target_county VARCHAR(255), location GEOGRAPHY (POINT, 4326), -- PostGIS point -- Generation metadata generation_data JSONB DEFAULT '{}', -- LLM prompt, tokens, cost, avatar -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints UNIQUE (site_id, slug) ); CREATE INDEX IF NOT EXISTS idx_posts_site_id ON posts (site_id); CREATE INDEX IF NOT EXISTS idx_posts_status ON posts (status); CREATE INDEX IF NOT EXISTS idx_posts_slug ON posts (slug); CREATE INDEX IF NOT EXISTS idx_posts_published_at ON posts (published_at); CREATE INDEX IF NOT EXISTS idx_posts_location ON posts USING GIST (location); CREATE INDEX IF NOT EXISTS idx_posts_target_city ON posts (target_city); -- ============================================================ -- 3. PAGES Table (Static Landing Pages) -- ============================================================ CREATE TABLE IF NOT EXISTS pages ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), site_id UUID NOT NULL REFERENCES sites(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, route VARCHAR(512) NOT NULL, html_content TEXT, blocks JSONB DEFAULT '[]', -- Block-based content -- SEO priority INT DEFAULT 50, -- For sitemap.xml (0-100) meta_title VARCHAR(255), meta_description VARCHAR(512), -- Status status VARCHAR(50) DEFAULT 'draft', published_at TIMESTAMPTZ, -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), -- Constraints UNIQUE (site_id, route) ); CREATE INDEX IF NOT EXISTS idx_pages_site_id ON pages (site_id); CREATE INDEX IF NOT EXISTS idx_pages_route ON pages (route); CREATE INDEX IF NOT EXISTS idx_pages_status ON pages (status); CREATE INDEX IF NOT EXISTS idx_pages_priority ON pages (priority); -- ============================================================ -- 4. GENERATION_JOBS Table (Queue Tracking) -- ============================================================ CREATE TABLE IF NOT EXISTS generation_jobs ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), job_id VARCHAR(255) NOT NULL UNIQUE, -- BullMQ Job ID campaign_id UUID, -- Optional campaign reference -- Job config job_type VARCHAR(100) NOT NULL, -- 'generate_post', 'publish', 'assemble' target_data JSONB NOT NULL, -- Input data (city, lat/lng, prompt) -- Status tracking status VARCHAR(50) DEFAULT 'queued', -- queued, processing, success, failed progress INT DEFAULT 0, -- 0-100 -- Results result_ref_id UUID, -- Links to posts.id or pages.id result_type VARCHAR(50), -- 'post' or 'page' output_data JSONB, -- Generated content, metadata -- Error handling error_log TEXT, retry_count INT DEFAULT 0, -- Cost tracking tokens_used INT, estimated_cost_usd DECIMAL(10, 6), -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_jobs_job_id ON generation_jobs (job_id); CREATE INDEX IF NOT EXISTS idx_jobs_status ON generation_jobs (status); CREATE INDEX IF NOT EXISTS idx_jobs_campaign_id ON generation_jobs (campaign_id); CREATE INDEX IF NOT EXISTS idx_jobs_result_ref_id ON generation_jobs (result_ref_id); CREATE INDEX IF NOT EXISTS idx_jobs_created_at ON generation_jobs (created_at); -- ============================================================ -- 5. GEO_CLUSTERS Table (Geographic Targeting Groups) -- ============================================================ CREATE TABLE IF NOT EXISTS geo_clusters ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), name VARCHAR(255) NOT NULL, state VARCHAR(50), boundary GEOGRAPHY(POLYGON, 4326), -- PostGIS polygon center_point GEOGRAPHY(POINT, 4326), -- Metadata density VARCHAR(50), -- 'low', 'medium', 'high' target_count INT DEFAULT 0, -- How many locations to generate config JSONB DEFAULT '{}', -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_clusters_boundary ON geo_clusters USING GIST (boundary); CREATE INDEX IF NOT EXISTS idx_clusters_state ON geo_clusters (state); -- ============================================================ -- 6. GEO_LOCATIONS Table (Individual Target Points) -- ============================================================ CREATE TABLE IF NOT EXISTS geo_locations ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), cluster_id UUID REFERENCES geo_clusters(id) ON DELETE CASCADE, -- Location details city VARCHAR(255), state VARCHAR(50), country VARCHAR(255), zip VARCHAR(10), location GEOGRAPHY (POINT, 4326), -- Status content_generated BOOLEAN DEFAULT FALSE, post_id UUID REFERENCES posts (id) ON DELETE SET NULL, -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_locations_location ON geo_locations USING GIST (location); CREATE INDEX IF NOT EXISTS idx_locations_cluster_id ON geo_locations (cluster_id); CREATE INDEX IF NOT EXISTS idx_locations_city ON geo_locations (city); -- ============================================================ -- 7. UPDATED_AT Triggers (Auto-update timestamps) -- ============================================================ CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_sites_updated_at BEFORE UPDATE ON sites FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_posts_updated_at BEFORE UPDATE ON posts FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_pages_updated_at BEFORE UPDATE ON pages FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_generation_jobs_updated_at BEFORE UPDATE ON generation_jobs FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================================ -- SUCCESS MESSAGE -- ============================================================ DO $$ BEGIN RAISE NOTICE '🔱 Valhalla Database Schema Initialized Successfully'; END $$;