Files
tenante-api/sql/tenante_admin.sql
2025-08-11 22:15:32 +02:00

165 lines
6.3 KiB
SQL

-- CREATE DATABASE "tenante_admin_PRD";
-- Drop all tables
DO $$
DECLARE
tabName text;
BEGIN
FOR tabName IN
SELECT tablename
FROM pg_tables
WHERE schemaname = 'public'
LOOP
EXECUTE 'DROP TABLE IF EXISTS public."' || tabName || '" CASCADE';
END LOOP;
END $$;
-- Install uuid extension
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Create the ORGANIZATION table
CREATE TABLE IF NOT EXISTS "organization" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL UNIQUE,
slug TEXT NOT NULL UNIQUE,
"ssoConfigurationId" UUID,
"ssoDomain" UUID,
"ssoEnabled" BOOLEAN NOT NULL DEFAULT FALSE,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ
);
-- Create the PROJECT table
CREATE TABLE IF NOT EXISTS "project" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL,
slug TEXT NOT NULL,
description TEXT,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ,
"organizationId" UUID REFERENCES organization(id) ON DELETE CASCADE,
CONSTRAINT unique_name_per_org UNIQUE ("organizationId", name),
CONSTRAINT unique_slug_per_org UNIQUE ("organizationId", slug)
);
-- Create the USER table
CREATE TABLE IF NOT EXISTS "user" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"firstName" TEXT NOT NULL,
"lastName" TEXT NOT NULL,
"displayName" TEXT NOT NULL,
"username" TEXT NOT NULL UNIQUE,
"email" TEXT NOT NULL UNIQUE,
"password" TEXT NOT NULL,
"verified" BOOLEAN NOT NULL DEFAULT FALSE,
"verifiedAt" TIMESTAMPTZ,
"enabled" BOOLEAN NOT NULL DEFAULT TRUE,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ
);
-- Create the ACCOUNT table
CREATE TABLE IF NOT EXISTS "account" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"userId" UUID REFERENCES "user"(id) ON DELETE CASCADE,
"provider" TEXT NOT NULL,
"providerAccountId" TEXT NOT NULL,
"refreshToken" TEXT,
"accessToken" TEXT NOT NULL,
"accessTokenExpires" TIMESTAMPTZ NOT NULL,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ,
CONSTRAINT unique_provider_per_user UNIQUE ("userId", "provider"),
CONSTRAINT unique_provider_account_per_user UNIQUE ("userId", "provider", "providerAccountId")
);
-- Create the MFA table to store MFA data
CREATE TABLE IF NOT EXISTS "mfa" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"userId" UUID REFERENCES "user"(id) ON DELETE CASCADE,
"secret" TEXT NOT NULL UNIQUE,
"enabled" BOOLEAN NOT NULL DEFAULT TRUE,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create ENUM for user roles
DROP TYPE IF EXISTS "user_role" CASCADE;
CREATE TYPE "user_role" AS ENUM ('owner', 'admin', 'member', 'guest');
-- Create the PROJECT_USER table to link users to projects and assign roles
CREATE TABLE IF NOT EXISTS "project_user" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"userId" UUID REFERENCES "user"(id) ON DELETE CASCADE,
"projectId" UUID REFERENCES "project"(id) ON DELETE CASCADE,
"role" "user_role" NOT NULL DEFAULT 'guest',
"createdBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"updatedBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"deletedBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ,
CONSTRAINT unique_user_per_project UNIQUE ("userId", "projectId"),
CONSTRAINT unique_role_per_user_per_project UNIQUE ("userId", "projectId", "role")
);
-- Create the APP table to link apps to projects and assign roles
CREATE TABLE IF NOT EXISTS "app" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name TEXT NOT NULL,
slug TEXT NOT NULL,
description TEXT,
"projectId" UUID REFERENCES "project"(id) ON DELETE CASCADE,
"createdBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"updatedBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"deletedBy" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ,
CONSTRAINT unique_name_per_project UNIQUE ("projectId", name),
CONSTRAINT unique_slug_per_project UNIQUE ("projectId", slug)
);
DROP TYPE IF EXISTS "user_audit_action" CASCADE;
CREATE TYPE "user_audit_action" AS ENUM ('login', 'password_change', 'reset_password', '2fa_enable', '2fa_disable', '2fa_generate_backup', 'request_deletion', 'stop_deletion');
-- Create USER_AUDIT table (to log any user changes and activities e.g., login attempts, password changes, 2FA changes
CREATE TABLE IF NOT EXISTS "user_audit" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"action" "user_audit_action" NOT NULL DEFAULT 'login',
"ipAddress" TEXT NOT NULL,
"userAgent" TEXT NOT NULL,
"appId" UUID REFERENCES "app"(id) ON DELETE SET NULL,
"userId" UUID REFERENCES "user"(id) ON DELETE CASCADE,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"deletedAt" TIMESTAMPTZ
);
-- Create the SESSION table to save session data
CREATE TABLE IF NOT EXISTS "session" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
"userId" UUID REFERENCES "user"(id) ON DELETE CASCADE,
"ipAddress" TEXT NOT NULL,
"userAgent" TEXT NOT NULL,
"refreshToken" TEXT NOT NULL,
"appId" UUID REFERENCES "app"(id) ON DELETE SET NULL,
"expiresAt" TIMESTAMPTZ NOT NULL,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW()
);
-- Create the EVENT table to save webhook data and more
CREATE TABLE IF NOT EXISTS "event" (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
type TEXT NOT NULL,
payload JSONB NOT NULL DEFAULT '{}',
"appId" UUID REFERENCES "app"(id) ON DELETE SET NULL,
"userId" UUID REFERENCES "user"(id) ON DELETE SET NULL,
"createdAt" TIMESTAMPTZ NOT NULL DEFAULT NOW(),
"updatedAt" TIMESTAMPTZ NOT NULL DEFAULT NOW()
);