mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 12:47:13 +01:00
## Database Schema Enhancements ### Migration 19 - Fixed - Removed invalid composite index on session(visitor_id, user_id) - visitor_id column doesn't exist in session table - Fixed migration to only create valid indexes ### Migration 20 - New Constraints (with rollback support) - Added websiteId foreign key to UserMapping table - Added foreign key constraint to Website table for referential integrity - Added composite index on UserMapping(websiteId, userId) for query performance - Added composite index on Session(websiteId, userId) for join optimization ### Schema Updates - Updated UserMapping model with websiteId field - Added foreign key relationship: UserMapping -> Website - Added userMappings relation to Website model - Added composite indexes for better query performance ## Files Changed ### Modified - prisma/schema.prisma - Added foreign keys and composite indexes - prisma/migrations/19_add_user_id_mapping/migration.sql - Fixed invalid index ### New - prisma/migrations/20_add_user_mapping_constraints/migration.sql - Forward migration - prisma/migrations/20_add_user_mapping_constraints/rollback.sql - Rollback script ## Benefits - ✅ Referential integrity enforced at database level - ✅ Optimized queries for Umami sync operations - ✅ Better join performance on Session table - ✅ Rollback capability for safe schema changes ## Breaking Changes - UserMapping table now requires websiteId field - Existing data will be migrated to use first available website_id ## Migration Notes Run the migration with: ```bash npx prisma migrate deploy ``` To rollback if needed: ```bash psql -d umami -f prisma/migrations/20_add_user_mapping_constraints/rollback.sql ```
33 lines
1.5 KiB
SQL
33 lines
1.5 KiB
SQL
-- Migration: Add User ID Mapping
|
|
-- Description: Add user_id column to session table for unified user identification
|
|
-- Date: 2025-11-05
|
|
|
|
-- Add user_id column to session table
|
|
ALTER TABLE session ADD COLUMN IF NOT EXISTS user_id VARCHAR(36);
|
|
|
|
-- Add index for user_id lookups
|
|
CREATE INDEX IF NOT EXISTS idx_session_user_id ON session(user_id);
|
|
|
|
-- Create user_mapping table for tracking visitor_id to user_id relationships
|
|
CREATE TABLE IF NOT EXISTS user_mapping (
|
|
id SERIAL PRIMARY KEY,
|
|
visitor_id VARCHAR(36) NOT NULL,
|
|
user_id VARCHAR(36) NOT NULL,
|
|
first_seen_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
last_seen_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
|
session_count INTEGER DEFAULT 1,
|
|
UNIQUE(visitor_id, user_id)
|
|
);
|
|
|
|
-- Add indexes for user_mapping
|
|
CREATE INDEX IF NOT EXISTS idx_user_mapping_visitor ON user_mapping(visitor_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_mapping_user ON user_mapping(user_id);
|
|
CREATE INDEX IF NOT EXISTS idx_user_mapping_last_seen ON user_mapping(last_seen_at);
|
|
|
|
-- Add comments
|
|
COMMENT ON COLUMN session.user_id IS 'WordPress user ID for logged-in users';
|
|
COMMENT ON TABLE user_mapping IS 'Maps visitor IDs to user IDs for unified identification';
|
|
COMMENT ON COLUMN user_mapping.visitor_id IS 'Umami visitor ID (anonymous)';
|
|
COMMENT ON COLUMN user_mapping.user_id IS 'WordPress user ID (logged-in)';
|
|
COMMENT ON COLUMN user_mapping.session_count IS 'Number of sessions for this visitor-user pair';
|
|
|