Skip to content

Commit

Permalink
Third party devs init
Browse files Browse the repository at this point in the history
  • Loading branch information
AnthonyRonning committed Feb 3, 2025
1 parent b56e901 commit e139089
Show file tree
Hide file tree
Showing 15 changed files with 1,902 additions and 1 deletion.
15 changes: 15 additions & 0 deletions migrations/2025-01-20-223225_third_party_devs/down.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,15 @@
-- Drop triggers first
DROP TRIGGER IF EXISTS update_org_project_secrets_updated_at ON org_project_secrets;
DROP TRIGGER IF EXISTS update_org_projects_updated_at ON org_projects;
DROP TRIGGER IF EXISTS update_org_users_updated_at ON org_users;
DROP TRIGGER IF EXISTS update_orgs_updated_at ON orgs;

-- Drop tables in reverse order of creation (to handle foreign key dependencies)
DROP TABLE IF EXISTS org_project_secrets;
DROP TABLE IF EXISTS org_projects;
DROP TABLE IF EXISTS org_users;
DROP TABLE IF EXISTS invite_codes;
DROP TABLE IF EXISTS orgs;

-- Drop the trigger function
DROP FUNCTION IF EXISTS update_updated_at_column();
120 changes: 120 additions & 0 deletions migrations/2025-01-20-223225_third_party_devs/up.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,120 @@
-- Create organizations table
CREATE TABLE orgs (
id SERIAL PRIMARY KEY,
uuid UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
name TEXT NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
);

-- Create organization users table (for developers/admins of organizations)
CREATE TABLE org_users (
id SERIAL PRIMARY KEY,
uuid UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
org_id INTEGER NOT NULL REFERENCES orgs(id) ON DELETE CASCADE,
email TEXT NOT NULL,
name TEXT,
password_enc BYTEA,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE(org_id, email)
);

-- Create organization projects table
CREATE TABLE org_projects (
id SERIAL PRIMARY KEY,
uuid UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
client_id UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
org_id INTEGER NOT NULL REFERENCES orgs(id) ON DELETE CASCADE,
name TEXT NOT NULL,
description TEXT,
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'inactive', 'suspended')),
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE(org_id, name)
);

-- Create project secrets table for storing encrypted API keys, OAuth secrets, etc.
CREATE TABLE org_project_secrets (
id SERIAL PRIMARY KEY,
project_id INTEGER NOT NULL REFERENCES org_projects(id) ON DELETE CASCADE,
key_name TEXT NOT NULL,
secret_enc BYTEA NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
UNIQUE(project_id, key_name) -- Each key name should be unique per project
);

-- Create invite codes table for organization user invitations
CREATE TABLE invite_codes (
id SERIAL PRIMARY KEY,
code UUID NOT NULL DEFAULT uuid_generate_v4() UNIQUE,
org_id INTEGER NOT NULL REFERENCES orgs(id) ON DELETE CASCADE,
email TEXT NOT NULL,
used BOOLEAN NOT NULL DEFAULT false,
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT CURRENT_TIMESTAMP
);

-- Add indexes for foreign keys and commonly queried fields
CREATE INDEX idx_org_users_org_id ON org_users(org_id);
CREATE INDEX idx_org_users_email ON org_users(email);
CREATE INDEX idx_org_projects_org_id ON org_projects(org_id);
CREATE INDEX idx_org_projects_client_id ON org_projects(client_id);
CREATE INDEX idx_org_project_secrets_project_id ON org_project_secrets(project_id);
CREATE INDEX idx_invite_codes_org_id ON invite_codes(org_id);
CREATE INDEX idx_invite_codes_code ON invite_codes(code);
CREATE INDEX idx_invite_codes_email ON invite_codes(email);

-- Create updated_at triggers
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';

CREATE TRIGGER update_orgs_updated_at
BEFORE UPDATE ON orgs
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

CREATE TRIGGER update_org_users_updated_at
BEFORE UPDATE ON org_users
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

CREATE TRIGGER update_org_projects_updated_at
BEFORE UPDATE ON org_projects
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

CREATE TRIGGER update_org_project_secrets_updated_at
BEFORE UPDATE ON org_project_secrets
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

CREATE TRIGGER update_invite_codes_updated_at
BEFORE UPDATE ON invite_codes
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();

-- Create a default "OpenSecret" organization and "Maple" project for existing data
INSERT INTO orgs (name) VALUES ('OpenSecret');

-- Create the Maple project under OpenSecret organization
INSERT INTO org_projects (
org_id,
name,
description,
status
)
SELECT
id,
'Maple',
'TryMaple Project',
'active'
FROM orgs
WHERE name = 'OpenSecret';
Loading

0 comments on commit e139089

Please sign in to comment.