01-database.sql 7.3 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188
  1. -- Initialize core database schema for SaaS platform
  2. -- Extensions
  3. CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
  4. CREATE EXTENSION IF NOT EXISTS "pgcrypto";
  5. CREATE EXTENSION IF NOT EXISTS "pg_trgm";
  6. -- Users table
  7. CREATE TABLE IF NOT EXISTS users (
  8. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  9. email VARCHAR(255) UNIQUE NOT NULL,
  10. password_hash VARCHAR(255) NOT NULL,
  11. first_name VARCHAR(100),
  12. last_name VARCHAR(100),
  13. avatar_url TEXT,
  14. email_verified BOOLEAN DEFAULT FALSE,
  15. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
  16. updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  17. );
  18. -- Organizations table
  19. CREATE TABLE IF NOT EXISTS organizations (
  20. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  21. name VARCHAR(255) NOT NULL,
  22. slug VARCHAR(100) UNIQUE NOT NULL,
  23. description TEXT,
  24. logo_url TEXT,
  25. created_by UUID REFERENCES users(id) ON DELETE SET NULL,
  26. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
  27. updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  28. );
  29. -- Organization members
  30. CREATE TABLE IF NOT EXISTS organization_members (
  31. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  32. organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
  33. user_id UUID REFERENCES users(id) ON DELETE CASCADE,
  34. role VARCHAR(50) DEFAULT 'member' CHECK (role IN ('owner', 'admin', 'member')),
  35. joined_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
  36. UNIQUE(organization_id, user_id)
  37. );
  38. -- Applications table for hosting TypeScript apps
  39. CREATE TABLE IF NOT EXISTS applications (
  40. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  41. name VARCHAR(255) NOT NULL,
  42. slug VARCHAR(100) NOT NULL,
  43. description TEXT,
  44. repository_url TEXT,
  45. branch VARCHAR(100) DEFAULT 'main',
  46. build_command VARCHAR(500),
  47. start_command VARCHAR(500),
  48. environment JSONB DEFAULT '{}',
  49. domains TEXT[],
  50. status VARCHAR(50) DEFAULT 'inactive' CHECK (status IN ('building', 'active', 'inactive', 'error')),
  51. organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
  52. created_by UUID REFERENCES users(id) ON DELETE SET NULL,
  53. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
  54. updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
  55. UNIQUE(slug)
  56. );
  57. -- Deployments table
  58. CREATE TABLE IF NOT EXISTS deployments (
  59. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  60. application_id UUID REFERENCES applications(id) ON DELETE CASCADE,
  61. version VARCHAR(100),
  62. commit_hash VARCHAR(40),
  63. build_log TEXT,
  64. status VARCHAR(50) DEFAULT 'pending' CHECK (status IN ('pending', 'building', 'deployed', 'failed', 'rolling_back')),
  65. deployed_at TIMESTAMP WITH TIME ZONE,
  66. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  67. );
  68. -- API Keys table
  69. CREATE TABLE IF NOT EXISTS api_keys (
  70. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  71. name VARCHAR(255) NOT NULL,
  72. key_hash VARCHAR(255) NOT NULL UNIQUE,
  73. permissions JSONB DEFAULT '[]',
  74. organization_id UUID REFERENCES organizations(id) ON DELETE CASCADE,
  75. created_by UUID REFERENCES users(id) ON DELETE SET NULL,
  76. last_used_at TIMESTAMP WITH TIME ZONE,
  77. expires_at TIMESTAMP WITH TIME ZONE,
  78. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  79. );
  80. -- Sessions table for authentication
  81. CREATE TABLE IF NOT EXISTS sessions (
  82. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  83. user_id UUID REFERENCES users(id) ON DELETE CASCADE,
  84. token_hash VARCHAR(255) NOT NULL UNIQUE,
  85. refresh_token_hash VARCHAR(255),
  86. expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
  87. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  88. );
  89. -- Audit log
  90. CREATE TABLE IF NOT EXISTS audit_logs (
  91. id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
  92. user_id UUID REFERENCES users(id) ON DELETE SET NULL,
  93. organization_id UUID REFERENCES organizations(id) ON DELETE SET NULL,
  94. action VARCHAR(100) NOT NULL,
  95. resource_type VARCHAR(100) NOT NULL,
  96. resource_id UUID,
  97. details JSONB DEFAULT '{}',
  98. ip_address INET,
  99. user_agent TEXT,
  100. created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
  101. );
  102. -- Indexes for performance
  103. CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
  104. CREATE INDEX IF NOT EXISTS idx_users_email_verified ON users(email_verified);
  105. CREATE INDEX IF NOT EXISTS idx_organizations_slug ON organizations(slug);
  106. CREATE INDEX IF NOT EXISTS idx_organization_members_org_id ON organization_members(organization_id);
  107. CREATE INDEX IF NOT EXISTS idx_organization_members_user_id ON organization_members(user_id);
  108. CREATE INDEX IF NOT EXISTS idx_applications_org_id ON applications(organization_id);
  109. CREATE INDEX IF NOT EXISTS idx_applications_status ON applications(status);
  110. CREATE INDEX IF NOT EXISTS idx_deployments_app_id ON deployments(application_id);
  111. CREATE INDEX IF NOT EXISTS idx_api_keys_org_id ON api_keys(organization_id);
  112. CREATE INDEX IF NOT EXISTS idx_sessions_user_id ON sessions(user_id);
  113. CREATE INDEX IF NOT EXISTS idx_sessions_token_hash ON sessions(token_hash);
  114. CREATE INDEX IF NOT EXISTS idx_audit_logs_user_id ON audit_logs(user_id);
  115. CREATE INDEX IF NOT EXISTS idx_audit_logs_org_id ON audit_logs(organization_id);
  116. CREATE INDEX IF NOT EXISTS idx_audit_logs_created_at ON audit_logs(created_at);
  117. -- Function to update updated_at timestamp
  118. CREATE OR REPLACE FUNCTION update_updated_at_column()
  119. RETURNS TRIGGER AS $$
  120. BEGIN
  121. NEW.updated_at = CURRENT_TIMESTAMP;
  122. RETURN NEW;
  123. END;
  124. $$ language 'plpgsql';
  125. -- Triggers for updated_at
  126. CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
  127. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  128. CREATE TRIGGER update_organizations_updated_at BEFORE UPDATE ON organizations
  129. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  130. CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications
  131. FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
  132. -- Row Level Security (RLS) for multi-tenancy
  133. ALTER TABLE applications ENABLE ROW LEVEL SECURITY;
  134. ALTER TABLE deployments ENABLE ROW LEVEL SECURITY;
  135. ALTER TABLE api_keys ENABLE ROW LEVEL SECURITY;
  136. -- RLS Policies
  137. CREATE POLICY "Users can view applications in their orgs" ON applications
  138. FOR SELECT USING (
  139. organization_id IN (
  140. SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
  141. )
  142. );
  143. CREATE POLICY "Users can insert applications in their orgs" ON applications
  144. FOR INSERT WITH CHECK (
  145. organization_id IN (
  146. SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
  147. )
  148. );
  149. CREATE POLICY "Users can update applications in their orgs" ON applications
  150. FOR UPDATE USING (
  151. organization_id IN (
  152. SELECT organization_id FROM organization_members WHERE user_id = auth.uid()
  153. )
  154. );
  155. -- Create default admin user (password: admin123 - change immediately)
  156. INSERT INTO users (email, password_hash, first_name, last_name, email_verified)
  157. VALUES (
  158. 'admin@saas.local',
  159. '$2b$10$rQO8vV8x8t5QX7O9HJ5Y/uKQ8vV8x8t5QX7O9HJ5Y/uKQ8vV8x8t5Q',
  160. 'Admin',
  161. 'User',
  162. true
  163. ) ON CONFLICT (email) DO NOTHING;
  164. -- Create default organization
  165. INSERT INTO organizations (name, slug, description, created_by)
  166. SELECT 'Default Organization', 'default-org', 'Default organization for getting started', id
  167. FROM users WHERE email = 'admin@saas.local'
  168. ON CONFLICT (slug) DO NOTHING;