| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188 |
- -- Initialize core database schema for SaaS platform
- -- Extensions
- CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
- CREATE EXTENSION IF NOT EXISTS "pgcrypto";
- CREATE EXTENSION IF NOT EXISTS "pg_trgm";
- -- Users table
- CREATE TABLE IF NOT EXISTS users (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- email VARCHAR(255) UNIQUE NOT NULL,
- password_hash VARCHAR(255) NOT NULL,
- first_name VARCHAR(100),
- last_name VARCHAR(100),
- avatar_url TEXT,
- email_verified BOOLEAN DEFAULT FALSE,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- Organizations table
- CREATE TABLE IF NOT EXISTS organizations (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- name VARCHAR(255) NOT NULL,
- slug VARCHAR(100) UNIQUE NOT NULL,
- description TEXT,
- logo_url TEXT,
- created_by UUID REFERENCES users(id) ON DELETE SET NULL,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- Organization members
- CREATE TABLE IF NOT EXISTS organization_members (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
- user_id UUID REFERENCES users(id) ON DELETE CASCADE,
- role VARCHAR(50) DEFAULT 'member' CHECK (role IN ('owner', 'admin', 'member')),
- joined_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
- UNIQUE(organization_id, user_id)
- );
- -- Applications table for hosting TypeScript apps
- CREATE TABLE IF NOT EXISTS applications (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- name VARCHAR(255) NOT NULL,
- slug VARCHAR(100) NOT NULL,
- description TEXT,
- repository_url TEXT,
- branch VARCHAR(100) DEFAULT 'main',
- build_command VARCHAR(500),
- start_command VARCHAR(500),
- environment JSONB DEFAULT '{}',
- domains TEXT[],
- status VARCHAR(50) DEFAULT 'inactive' CHECK (status IN ('building', 'active', 'inactive', 'error')),
- organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
- created_by UUID REFERENCES users(id) ON DELETE SET NULL,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
- updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
- UNIQUE(slug)
- );
- -- Deployments table
- CREATE TABLE IF NOT EXISTS deployments (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- application_id UUID REFERENCES applications(id) ON DELETE CASCADE,
- version VARCHAR(100),
- commit_hash VARCHAR(40),
- build_log TEXT,
- status VARCHAR(50) DEFAULT 'pending' CHECK (status IN ('pending', 'building', 'deployed', 'failed', 'rolling_back')),
- deployed_at TIMESTAMP WITH TIME ZONE,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- API Keys table
- CREATE TABLE IF NOT EXISTS api_keys (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- name VARCHAR(255) NOT NULL,
- key_hash VARCHAR(255) NOT NULL UNIQUE,
- permissions JSONB DEFAULT '[]',
- organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
- created_by UUID REFERENCES users(id) ON DELETE SET NULL,
- last_used_at TIMESTAMP WITH TIME ZONE,
- expires_at TIMESTAMP WITH TIME ZONE,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- Sessions table for authentication
- CREATE TABLE IF NOT EXISTS sessions (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- user_id UUID REFERENCES users(id) ON DELETE CASCADE,
- token_hash VARCHAR(255) NOT NULL UNIQUE,
- refresh_token_hash VARCHAR(255),
- expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- Audit log
- CREATE TABLE IF NOT EXISTS audit_logs (
- id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
- user_id UUID REFERENCES users(id) ON DELETE SET NULL,
- organization_id UUID REFERENCES organizations(id) ON DELETE SET NULL,
- action VARCHAR(100) NOT NULL,
- resource_type VARCHAR(100) NOT NULL,
- resource_id UUID,
- details JSONB DEFAULT '{}',
- ip_address INET,
- user_agent TEXT,
- created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
- );
- -- Indexes for performance
- CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
- CREATE INDEX IF NOT EXISTS idx_users_email_verified ON users(email_verified);
- CREATE INDEX IF NOT EXISTS idx_organizations_slug ON organizations(slug);
- CREATE INDEX IF NOT EXISTS idx_organization_members_org_id ON organization_members(organization_id);
- CREATE INDEX IF NOT EXISTS idx_organization_members_user_id ON organization_members(user_id);
- CREATE INDEX IF NOT EXISTS idx_applications_org_id ON applications(organization_id);
- CREATE INDEX IF NOT EXISTS idx_applications_status ON applications(status);
- CREATE INDEX IF NOT EXISTS idx_deployments_app_id ON deployments(application_id);
- CREATE INDEX IF NOT EXISTS idx_api_keys_org_id ON api_keys(organization_id);
- CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
- CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash);
- CREATE INDEX IF NOT EXISTS idx_audit_logs_user_id ON audit_logs(user_id);
- CREATE INDEX IF NOT EXISTS idx_audit_logs_org_id ON audit_logs(organization_id);
- CREATE INDEX IF NOT EXISTS idx_audit_logs_created_at ON audit_logs(created_at);
- -- Function to update updated_at timestamp
- CREATE OR REPLACE FUNCTION update_updated_at_column()
- RETURNS TRIGGER AS $$
- BEGIN
- NEW.updated_at = CURRENT_TIMESTAMP;
- RETURN NEW;
- END;
- $$ language 'plpgsql';
- -- Triggers for updated_at
- CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
- CREATE TRIGGER update_organizations_updated_at BEFORE UPDATE ON organizations
- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
- CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications
- FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
- -- Row Level Security (RLS) for multi-tenancy
- ALTER TABLE applications ENABLE ROW LEVEL SECURITY;
- ALTER TABLE deployments ENABLE ROW LEVEL SECURITY;
- ALTER TABLE api_keys ENABLE ROW LEVEL SECURITY;
- -- RLS Policies
- CREATE POLICY "Users can view applications in their orgs" ON applications
- FOR SELECT USING (
- organization_id IN (
- SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
- )
- );
- CREATE POLICY "Users can insert applications in their orgs" ON applications
- FOR INSERT WITH CHECK (
- organization_id IN (
- SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
- )
- );
- CREATE POLICY "Users can update applications in their orgs" ON applications
- FOR UPDATE USING (
- organization_id IN (
- SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
- )
- );
- -- Create default admin user (password: admin123 - change immediately)
- INSERT INTO users (email, password_hash, first_name, last_name, email_verified)
- VALUES (
- 'admin@saas.local',
- '$2b$10$rQO8vV8x8t5QX7O9HJ5Y/uKQ8vV8x8t5QX7O9HJ5Y/uKQ8vV8x8t5Q',
- 'Admin',
- 'User',
- true
- ) ON CONFLICT (email) DO NOTHING;
- -- Create default organization
- INSERT INTO organizations (name, slug, description, created_by)
- SELECT 'Default Organization', 'default-org', 'Default organization for getting started', id
- FROM users WHERE email = 'admin@saas.local'
- ON CONFLICT (slug) DO NOTHING;
|