Files
cannaiq/backend/migrations/005_api_tokens.sql
2025-11-28 19:45:44 -07:00

52 lines
1.8 KiB
PL/PgSQL

-- API Tokens Table
CREATE TABLE IF NOT EXISTS api_tokens (
id SERIAL PRIMARY KEY,
name VARCHAR(255) NOT NULL,
token VARCHAR(255) UNIQUE NOT NULL,
description TEXT,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
active BOOLEAN DEFAULT true,
rate_limit INTEGER DEFAULT 100, -- requests per minute
allowed_endpoints TEXT[], -- null = all endpoints allowed
expires_at TIMESTAMP,
last_used_at TIMESTAMP,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- API Token Usage Tracking
CREATE TABLE IF NOT EXISTS api_token_usage (
id SERIAL PRIMARY KEY,
token_id INTEGER REFERENCES api_tokens(id) ON DELETE CASCADE,
endpoint VARCHAR(255) NOT NULL,
method VARCHAR(10) NOT NULL,
status_code INTEGER,
response_time_ms INTEGER,
request_size INTEGER, -- bytes
response_size INTEGER, -- bytes
ip_address INET,
user_agent TEXT,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Indexes for performance
CREATE INDEX IF NOT EXISTS idx_api_tokens_token ON api_tokens(token);
CREATE INDEX IF NOT EXISTS idx_api_tokens_active ON api_tokens(active);
CREATE INDEX IF NOT EXISTS idx_api_token_usage_token_id ON api_token_usage(token_id);
CREATE INDEX IF NOT EXISTS idx_api_token_usage_created_at ON api_token_usage(created_at);
CREATE INDEX IF NOT EXISTS idx_api_token_usage_endpoint ON api_token_usage(endpoint);
-- Function to update updated_at timestamp
CREATE OR REPLACE FUNCTION update_api_token_updated_at()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;
CREATE TRIGGER api_tokens_updated_at
BEFORE UPDATE ON api_tokens
FOR EACH ROW
EXECUTE FUNCTION update_api_token_updated_at();