umami/prisma/migrations/20_add_user_mapping_constraints/migration.sql
iskandarsulaili 7c1db78050 feat: Add UserMapping constraints and schema improvements
## 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
```
2025-11-06 22:04:57 +08:00

23 lines
922 B
SQL

-- Add websiteId column to user_mapping table
ALTER TABLE user_mapping ADD COLUMN website_id UUID;
-- Update existing rows with a default website_id (you may need to adjust this based on your data)
-- This assumes you have at least one website in your database
UPDATE user_mapping
SET website_id = (SELECT website_id FROM website LIMIT 1)
WHERE website_id IS NULL;
-- Make website_id NOT NULL after populating
ALTER TABLE user_mapping ALTER COLUMN website_id SET NOT NULL;
-- Add foreign key constraint
ALTER TABLE user_mapping
ADD CONSTRAINT user_mapping_website_id_fkey
FOREIGN KEY (website_id) REFERENCES website(website_id);
-- Add composite index for better query performance
CREATE INDEX user_mapping_website_id_user_id_idx ON user_mapping(website_id, user_id);
-- Add composite index on session table for better join performance
CREATE INDEX session_website_id_user_id_idx ON session(website_id, user_id);