feat: secu migrate to user uuid
This commit is contained in:
@@ -1,3 +1,6 @@
|
||||
-- Enable UUID extension for secure user identification
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- Create enum for skill levels
|
||||
CREATE TYPE skill_level_enum AS ENUM ('never', 'not-autonomous', 'autonomous', 'expert');
|
||||
|
||||
@@ -38,15 +41,19 @@ CREATE TABLE skill_links (
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
||||
);
|
||||
|
||||
-- Users table
|
||||
-- Users table with UUID primary key for security
|
||||
-- UUIDs prevent user enumeration attacks (vs sequential IDs 1,2,3...)
|
||||
CREATE TABLE users (
|
||||
id SERIAL PRIMARY KEY,
|
||||
id SERIAL, -- Legacy ID kept for backward compatibility during migration
|
||||
uuid_id UUID DEFAULT uuid_generate_v4() NOT NULL,
|
||||
first_name VARCHAR(100) NOT NULL,
|
||||
last_name VARCHAR(100) NOT NULL,
|
||||
team_id VARCHAR(50) REFERENCES teams(id),
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(first_name, last_name, team_id)
|
||||
PRIMARY KEY (uuid_id),
|
||||
UNIQUE(first_name, last_name, team_id),
|
||||
UNIQUE(uuid_id)
|
||||
);
|
||||
|
||||
-- ========================================
|
||||
@@ -56,10 +63,11 @@ CREATE TABLE users (
|
||||
-- User evaluations - metadata about user's evaluation session
|
||||
CREATE TABLE user_evaluations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
|
||||
user_id INTEGER, -- Legacy column kept for backward compatibility
|
||||
user_uuid UUID REFERENCES users(uuid_id) ON DELETE CASCADE,
|
||||
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(user_id)
|
||||
UNIQUE(user_uuid)
|
||||
);
|
||||
|
||||
-- Skill evaluations - direct relationship between user and skill
|
||||
@@ -93,7 +101,9 @@ CREATE INDEX idx_skills_category_id ON skills(category_id);
|
||||
CREATE INDEX idx_skill_links_skill_id ON skill_links(skill_id);
|
||||
CREATE INDEX idx_users_team_id ON users(team_id);
|
||||
CREATE INDEX idx_users_unique_person ON users(first_name, last_name, team_id);
|
||||
CREATE INDEX idx_user_evaluations_user_id ON user_evaluations(user_id);
|
||||
CREATE INDEX idx_users_uuid_id ON users(uuid_id); -- Index on UUID for performance
|
||||
CREATE INDEX idx_user_evaluations_user_uuid ON user_evaluations(user_uuid);
|
||||
CREATE INDEX idx_user_evaluations_user_id ON user_evaluations(user_id); -- Legacy index
|
||||
CREATE INDEX idx_skill_evaluations_user_evaluation_id ON skill_evaluations(user_evaluation_id);
|
||||
CREATE INDEX idx_skill_evaluations_skill_id ON skill_evaluations(skill_id);
|
||||
CREATE INDEX idx_skill_evaluations_is_selected ON skill_evaluations(is_selected);
|
||||
@@ -138,7 +148,7 @@ SELECT
|
||||
se.updated_at
|
||||
FROM users u
|
||||
JOIN teams t ON u.team_id = t.id
|
||||
JOIN user_evaluations ue ON u.id = ue.user_id
|
||||
JOIN user_evaluations ue ON u.uuid_id = ue.user_uuid
|
||||
JOIN skill_evaluations se ON ue.id = se.user_evaluation_id
|
||||
JOIN skills s ON se.skill_id = s.id
|
||||
JOIN skill_categories sc ON s.category_id = sc.id;
|
||||
|
||||
40
scripts/migrate-to-uuid.sql
Normal file
40
scripts/migrate-to-uuid.sql
Normal file
@@ -0,0 +1,40 @@
|
||||
-- Migration script: Replace sequential user IDs with UUIDs for security
|
||||
-- This prevents enumeration attacks and improves security
|
||||
|
||||
-- Step 1: Enable UUID extension if not already enabled
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
||||
|
||||
-- Step 2: Add new UUID column to users table
|
||||
ALTER TABLE users ADD COLUMN uuid_id UUID DEFAULT uuid_generate_v4();
|
||||
|
||||
-- Step 3: Update all existing users to have UUIDs (they will be auto-generated)
|
||||
UPDATE users SET uuid_id = uuid_generate_v4() WHERE uuid_id IS NULL;
|
||||
|
||||
-- Step 4: Make UUID column NOT NULL
|
||||
ALTER TABLE users ALTER COLUMN uuid_id SET NOT NULL;
|
||||
|
||||
-- Step 5: Add new UUID column to user_evaluations table
|
||||
ALTER TABLE user_evaluations ADD COLUMN user_uuid UUID;
|
||||
|
||||
-- Step 6: Update user_evaluations to use the new UUIDs
|
||||
UPDATE user_evaluations
|
||||
SET user_uuid = users.uuid_id
|
||||
FROM users
|
||||
WHERE user_evaluations.user_id = users.id;
|
||||
|
||||
-- Step 7: Make user_uuid NOT NULL
|
||||
ALTER TABLE user_evaluations ALTER COLUMN user_uuid SET NOT NULL;
|
||||
|
||||
-- Step 8: Add new UUID column to skill_evaluations (via user_evaluations)
|
||||
-- No direct change needed as skill_evaluations references user_evaluations.id
|
||||
|
||||
-- Step 9: Create unique constraint on UUID
|
||||
ALTER TABLE users ADD CONSTRAINT users_uuid_unique UNIQUE (uuid_id);
|
||||
|
||||
-- Step 10: Add unique constraint and foreign key for user_evaluations
|
||||
ALTER TABLE user_evaluations ADD CONSTRAINT user_evaluations_user_uuid_unique UNIQUE (user_uuid);
|
||||
ALTER TABLE user_evaluations ADD CONSTRAINT fk_user_evaluations_user_uuid
|
||||
FOREIGN KEY (user_uuid) REFERENCES users(uuid_id);
|
||||
|
||||
-- Note: The actual switchover will be done in the application code
|
||||
-- The old id columns will be kept temporarily for backward compatibility
|
||||
Reference in New Issue
Block a user