Files
skybridge/kms/migrations/001_initial_schema.up.sql
2025-08-26 19:16:41 -04:00

170 lines
8.2 KiB
PL/PgSQL

-- Migration: 001_initial_schema
-- Create initial database schema for API Key Management Service
-- Enable UUID extension
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Applications table
CREATE TABLE applications (
app_id VARCHAR(255) PRIMARY KEY,
app_link VARCHAR(500) NOT NULL,
type TEXT[] NOT NULL CHECK (array_length(type, 1) > 0),
callback_url VARCHAR(500) NOT NULL,
hmac_key VARCHAR(255) NOT NULL,
token_renewal_duration BIGINT NOT NULL, -- Duration in nanoseconds
max_token_duration BIGINT NOT NULL, -- Duration in nanoseconds
owner_type VARCHAR(20) NOT NULL CHECK (owner_type IN ('individual', 'team')),
owner_name VARCHAR(255) NOT NULL,
owner_owner VARCHAR(255) NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create index for applications
CREATE INDEX idx_applications_owner_type ON applications(owner_type);
CREATE INDEX idx_applications_created_at ON applications(created_at);
-- Available permissions table (global catalog)
CREATE TABLE available_permissions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
scope VARCHAR(255) UNIQUE NOT NULL,
name VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
category VARCHAR(100) NOT NULL,
parent_scope VARCHAR(255) REFERENCES available_permissions(scope) ON DELETE SET NULL,
is_system BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by VARCHAR(255) NOT NULL,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_by VARCHAR(255) NOT NULL
);
-- Create indexes for available permissions
CREATE INDEX idx_available_permissions_scope ON available_permissions(scope);
CREATE INDEX idx_available_permissions_category ON available_permissions(category);
CREATE INDEX idx_available_permissions_parent_scope ON available_permissions(parent_scope);
CREATE INDEX idx_available_permissions_is_system ON available_permissions(is_system);
-- Static tokens table
CREATE TABLE static_tokens (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
app_id VARCHAR(255) NOT NULL REFERENCES applications(app_id) ON DELETE CASCADE,
owner_type VARCHAR(20) NOT NULL CHECK (owner_type IN ('individual', 'team')),
owner_name VARCHAR(255) NOT NULL,
owner_owner VARCHAR(255) NOT NULL,
key_hash VARCHAR(255) NOT NULL UNIQUE, -- Store hashed key for security
type VARCHAR(20) NOT NULL CHECK (type = 'hmac'),
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW()
);
-- Create indexes for static tokens
CREATE INDEX idx_static_tokens_app_id ON static_tokens(app_id);
CREATE INDEX idx_static_tokens_key_hash ON static_tokens(key_hash);
CREATE INDEX idx_static_tokens_created_at ON static_tokens(created_at);
-- Granted permissions table (links tokens to permissions)
CREATE TABLE granted_permissions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
token_type VARCHAR(20) NOT NULL CHECK (token_type = 'static'),
token_id UUID NOT NULL REFERENCES static_tokens(id) ON DELETE CASCADE,
permission_id UUID NOT NULL REFERENCES available_permissions(id) ON DELETE CASCADE,
scope VARCHAR(255) NOT NULL, -- Denormalized for fast reads
created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(),
created_by VARCHAR(255) NOT NULL,
revoked BOOLEAN DEFAULT FALSE,
-- Ensure unique permission per token
UNIQUE(token_type, token_id, permission_id)
);
-- Create indexes for granted permissions
CREATE INDEX idx_granted_permissions_token ON granted_permissions(token_type, token_id);
CREATE INDEX idx_granted_permissions_permission_id ON granted_permissions(permission_id);
CREATE INDEX idx_granted_permissions_scope ON granted_permissions(scope);
CREATE INDEX idx_granted_permissions_revoked ON granted_permissions(revoked);
-- Create trigger for updating updated_at timestamps
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = NOW();
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
-- Apply triggers to tables that have updated_at
CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_static_tokens_updated_at BEFORE UPDATE ON static_tokens
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_available_permissions_updated_at BEFORE UPDATE ON available_permissions
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
-- Insert initial system permissions
INSERT INTO available_permissions (scope, name, description, category, is_system, created_by, updated_by) VALUES
-- Internal application management
('internal', 'Internal System Access', 'Full access to internal system operations', 'system', true, 'system', 'system'),
('internal.read', 'Internal Read Access', 'Read access to internal system data', 'system', true, 'system', 'system'),
('internal.write', 'Internal Write Access', 'Write access to internal system data', 'system', true, 'system', 'system'),
('internal.admin', 'Internal Admin Access', 'Administrative access to internal system', 'system', true, 'system', 'system'),
-- Application management
('app', 'Application Access', 'Access to application management', 'application', false, 'system', 'system'),
('app.read', 'Application Read', 'Read application information', 'application', false, 'system', 'system'),
('app.write', 'Application Write', 'Create and update applications', 'application', false, 'system', 'system'),
('app.delete', 'Application Delete', 'Delete applications', 'application', false, 'system', 'system'),
-- Token management
('token', 'Token Access', 'Access to token management', 'token', false, 'system', 'system'),
('token.read', 'Token Read', 'Read token information', 'token', false, 'system', 'system'),
('token.create', 'Token Create', 'Create new tokens', 'token', false, 'system', 'system'),
('token.revoke', 'Token Revoke', 'Revoke existing tokens', 'token', false, 'system', 'system'),
-- Permission management
('permission', 'Permission Access', 'Access to permission management', 'permission', false, 'system', 'system'),
('permission.read', 'Permission Read', 'Read permission information', 'permission', false, 'system', 'system'),
('permission.write', 'Permission Write', 'Create and update permissions', 'permission', false, 'system', 'system'),
('permission.grant', 'Permission Grant', 'Grant permissions to tokens', 'permission', false, 'system', 'system'),
('permission.revoke', 'Permission Revoke', 'Revoke permissions from tokens', 'permission', false, 'system', 'system'),
-- Repository access (example permissions)
('repo', 'Repository Access', 'Access to repository operations', 'repository', false, 'system', 'system'),
('repo.read', 'Repository Read', 'Read repository data', 'repository', false, 'system', 'system'),
('repo.write', 'Repository Write', 'Write to repositories', 'repository', false, 'system', 'system'),
('repo.admin', 'Repository Admin', 'Administrative access to repositories', 'repository', false, 'system', 'system');
-- Set up parent-child relationships for hierarchical permissions
UPDATE available_permissions SET parent_scope = 'internal' WHERE scope IN ('internal.read', 'internal.write', 'internal.admin');
UPDATE available_permissions SET parent_scope = 'app' WHERE scope IN ('app.read', 'app.write', 'app.delete');
UPDATE available_permissions SET parent_scope = 'token' WHERE scope IN ('token.read', 'token.create', 'token.revoke');
UPDATE available_permissions SET parent_scope = 'permission' WHERE scope IN ('permission.read', 'permission.write', 'permission.grant', 'permission.revoke');
UPDATE available_permissions SET parent_scope = 'repo' WHERE scope IN ('repo.read', 'repo.write', 'repo.admin');
-- Insert the internal application (for bootstrapping)
INSERT INTO applications (
app_id,
app_link,
type,
callback_url,
hmac_key,
token_renewal_duration,
max_token_duration,
owner_type,
owner_name,
owner_owner
) VALUES (
'internal.api-key-service',
'http://localhost:8080',
ARRAY['static'],
'http://localhost:8080/auth/callback',
'bootstrap-hmac-key-change-in-production',
604800000000000, -- 7 days in nanoseconds
2592000000000000, -- 30 days in nanoseconds
'team',
'API Key Service',
'system'
);