-- Create user_sessions table for session management CREATE TABLE IF NOT EXISTS user_sessions ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id VARCHAR(255) NOT NULL, app_id VARCHAR(255) NOT NULL, session_type VARCHAR(20) NOT NULL CHECK (session_type IN ('web', 'mobile', 'api')), status VARCHAR(20) NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'expired', 'revoked', 'suspended')), access_token TEXT, refresh_token TEXT, id_token TEXT, ip_address INET, user_agent TEXT, last_activity TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), expires_at TIMESTAMP WITH TIME ZONE NOT NULL, created_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE NOT NULL DEFAULT NOW(), revoked_at TIMESTAMP WITH TIME ZONE, revoked_by VARCHAR(255), metadata JSONB DEFAULT '{}', -- Foreign key constraint to applications table CONSTRAINT fk_user_sessions_app_id FOREIGN KEY (app_id) REFERENCES applications(app_id) ON DELETE CASCADE ); -- Create indexes for performance CREATE INDEX IF NOT EXISTS idx_user_sessions_user_id ON user_sessions(user_id); CREATE INDEX IF NOT EXISTS idx_user_sessions_app_id ON user_sessions(app_id); CREATE INDEX IF NOT EXISTS idx_user_sessions_user_app ON user_sessions(user_id, app_id); CREATE INDEX IF NOT EXISTS idx_user_sessions_status ON user_sessions(status); CREATE INDEX IF NOT EXISTS idx_user_sessions_expires_at ON user_sessions(expires_at); CREATE INDEX IF NOT EXISTS idx_user_sessions_last_activity ON user_sessions(last_activity); CREATE INDEX IF NOT EXISTS idx_user_sessions_created_at ON user_sessions(created_at); -- Create partial indexes for active sessions (most common queries) CREATE INDEX IF NOT EXISTS idx_user_sessions_active ON user_sessions(user_id, app_id) WHERE status = 'active'; CREATE INDEX IF NOT EXISTS idx_user_sessions_active_expires ON user_sessions(user_id, expires_at) WHERE status = 'active'; -- Create GIN index for metadata JSONB queries CREATE INDEX IF NOT EXISTS idx_user_sessions_metadata ON user_sessions USING GIN (metadata); -- Create index for tenant-based queries (if using multi-tenancy) CREATE INDEX IF NOT EXISTS idx_user_sessions_tenant ON user_sessions((metadata->>'tenant_id')) WHERE metadata->>'tenant_id' IS NOT NULL; -- Add comments for documentation COMMENT ON TABLE user_sessions IS 'Stores user session information for authentication and session management'; COMMENT ON COLUMN user_sessions.id IS 'Unique session identifier'; COMMENT ON COLUMN user_sessions.user_id IS 'User identifier (email, username, or external ID)'; COMMENT ON COLUMN user_sessions.app_id IS 'Application identifier this session belongs to'; COMMENT ON COLUMN user_sessions.session_type IS 'Type of session: web, mobile, or api'; COMMENT ON COLUMN user_sessions.status IS 'Current session status: active, expired, revoked, or suspended'; COMMENT ON COLUMN user_sessions.access_token IS 'OAuth2/OIDC access token (encrypted/hashed)'; COMMENT ON COLUMN user_sessions.refresh_token IS 'OAuth2/OIDC refresh token (encrypted/hashed)'; COMMENT ON COLUMN user_sessions.id_token IS 'OIDC ID token (encrypted/hashed)'; COMMENT ON COLUMN user_sessions.ip_address IS 'IP address of the client when session was created'; COMMENT ON COLUMN user_sessions.user_agent IS 'User agent string of the client'; COMMENT ON COLUMN user_sessions.last_activity IS 'Timestamp of last session activity'; COMMENT ON COLUMN user_sessions.expires_at IS 'When the session expires'; COMMENT ON COLUMN user_sessions.revoked_at IS 'When the session was revoked (if applicable)'; COMMENT ON COLUMN user_sessions.revoked_by IS 'Who revoked the session (user ID or system)'; COMMENT ON COLUMN user_sessions.metadata IS 'Additional session metadata (device info, location, etc.)';