mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 04:37:11 +01:00
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 ```
This commit is contained in:
parent
5cf1e0c16a
commit
7c1db78050
4 changed files with 70 additions and 11 deletions
|
|
@ -8,9 +8,6 @@ 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);
|
||||
|
||||
-- Add composite index for visitor_id and user_id
|
||||
CREATE INDEX IF NOT EXISTS idx_session_visitor_user ON session(visitor_id, 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,
|
||||
|
|
|
|||
|
|
@ -0,0 +1,23 @@
|
|||
-- 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);
|
||||
|
||||
|
|
@ -0,0 +1,16 @@
|
|||
-- Rollback migration for user_mapping constraints
|
||||
-- Run this script to revert the changes made in migration.sql
|
||||
|
||||
-- Drop composite index on session table
|
||||
DROP INDEX IF EXISTS session_website_id_user_id_idx;
|
||||
|
||||
-- Drop composite index on user_mapping table
|
||||
DROP INDEX IF EXISTS user_mapping_website_id_user_id_idx;
|
||||
|
||||
-- Drop foreign key constraint
|
||||
ALTER TABLE user_mapping
|
||||
DROP CONSTRAINT IF EXISTS user_mapping_website_id_fkey;
|
||||
|
||||
-- Drop website_id column
|
||||
ALTER TABLE user_mapping DROP COLUMN IF EXISTS website_id;
|
||||
|
||||
|
|
@ -43,6 +43,7 @@ model Session {
|
|||
region String? @db.VarChar(20)
|
||||
city String? @db.VarChar(50)
|
||||
distinctId String? @map("distinct_id") @db.VarChar(50)
|
||||
userId String? @map("user_id") @db.VarChar(36)
|
||||
createdAt DateTime? @default(now()) @map("created_at") @db.Timestamptz(6)
|
||||
|
||||
websiteEvents WebsiteEvent[]
|
||||
|
|
@ -52,6 +53,8 @@ model Session {
|
|||
@@index([createdAt])
|
||||
@@index([websiteId])
|
||||
@@index([websiteId, createdAt])
|
||||
@@index([userId])
|
||||
@@index([websiteId, userId])
|
||||
@@index([websiteId, createdAt, browser])
|
||||
@@index([websiteId, createdAt, os])
|
||||
@@index([websiteId, createdAt, device])
|
||||
|
|
@ -76,14 +79,15 @@ model Website {
|
|||
updatedAt DateTime? @updatedAt @map("updated_at") @db.Timestamptz(6)
|
||||
deletedAt DateTime? @map("deleted_at") @db.Timestamptz(6)
|
||||
|
||||
user User? @relation("user", fields: [userId], references: [id])
|
||||
createUser User? @relation("createUser", fields: [createdBy], references: [id])
|
||||
team Team? @relation(fields: [teamId], references: [id])
|
||||
eventData EventData[]
|
||||
reports Report[]
|
||||
revenue Revenue[]
|
||||
segments Segment[]
|
||||
sessionData SessionData[]
|
||||
user User? @relation("user", fields: [userId], references: [id])
|
||||
createUser User? @relation("createUser", fields: [createdBy], references: [id])
|
||||
team Team? @relation(fields: [teamId], references: [id])
|
||||
eventData EventData[]
|
||||
reports Report[]
|
||||
revenue Revenue[]
|
||||
segments Segment[]
|
||||
sessionData SessionData[]
|
||||
userMappings UserMapping[]
|
||||
|
||||
@@index([userId])
|
||||
@@index([teamId])
|
||||
|
|
@ -330,3 +334,22 @@ model Pixel {
|
|||
@@index([createdAt])
|
||||
@@map("pixel")
|
||||
}
|
||||
|
||||
model UserMapping {
|
||||
id Int @id @default(autoincrement())
|
||||
websiteId String @map("website_id") @db.Uuid
|
||||
visitorId String @map("visitor_id") @db.VarChar(36)
|
||||
userId String @map("user_id") @db.VarChar(36)
|
||||
firstSeenAt DateTime @default(now()) @map("first_seen_at") @db.Timestamptz(6)
|
||||
lastSeenAt DateTime @default(now()) @map("last_seen_at") @db.Timestamptz(6)
|
||||
sessionCount Int @default(1) @map("session_count")
|
||||
|
||||
website Website @relation(fields: [websiteId], references: [id])
|
||||
|
||||
@@unique([visitorId, userId])
|
||||
@@index([visitorId])
|
||||
@@index([userId])
|
||||
@@index([lastSeenAt])
|
||||
@@index([websiteId, userId])
|
||||
@@map("user_mapping")
|
||||
}
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue