852 lines
27 KiB
Markdown
852 lines
27 KiB
Markdown
# KMS Database Schema Documentation
|
|
|
|
## Table of Contents
|
|
1. [Schema Overview](#schema-overview)
|
|
2. [Entity Relationship Diagram](#entity-relationship-diagram)
|
|
3. [Table Definitions](#table-definitions)
|
|
4. [Relationships and Constraints](#relationships-and-constraints)
|
|
5. [Indexes and Performance](#indexes-and-performance)
|
|
6. [Security Considerations](#security-considerations)
|
|
7. [Migration Strategy](#migration-strategy)
|
|
8. [Query Patterns](#query-patterns)
|
|
|
|
---
|
|
|
|
## Schema Overview
|
|
|
|
The KMS database schema is designed around core entities that manage applications, tokens, permissions, and user sessions. The schema follows PostgreSQL best practices with proper normalization, constraints, and indexing strategies.
|
|
|
|
### Core Entities
|
|
- **Applications**: Central configuration for API key management
|
|
- **Static Tokens**: Long-lived API tokens with HMAC signatures
|
|
- **User Sessions**: JWT token tracking with metadata
|
|
- **Available Permissions**: Hierarchical permission catalog
|
|
- **Granted Permissions**: Token-permission relationships
|
|
- **Audit Logs**: Complete audit trail of all operations
|
|
|
|
### Design Principles
|
|
- **Normalized Design**: Reduces data redundancy
|
|
- **Referential Integrity**: Foreign key constraints ensure consistency
|
|
- **Audit Trail**: Complete history of all operations
|
|
- **Performance Optimized**: Strategic indexing for common queries
|
|
- **Security First**: Sensitive data protection and access controls
|
|
|
|
---
|
|
|
|
## Entity Relationship Diagram
|
|
|
|
```mermaid
|
|
erDiagram
|
|
%% Core Application Entity
|
|
applications {
|
|
string app_id PK "Application identifier"
|
|
string app_link "Application URL"
|
|
text[] type "static|user application types"
|
|
string callback_url "OAuth2 callback URL"
|
|
string hmac_key "HMAC signing key"
|
|
string token_prefix "Custom token prefix"
|
|
bigint token_renewal_duration "Token renewal window (ns)"
|
|
bigint max_token_duration "Max token lifetime (ns)"
|
|
string owner_type "individual|team"
|
|
string owner_name "Owner display name"
|
|
string owner_owner "Owner identifier"
|
|
timestamp created_at
|
|
timestamp updated_at
|
|
}
|
|
|
|
%% Static Token Management
|
|
static_tokens {
|
|
uuid id PK
|
|
string app_id FK "References applications.app_id"
|
|
string owner_type "individual|team"
|
|
string owner_name "Token owner name"
|
|
string owner_owner "Token owner identifier"
|
|
string key_hash "BCrypt hashed token (cost 14)"
|
|
string type "Always 'hmac'"
|
|
timestamp created_at
|
|
timestamp updated_at
|
|
}
|
|
|
|
%% User Session Tracking
|
|
user_sessions {
|
|
uuid id PK
|
|
string user_id "User identifier"
|
|
string app_id FK "References applications.app_id"
|
|
string session_token "Hashed session identifier"
|
|
text permissions "JSON array of permissions"
|
|
timestamp expires_at "Session expiration"
|
|
timestamp max_valid_at "Maximum validity window"
|
|
string provider "header|jwt|oauth2|saml"
|
|
json metadata "Provider-specific data"
|
|
boolean active "Session status"
|
|
timestamp created_at
|
|
timestamp updated_at
|
|
timestamp last_used_at
|
|
}
|
|
|
|
%% Permission Catalog
|
|
available_permissions {
|
|
uuid id PK
|
|
string scope UK "Unique permission scope"
|
|
string name "Human-readable name"
|
|
text description "Permission description"
|
|
string category "Permission category"
|
|
string parent_scope FK "References available_permissions.scope"
|
|
boolean is_system "System permission flag"
|
|
timestamp created_at
|
|
string created_by "Creator identifier"
|
|
timestamp updated_at
|
|
string updated_by "Last updater"
|
|
}
|
|
|
|
%% Token-Permission Relationships
|
|
granted_permissions {
|
|
uuid id PK
|
|
string token_type "static|user"
|
|
uuid token_id FK "References static_tokens.id"
|
|
uuid permission_id FK "References available_permissions.id"
|
|
string scope "Denormalized permission scope"
|
|
timestamp created_at
|
|
string created_by "Grant creator"
|
|
boolean revoked "Permission revocation status"
|
|
timestamp revoked_at "Revocation timestamp"
|
|
string revoked_by "Revoker identifier"
|
|
}
|
|
|
|
%% Audit Trail
|
|
audit_logs {
|
|
uuid id PK
|
|
timestamp timestamp "Event timestamp"
|
|
string user_id "Acting user"
|
|
string action "Action performed"
|
|
string resource_type "Resource type affected"
|
|
string resource_id "Resource identifier"
|
|
json old_values "Previous values"
|
|
json new_values "New values"
|
|
string ip_address "Client IP"
|
|
string user_agent "Client user agent"
|
|
json metadata "Additional context"
|
|
}
|
|
|
|
%% Relationships
|
|
applications ||--o{ static_tokens : "app_id"
|
|
applications ||--o{ user_sessions : "app_id"
|
|
available_permissions ||--o{ available_permissions : "parent_scope"
|
|
available_permissions ||--o{ granted_permissions : "permission_id"
|
|
static_tokens ||--o{ granted_permissions : "token_id"
|
|
|
|
%% Indexes and Constraints
|
|
applications {
|
|
index idx_applications_owner_type "owner_type"
|
|
index idx_applications_created_at "created_at"
|
|
check owner_type_valid "owner_type IN ('individual', 'team')"
|
|
check type_not_empty "array_length(type, 1) > 0"
|
|
}
|
|
|
|
static_tokens {
|
|
index idx_static_tokens_app_id "app_id"
|
|
index idx_static_tokens_key_hash "key_hash"
|
|
unique key_hash_unique "key_hash"
|
|
check type_hmac "type = 'hmac'"
|
|
}
|
|
|
|
user_sessions {
|
|
index idx_user_sessions_user_id "user_id"
|
|
index idx_user_sessions_app_id "app_id"
|
|
index idx_user_sessions_token "session_token"
|
|
index idx_user_sessions_expires_at "expires_at"
|
|
index idx_user_sessions_active "active"
|
|
}
|
|
|
|
available_permissions {
|
|
index idx_available_permissions_scope "scope"
|
|
index idx_available_permissions_category "category"
|
|
index idx_available_permissions_parent_scope "parent_scope"
|
|
index idx_available_permissions_is_system "is_system"
|
|
}
|
|
|
|
granted_permissions {
|
|
index idx_granted_permissions_token "token_type, token_id"
|
|
index idx_granted_permissions_permission_id "permission_id"
|
|
index idx_granted_permissions_scope "scope"
|
|
index idx_granted_permissions_revoked "revoked"
|
|
unique token_permission_unique "token_type, token_id, permission_id"
|
|
}
|
|
```
|
|
|
|
---
|
|
|
|
## Table Definitions
|
|
|
|
### Applications Table
|
|
|
|
The central configuration table for all applications in the system.
|
|
|
|
```sql
|
|
CREATE TABLE applications (
|
|
app_id VARCHAR(100) PRIMARY KEY,
|
|
app_link TEXT NOT NULL,
|
|
type TEXT[] NOT NULL DEFAULT '{}',
|
|
callback_url TEXT,
|
|
hmac_key TEXT NOT NULL,
|
|
token_prefix VARCHAR(10),
|
|
token_renewal_duration BIGINT NOT NULL DEFAULT 3600000000000, -- 1 hour in nanoseconds
|
|
max_token_duration BIGINT NOT NULL DEFAULT 86400000000000, -- 24 hours 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 NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
|
|
-- Constraints
|
|
CONSTRAINT app_id_format CHECK (app_id ~ '^[a-zA-Z0-9][a-zA-Z0-9._-]*[a-zA-Z0-9]$'),
|
|
CONSTRAINT type_not_empty CHECK (array_length(type, 1) > 0),
|
|
CONSTRAINT token_prefix_format CHECK (token_prefix IS NULL OR token_prefix ~ '^[A-Z]{2,4}$'),
|
|
CONSTRAINT valid_durations CHECK (
|
|
token_renewal_duration > 0 AND
|
|
max_token_duration > 0 AND
|
|
max_token_duration > token_renewal_duration
|
|
)
|
|
);
|
|
```
|
|
|
|
#### Field Descriptions
|
|
- **`app_id`**: Unique application identifier, must follow naming conventions
|
|
- **`app_link`**: URL to the application for reference
|
|
- **`type`**: Array of supported token types (`static`, `user`)
|
|
- **`callback_url`**: OAuth2/SAML callback URL for authentication flows
|
|
- **`hmac_key`**: HMAC signing key for static token validation
|
|
- **`token_prefix`**: Custom prefix for generated tokens (2-4 uppercase letters)
|
|
- **`token_renewal_duration`**: How long tokens can be renewed (nanoseconds)
|
|
- **`max_token_duration`**: Maximum token lifetime (nanoseconds)
|
|
- **`owner_type`**: Individual or team ownership
|
|
- **`owner_name`**: Display name of the owner
|
|
- **`owner_owner`**: Identifier of the owner (email for individual, team ID for team)
|
|
|
|
### Static Tokens Table
|
|
|
|
Long-lived API tokens with HMAC-based authentication.
|
|
|
|
```sql
|
|
CREATE TABLE static_tokens (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
app_id VARCHAR(100) 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 TEXT NOT NULL UNIQUE,
|
|
type VARCHAR(10) NOT NULL DEFAULT 'hmac' CHECK (type = 'hmac'),
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW()
|
|
);
|
|
```
|
|
|
|
#### Security Features
|
|
- **`key_hash`**: BCrypt hash of the actual token (cost 14)
|
|
- **Unique constraint**: Prevents token duplication
|
|
- **Cascade deletion**: Tokens deleted when application is removed
|
|
- **Owner tracking**: Links tokens to their creators
|
|
|
|
### User Sessions Table
|
|
|
|
JWT token session tracking with comprehensive metadata.
|
|
|
|
```sql
|
|
CREATE TABLE user_sessions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
user_id VARCHAR(255) NOT NULL,
|
|
app_id VARCHAR(100) NOT NULL REFERENCES applications(app_id) ON DELETE CASCADE,
|
|
session_token VARCHAR(255) NOT NULL,
|
|
permissions TEXT NOT NULL DEFAULT '[]', -- JSON array
|
|
expires_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
max_valid_at TIMESTAMP WITH TIME ZONE NOT NULL,
|
|
provider VARCHAR(20) NOT NULL CHECK (provider IN ('header', 'jwt', 'oauth2', 'saml')),
|
|
metadata JSONB DEFAULT '{}',
|
|
active BOOLEAN NOT NULL DEFAULT true,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
last_used_at TIMESTAMP WITH TIME ZONE,
|
|
|
|
-- Constraints
|
|
CONSTRAINT valid_session_times CHECK (max_valid_at >= expires_at),
|
|
CONSTRAINT valid_permissions CHECK (permissions::json IS NOT NULL)
|
|
);
|
|
```
|
|
|
|
#### Session Management Features
|
|
- **Session tracking**: Complete session lifecycle management
|
|
- **Multi-provider support**: Tracks authentication method
|
|
- **Permission storage**: JSON array of granted permissions
|
|
- **Activity tracking**: Last used timestamp for session cleanup
|
|
- **Flexible metadata**: Provider-specific data storage
|
|
|
|
### Available Permissions Table
|
|
|
|
Hierarchical permission catalog with system and custom permissions.
|
|
|
|
```sql
|
|
CREATE TABLE available_permissions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
scope VARCHAR(255) NOT NULL UNIQUE,
|
|
name VARCHAR(255) NOT NULL,
|
|
description TEXT,
|
|
category VARCHAR(100) NOT NULL DEFAULT 'custom',
|
|
parent_scope VARCHAR(255) REFERENCES available_permissions(scope) ON DELETE SET NULL,
|
|
is_system BOOLEAN NOT NULL DEFAULT false,
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL,
|
|
updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
updated_by VARCHAR(255) NOT NULL,
|
|
|
|
-- Constraints
|
|
CONSTRAINT scope_format CHECK (scope ~ '^[a-zA-Z][a-zA-Z0-9._]*[a-zA-Z0-9]$'),
|
|
CONSTRAINT no_self_reference CHECK (scope != parent_scope)
|
|
);
|
|
```
|
|
|
|
#### Permission Hierarchy Features
|
|
- **Hierarchical structure**: Parent-child permission relationships
|
|
- **System permissions**: Built-in permissions that cannot be deleted
|
|
- **Flexible scoping**: Dot-notation permission scopes
|
|
- **Audit tracking**: Creation and modification history
|
|
|
|
### Granted Permissions Table
|
|
|
|
Token-permission relationship management with revocation support.
|
|
|
|
```sql
|
|
CREATE TABLE granted_permissions (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
token_type VARCHAR(10) NOT NULL CHECK (token_type IN ('static', 'user')),
|
|
token_id UUID NOT NULL,
|
|
permission_id UUID NOT NULL REFERENCES available_permissions(id) ON DELETE CASCADE,
|
|
scope VARCHAR(255) NOT NULL, -- Denormalized for performance
|
|
created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
created_by VARCHAR(255) NOT NULL,
|
|
revoked BOOLEAN NOT NULL DEFAULT false,
|
|
revoked_at TIMESTAMP WITH TIME ZONE,
|
|
revoked_by VARCHAR(255),
|
|
|
|
-- Constraints
|
|
CONSTRAINT unique_token_permission UNIQUE (token_type, token_id, permission_id),
|
|
CONSTRAINT valid_revocation CHECK (
|
|
(revoked = false AND revoked_at IS NULL AND revoked_by IS NULL) OR
|
|
(revoked = true AND revoked_at IS NOT NULL AND revoked_by IS NOT NULL)
|
|
)
|
|
);
|
|
```
|
|
|
|
#### Permission Grant Features
|
|
- **Multi-token support**: Works with both static and user tokens
|
|
- **Denormalized scope**: Performance optimization for common queries
|
|
- **Revocation tracking**: Complete audit trail of permission changes
|
|
- **Referential integrity**: Maintains consistency with permission catalog
|
|
|
|
### Audit Logs Table
|
|
|
|
Complete audit trail of all system operations.
|
|
|
|
```sql
|
|
CREATE TABLE audit_logs (
|
|
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
|
timestamp TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(),
|
|
user_id VARCHAR(255) NOT NULL,
|
|
action VARCHAR(100) NOT NULL,
|
|
resource_type VARCHAR(50) NOT NULL,
|
|
resource_id VARCHAR(255),
|
|
old_values JSONB,
|
|
new_values JSONB,
|
|
ip_address INET,
|
|
user_agent TEXT,
|
|
metadata JSONB DEFAULT '{}',
|
|
|
|
-- Constraints
|
|
CONSTRAINT valid_action CHECK (action ~ '^[a-z][a-z_]*[a-z]$'),
|
|
CONSTRAINT valid_resource_type CHECK (resource_type ~ '^[a-z][a-z_]*[a-z]$')
|
|
);
|
|
```
|
|
|
|
#### Audit Features
|
|
- **Complete coverage**: All operations logged
|
|
- **Before/after values**: Full change tracking
|
|
- **Client context**: IP address and user agent
|
|
- **Flexible metadata**: Additional context storage
|
|
- **Time-series data**: Ordered by timestamp for analysis
|
|
|
|
---
|
|
|
|
## Relationships and Constraints
|
|
|
|
### Primary Relationships
|
|
|
|
#### **Application → Static Tokens (1:N)**
|
|
```sql
|
|
ALTER TABLE static_tokens
|
|
ADD CONSTRAINT fk_static_tokens_app_id
|
|
FOREIGN KEY (app_id) REFERENCES applications(app_id) ON DELETE CASCADE;
|
|
```
|
|
|
|
#### **Application → User Sessions (1:N)**
|
|
```sql
|
|
ALTER TABLE user_sessions
|
|
ADD CONSTRAINT fk_user_sessions_app_id
|
|
FOREIGN KEY (app_id) REFERENCES applications(app_id) ON DELETE CASCADE;
|
|
```
|
|
|
|
#### **Available Permissions → Self (Hierarchy)**
|
|
```sql
|
|
ALTER TABLE available_permissions
|
|
ADD CONSTRAINT fk_available_permissions_parent
|
|
FOREIGN KEY (parent_scope) REFERENCES available_permissions(scope) ON DELETE SET NULL;
|
|
```
|
|
|
|
#### **Granted Permissions → Available Permissions (N:1)**
|
|
```sql
|
|
ALTER TABLE granted_permissions
|
|
ADD CONSTRAINT fk_granted_permissions_permission
|
|
FOREIGN KEY (permission_id) REFERENCES available_permissions(id) ON DELETE CASCADE;
|
|
```
|
|
|
|
### Data Integrity Constraints
|
|
|
|
#### **Check Constraints**
|
|
```sql
|
|
-- Application ID format validation
|
|
ALTER TABLE applications
|
|
ADD CONSTRAINT app_id_format
|
|
CHECK (app_id ~ '^[a-zA-Z0-9][a-zA-Z0-9._-]*[a-zA-Z0-9]$');
|
|
|
|
-- Owner type validation
|
|
ALTER TABLE applications
|
|
ADD CONSTRAINT owner_type_valid
|
|
CHECK (owner_type IN ('individual', 'team'));
|
|
|
|
-- Token type validation
|
|
ALTER TABLE static_tokens
|
|
ADD CONSTRAINT type_hmac
|
|
CHECK (type = 'hmac');
|
|
|
|
-- Permission scope format
|
|
ALTER TABLE available_permissions
|
|
ADD CONSTRAINT scope_format
|
|
CHECK (scope ~ '^[a-zA-Z][a-zA-Z0-9._]*[a-zA-Z0-9]$');
|
|
|
|
-- Session time validation
|
|
ALTER TABLE user_sessions
|
|
ADD CONSTRAINT valid_session_times
|
|
CHECK (max_valid_at >= expires_at);
|
|
```
|
|
|
|
#### **Unique Constraints**
|
|
```sql
|
|
-- Unique token hashes
|
|
ALTER TABLE static_tokens
|
|
ADD CONSTRAINT key_hash_unique UNIQUE (key_hash);
|
|
|
|
-- Unique permission scopes
|
|
ALTER TABLE available_permissions
|
|
ADD CONSTRAINT scope_unique UNIQUE (scope);
|
|
|
|
-- Unique token-permission relationships
|
|
ALTER TABLE granted_permissions
|
|
ADD CONSTRAINT unique_token_permission
|
|
UNIQUE (token_type, token_id, permission_id);
|
|
```
|
|
|
|
---
|
|
|
|
## Indexes and Performance
|
|
|
|
### Primary Indexes
|
|
|
|
#### **Applications Table**
|
|
```sql
|
|
-- Primary key index (automatic)
|
|
CREATE INDEX idx_applications_owner_type ON applications(owner_type);
|
|
CREATE INDEX idx_applications_created_at ON applications(created_at);
|
|
CREATE INDEX idx_applications_owner_owner ON applications(owner_owner);
|
|
```
|
|
|
|
#### **Static Tokens Table**
|
|
```sql
|
|
-- Foreign key and lookup indexes
|
|
CREATE INDEX idx_static_tokens_app_id ON static_tokens(app_id);
|
|
CREATE INDEX idx_static_tokens_key_hash ON static_tokens(key_hash); -- For token verification
|
|
CREATE INDEX idx_static_tokens_created_at ON static_tokens(created_at);
|
|
CREATE INDEX idx_static_tokens_owner_owner ON static_tokens(owner_owner);
|
|
```
|
|
|
|
#### **User Sessions Table**
|
|
```sql
|
|
-- Session lookup indexes
|
|
CREATE INDEX idx_user_sessions_user_id ON user_sessions(user_id);
|
|
CREATE INDEX idx_user_sessions_app_id ON user_sessions(app_id);
|
|
CREATE INDEX idx_user_sessions_token ON user_sessions(session_token);
|
|
CREATE INDEX idx_user_sessions_expires_at ON user_sessions(expires_at);
|
|
CREATE INDEX idx_user_sessions_active ON user_sessions(active);
|
|
|
|
-- Composite index for active session lookup
|
|
CREATE INDEX idx_user_sessions_active_lookup
|
|
ON user_sessions(user_id, app_id, active) WHERE active = true;
|
|
|
|
-- Cleanup index for expired sessions
|
|
CREATE INDEX idx_user_sessions_cleanup
|
|
ON user_sessions(expires_at) WHERE active = true;
|
|
```
|
|
|
|
#### **Available Permissions Table**
|
|
```sql
|
|
-- Permission lookup indexes
|
|
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);
|
|
|
|
-- Hierarchy traversal index
|
|
CREATE INDEX idx_available_permissions_hierarchy
|
|
ON available_permissions(parent_scope, scope);
|
|
```
|
|
|
|
#### **Granted Permissions Table**
|
|
```sql
|
|
-- Token permission lookup
|
|
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);
|
|
|
|
-- Active permissions index
|
|
CREATE INDEX idx_granted_permissions_active
|
|
ON granted_permissions(token_type, token_id, scope) WHERE revoked = false;
|
|
|
|
-- Permission cleanup index
|
|
CREATE INDEX idx_granted_permissions_revoked_at ON granted_permissions(revoked_at);
|
|
```
|
|
|
|
#### **Audit Logs Table**
|
|
```sql
|
|
-- Audit query indexes
|
|
CREATE INDEX idx_audit_logs_timestamp ON audit_logs(timestamp);
|
|
CREATE INDEX idx_audit_logs_user_id ON audit_logs(user_id);
|
|
CREATE INDEX idx_audit_logs_action ON audit_logs(action);
|
|
CREATE INDEX idx_audit_logs_resource ON audit_logs(resource_type, resource_id);
|
|
|
|
-- Time-series partitioning preparation
|
|
CREATE INDEX idx_audit_logs_monthly
|
|
ON audit_logs(date_trunc('month', timestamp), timestamp);
|
|
```
|
|
|
|
### Performance Optimization
|
|
|
|
#### **Partial Indexes**
|
|
```sql
|
|
-- Index only active sessions
|
|
CREATE INDEX idx_active_sessions
|
|
ON user_sessions(user_id, app_id) WHERE active = true;
|
|
|
|
-- Index only non-revoked permissions
|
|
CREATE INDEX idx_active_permissions
|
|
ON granted_permissions(token_id, scope) WHERE revoked = false;
|
|
|
|
-- Index only system permissions
|
|
CREATE INDEX idx_system_permissions
|
|
ON available_permissions(scope, parent_scope) WHERE is_system = true;
|
|
```
|
|
|
|
#### **Composite Indexes**
|
|
```sql
|
|
-- Application ownership queries
|
|
CREATE INDEX idx_applications_ownership
|
|
ON applications(owner_type, owner_owner, created_at);
|
|
|
|
-- Token verification queries
|
|
CREATE INDEX idx_token_verification
|
|
ON static_tokens(app_id, key_hash);
|
|
|
|
-- Permission evaluation queries
|
|
CREATE INDEX idx_permission_evaluation
|
|
ON granted_permissions(token_type, token_id, permission_id, revoked);
|
|
```
|
|
|
|
---
|
|
|
|
## Security Considerations
|
|
|
|
### Data Protection
|
|
|
|
#### **Sensitive Data Handling**
|
|
```sql
|
|
-- HMAC keys should be encrypted at application level
|
|
-- Token hashes use BCrypt with cost 14
|
|
-- Audit logs contain no sensitive data in plaintext
|
|
|
|
-- Row-level security (RLS) for multi-tenant isolation
|
|
ALTER TABLE applications ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE static_tokens ENABLE ROW LEVEL SECURITY;
|
|
ALTER TABLE user_sessions ENABLE ROW LEVEL SECURITY;
|
|
|
|
-- Example RLS policy for application isolation
|
|
CREATE POLICY app_owner_policy ON applications
|
|
FOR ALL TO app_user
|
|
USING (owner_owner = current_setting('app.user_id'));
|
|
```
|
|
|
|
#### **Access Control**
|
|
```sql
|
|
-- Database roles for different access patterns
|
|
CREATE ROLE kms_api_service;
|
|
CREATE ROLE kms_readonly;
|
|
CREATE ROLE kms_admin;
|
|
|
|
-- Grant appropriate permissions
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON applications TO kms_api_service;
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON static_tokens TO kms_api_service;
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON user_sessions TO kms_api_service;
|
|
GRANT SELECT, INSERT, UPDATE, DELETE ON granted_permissions TO kms_api_service;
|
|
GRANT SELECT, INSERT ON audit_logs TO kms_api_service;
|
|
|
|
-- Read-only access for reporting
|
|
GRANT SELECT ON ALL TABLES IN SCHEMA public TO kms_readonly;
|
|
|
|
-- Admin access for maintenance
|
|
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO kms_admin;
|
|
```
|
|
|
|
### Audit and Compliance
|
|
|
|
#### **Audit Triggers**
|
|
```sql
|
|
-- Automatic audit logging trigger
|
|
CREATE OR REPLACE FUNCTION audit_trigger_function()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
INSERT INTO audit_logs (
|
|
user_id, action, resource_type, resource_id,
|
|
old_values, new_values, ip_address
|
|
) VALUES (
|
|
current_setting('app.user_id', true),
|
|
TG_OP,
|
|
TG_TABLE_NAME,
|
|
COALESCE(NEW.id, OLD.id)::text,
|
|
CASE WHEN TG_OP = 'DELETE' THEN row_to_json(OLD) ELSE NULL END,
|
|
CASE WHEN TG_OP = 'INSERT' THEN row_to_json(NEW)
|
|
WHEN TG_OP = 'UPDATE' THEN row_to_json(NEW)
|
|
ELSE NULL END,
|
|
inet_client_addr()
|
|
);
|
|
RETURN COALESCE(NEW, OLD);
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Apply audit trigger to sensitive tables
|
|
CREATE TRIGGER audit_applications
|
|
AFTER INSERT OR UPDATE OR DELETE ON applications
|
|
FOR EACH ROW EXECUTE FUNCTION audit_trigger_function();
|
|
|
|
CREATE TRIGGER audit_static_tokens
|
|
AFTER INSERT OR UPDATE OR DELETE ON static_tokens
|
|
FOR EACH ROW EXECUTE FUNCTION audit_trigger_function();
|
|
|
|
CREATE TRIGGER audit_granted_permissions
|
|
AFTER INSERT OR UPDATE OR DELETE ON granted_permissions
|
|
FOR EACH ROW EXECUTE FUNCTION audit_trigger_function();
|
|
```
|
|
|
|
---
|
|
|
|
## Migration Strategy
|
|
|
|
### Migration Framework
|
|
|
|
The KMS uses a custom Go migration system with the following structure:
|
|
|
|
```
|
|
migrations/
|
|
├── 001_initial_schema.up.sql
|
|
├── 001_initial_schema.down.sql
|
|
├── 002_user_sessions.up.sql
|
|
├── 002_user_sessions.down.sql
|
|
├── 003_add_token_prefix.up.sql
|
|
└── 003_add_token_prefix.down.sql
|
|
```
|
|
|
|
#### **Migration Management**
|
|
```go
|
|
// File: internal/database/migrations.go
|
|
type Migration struct {
|
|
Version int
|
|
Name string
|
|
UpScript string
|
|
DownScript string
|
|
AppliedAt time.Time
|
|
}
|
|
|
|
func RunMigrations(db *sql.DB, migrationsPath string) error {
|
|
// Create migration tracking table
|
|
createMigrationTable(db)
|
|
|
|
// Get applied migrations
|
|
applied, err := getAppliedMigrations(db)
|
|
if err != nil {
|
|
return err
|
|
}
|
|
|
|
// Run pending migrations
|
|
return runPendingMigrations(db, migrationsPath, applied)
|
|
}
|
|
```
|
|
|
|
### Schema Versioning
|
|
|
|
#### **Version Control**
|
|
- **Sequential numbering**: 001, 002, 003...
|
|
- **Descriptive names**: Clear migration purpose
|
|
- **Rollback support**: Down scripts for every migration
|
|
- **Atomic operations**: Each migration in a transaction
|
|
|
|
#### **Migration Best Practices**
|
|
```sql
|
|
-- Always start with BEGIN; and end with COMMIT;
|
|
BEGIN;
|
|
|
|
-- Add new columns with default values
|
|
ALTER TABLE applications
|
|
ADD COLUMN token_prefix VARCHAR(10) DEFAULT NULL;
|
|
|
|
-- Add constraints after data migration
|
|
ALTER TABLE applications
|
|
ADD CONSTRAINT token_prefix_format
|
|
CHECK (token_prefix IS NULL OR token_prefix ~ '^[A-Z]{2,4}$');
|
|
|
|
-- Create indexes concurrently (outside transaction)
|
|
COMMIT;
|
|
|
|
CREATE INDEX CONCURRENTLY idx_applications_token_prefix
|
|
ON applications(token_prefix) WHERE token_prefix IS NOT NULL;
|
|
```
|
|
|
|
---
|
|
|
|
## Query Patterns
|
|
|
|
### Common Query Patterns
|
|
|
|
#### **Application Queries**
|
|
```sql
|
|
-- Get application with ownership check
|
|
SELECT a.* FROM applications a
|
|
WHERE a.app_id = $1
|
|
AND (a.owner_owner = $2 OR $2 = 'admin@example.com');
|
|
|
|
-- List applications for user with pagination
|
|
SELECT a.app_id, a.app_link, a.owner_name, a.created_at
|
|
FROM applications a
|
|
WHERE a.owner_owner = $1
|
|
ORDER BY a.created_at DESC
|
|
LIMIT $2 OFFSET $3;
|
|
```
|
|
|
|
#### **Token Verification Queries**
|
|
```sql
|
|
-- Verify static token
|
|
SELECT st.id, st.app_id, st.key_hash
|
|
FROM static_tokens st
|
|
WHERE st.app_id = $1;
|
|
|
|
-- Get token permissions
|
|
SELECT ap.scope
|
|
FROM granted_permissions gp
|
|
JOIN available_permissions ap ON gp.permission_id = ap.id
|
|
WHERE gp.token_type = 'static'
|
|
AND gp.token_id = $1
|
|
AND gp.revoked = false;
|
|
```
|
|
|
|
#### **Session Management Queries**
|
|
```sql
|
|
-- Get active user session
|
|
SELECT us.* FROM user_sessions us
|
|
WHERE us.user_id = $1
|
|
AND us.app_id = $2
|
|
AND us.active = true
|
|
AND us.expires_at > NOW()
|
|
ORDER BY us.created_at DESC
|
|
LIMIT 1;
|
|
|
|
-- Clean up expired sessions
|
|
UPDATE user_sessions
|
|
SET active = false, updated_at = NOW()
|
|
WHERE active = true
|
|
AND expires_at < NOW();
|
|
```
|
|
|
|
#### **Permission Evaluation Queries**
|
|
```sql
|
|
-- Check user permission
|
|
WITH user_permissions AS (
|
|
SELECT DISTINCT ap.scope
|
|
FROM user_sessions us
|
|
JOIN granted_permissions gp ON gp.token_type = 'user'
|
|
JOIN available_permissions ap ON gp.permission_id = ap.id
|
|
WHERE us.user_id = $1
|
|
AND us.app_id = $2
|
|
AND us.active = true
|
|
AND us.expires_at > NOW()
|
|
AND gp.revoked = false
|
|
)
|
|
SELECT EXISTS(
|
|
SELECT 1 FROM user_permissions
|
|
WHERE scope = $3 OR scope = split_part($3, '.', 1)
|
|
);
|
|
|
|
-- Get permission hierarchy
|
|
WITH RECURSIVE permission_tree AS (
|
|
-- Base case: root permissions
|
|
SELECT id, scope, name, parent_scope, 0 as level
|
|
FROM available_permissions
|
|
WHERE parent_scope IS NULL
|
|
|
|
UNION ALL
|
|
|
|
-- Recursive case: child permissions
|
|
SELECT ap.id, ap.scope, ap.name, ap.parent_scope, pt.level + 1
|
|
FROM available_permissions ap
|
|
JOIN permission_tree pt ON ap.parent_scope = pt.scope
|
|
)
|
|
SELECT * FROM permission_tree ORDER BY level, scope;
|
|
```
|
|
|
|
### Performance Tuning
|
|
|
|
#### **Query Optimization**
|
|
```sql
|
|
-- Use EXPLAIN ANALYZE for query planning
|
|
EXPLAIN (ANALYZE, BUFFERS)
|
|
SELECT st.id FROM static_tokens st
|
|
WHERE st.app_id = 'test-app' AND st.key_hash = 'hash123';
|
|
|
|
-- Optimize with covering indexes
|
|
CREATE INDEX idx_static_tokens_covering
|
|
ON static_tokens(app_id, key_hash)
|
|
INCLUDE (id, created_at);
|
|
|
|
-- Use partial indexes for frequent filters
|
|
CREATE INDEX idx_active_sessions_partial
|
|
ON user_sessions(user_id, app_id, expires_at)
|
|
WHERE active = true;
|
|
```
|
|
|
|
#### **Connection Pooling Configuration**
|
|
```yaml
|
|
database:
|
|
host: postgres
|
|
port: 5432
|
|
name: kms
|
|
user: kms_api_service
|
|
max_open_connections: 25
|
|
max_idle_connections: 5
|
|
connection_max_lifetime: 300s
|
|
connection_max_idle_time: 60s
|
|
```
|
|
|
|
This database schema documentation provides comprehensive coverage of the KMS data model, suitable for developers, database administrators, and system architects who need to understand, maintain, or extend the database layer. |