-- ========================================== -- SESSIONS TABLE -- Purpose: Store refresh tokens for JWT authentication -- ========================================== CREATE TABLE IF NOT EXISTS sessions ( -- Primary key id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), -- User reference user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, -- Token details refresh_token VARCHAR(500) NOT NULL UNIQUE, refresh_token_hash VARCHAR(255) NOT NULL, -- bcrypt hash of token -- Device/Client information user_agent TEXT, ip_address INET, device_name VARCHAR(255), device_type VARCHAR(50), -- 'web', 'mobile', 'desktop' -- Expiry expires_at TIMESTAMPTZ NOT NULL, -- Status is_revoked BOOLEAN DEFAULT FALSE, revoked_at TIMESTAMPTZ, revoked_reason VARCHAR(255), -- Timestamps created_at TIMESTAMPTZ DEFAULT NOW() NOT NULL, last_used_at TIMESTAMPTZ DEFAULT NOW() NOT NULL, -- Constraints CONSTRAINT chk_device_type CHECK (device_type IN ('web', 'mobile', 'desktop', 'unknown')) ); -- Indexes for performance CREATE INDEX idx_sessions_user_id ON sessions(user_id) WHERE NOT is_revoked; CREATE INDEX idx_sessions_refresh_token ON sessions(refresh_token) WHERE NOT is_revoked; CREATE INDEX idx_sessions_expires_at ON sessions(expires_at); CREATE INDEX idx_sessions_is_revoked ON sessions(is_revoked); -- Index for cleanup queries (expired sessions) -- Note: Cannot use NOW() in partial index - it's not IMMUTABLE -- The application will filter expires_at < NOW() at query time CREATE INDEX idx_sessions_expired_cleanup ON sessions(expires_at, is_revoked) WHERE NOT is_revoked; -- Comments COMMENT ON TABLE sessions IS 'JWT refresh token storage with device tracking'; COMMENT ON COLUMN sessions.refresh_token IS 'Plain refresh token (indexed for lookup)'; COMMENT ON COLUMN sessions.refresh_token_hash IS 'Bcrypt hash of refresh token (for verification)'; COMMENT ON COLUMN sessions.is_revoked IS 'Manually revoked sessions (logout)';