-- Design Thinking Schema for Mylder Platform -- Migration: 20251214_design_thinking_schema.sql -- Enable UUID extension CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- Design phases enum CREATE TYPE design_phase AS ENUM ('empathize', 'define', 'ideate', 'prototype', 'test'); CREATE TYPE phase_status AS ENUM ('not_started', 'in_progress', 'completed', 'blocked', 'needs_review'); CREATE TYPE backlog_status AS ENUM ('backlog', 'ready', 'in_progress', 'done', 'blocked'); CREATE TYPE recommendation_type AS ENUM ('action', 'warning', 'insight', 'optimization'); CREATE TYPE recommendation_priority AS ENUM ('low', 'medium', 'high'); -- Projects table (extend or create) CREATE TABLE IF NOT EXISTS projects ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), user_id UUID NOT NULL REFERENCES auth.users(id) ON DELETE CASCADE, name TEXT NOT NULL, description TEXT, current_phase design_phase DEFAULT 'empathize', health_score INTEGER DEFAULT 100 CHECK (health_score >= 0 AND health_score <= 100), created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- Project phase tracking CREATE TABLE project_phases ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, phase design_phase NOT NULL, status phase_status DEFAULT 'not_started', started_at TIMESTAMPTZ, completed_at TIMESTAMPTZ, notes TEXT, iteration INTEGER DEFAULT 1, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(project_id, phase, iteration) ); -- Backlog items with WSJF prioritization CREATE TABLE backlog_items ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, title TEXT NOT NULL, description TEXT, phase design_phase NOT NULL, status backlog_status DEFAULT 'backlog', -- WSJF scoring (1-10 scale) user_value INTEGER DEFAULT 5 CHECK (user_value >= 1 AND user_value <= 10), time_criticality INTEGER DEFAULT 5 CHECK (time_criticality >= 1 AND time_criticality <= 10), risk_reduction INTEGER DEFAULT 5 CHECK (risk_reduction >= 1 AND risk_reduction <= 10), effort INTEGER DEFAULT 5 CHECK (effort >= 1 AND effort <= 10), -- Computed priority score: (user_value + time_criticality + risk_reduction) / effort priority_score DECIMAL(4,2) GENERATED ALWAYS AS ( (user_value + time_criticality + risk_reduction)::DECIMAL / GREATEST(effort, 1) ) STORED, -- Dependencies depends_on UUID[] DEFAULT '{}', -- Assignment assigned_to UUID REFERENCES auth.users(id), due_date DATE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW() ); -- AI recommendations CREATE TABLE ai_recommendations ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, type recommendation_type NOT NULL, priority recommendation_priority DEFAULT 'medium', title TEXT NOT NULL, description TEXT NOT NULL, action_command TEXT, related_items UUID[] DEFAULT '{}', dismissed BOOLEAN DEFAULT FALSE, dismissed_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW() ); -- Project health metrics (historical tracking) CREATE TABLE project_health_snapshots ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, overall_score INTEGER NOT NULL CHECK (overall_score >= 0 AND overall_score <= 100), velocity INTEGER DEFAULT 0, blockers INTEGER DEFAULT 0, overdue INTEGER DEFAULT 0, completion_rate INTEGER DEFAULT 0, snapshot_date DATE DEFAULT CURRENT_DATE, created_at TIMESTAMPTZ DEFAULT NOW(), UNIQUE(project_id, snapshot_date) ); -- Activity feed for projects CREATE TABLE project_activities ( id UUID PRIMARY KEY DEFAULT uuid_generate_v4(), project_id UUID NOT NULL REFERENCES projects(id) ON DELETE CASCADE, user_id UUID REFERENCES auth.users(id), activity_type TEXT NOT NULL, message TEXT NOT NULL, metadata JSONB DEFAULT '{}', created_at TIMESTAMPTZ DEFAULT NOW() ); -- Indexes for performance CREATE INDEX idx_projects_user_id ON projects(user_id); CREATE INDEX idx_project_phases_project_id ON project_phases(project_id); CREATE INDEX idx_backlog_items_project_id ON backlog_items(project_id); CREATE INDEX idx_backlog_items_status ON backlog_items(status); CREATE INDEX idx_backlog_items_priority ON backlog_items(priority_score DESC); CREATE INDEX idx_ai_recommendations_project_id ON ai_recommendations(project_id); CREATE INDEX idx_ai_recommendations_dismissed ON ai_recommendations(dismissed) WHERE dismissed = FALSE; CREATE INDEX idx_project_health_snapshots_project_id ON project_health_snapshots(project_id); CREATE INDEX idx_project_activities_project_id ON project_activities(project_id); CREATE INDEX idx_project_activities_created_at ON project_activities(created_at DESC); -- Row Level Security ALTER TABLE projects ENABLE ROW LEVEL SECURITY; ALTER TABLE project_phases ENABLE ROW LEVEL SECURITY; ALTER TABLE backlog_items ENABLE ROW LEVEL SECURITY; ALTER TABLE ai_recommendations ENABLE ROW LEVEL SECURITY; ALTER TABLE project_health_snapshots ENABLE ROW LEVEL SECURITY; ALTER TABLE project_activities ENABLE ROW LEVEL SECURITY; -- RLS Policies: Users can only access their own projects CREATE POLICY "Users can view their own projects" ON projects FOR SELECT USING (auth.uid() = user_id); CREATE POLICY "Users can create their own projects" ON projects FOR INSERT WITH CHECK (auth.uid() = user_id); CREATE POLICY "Users can update their own projects" ON projects FOR UPDATE USING (auth.uid() = user_id); CREATE POLICY "Users can delete their own projects" ON projects FOR DELETE USING (auth.uid() = user_id); -- RLS for project_phases CREATE POLICY "Users can manage phases of their projects" ON project_phases FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = project_phases.project_id AND projects.user_id = auth.uid()) ); -- RLS for backlog_items CREATE POLICY "Users can manage backlog of their projects" ON backlog_items FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = backlog_items.project_id AND projects.user_id = auth.uid()) ); -- RLS for ai_recommendations CREATE POLICY "Users can view recommendations for their projects" ON ai_recommendations FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = ai_recommendations.project_id AND projects.user_id = auth.uid()) ); -- RLS for project_health_snapshots CREATE POLICY "Users can view health of their projects" ON project_health_snapshots FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = project_health_snapshots.project_id AND projects.user_id = auth.uid()) ); -- RLS for project_activities CREATE POLICY "Users can view activities of their projects" ON project_activities FOR ALL USING ( EXISTS (SELECT 1 FROM projects WHERE projects.id = project_activities.project_id AND projects.user_id = auth.uid()) ); -- Functions -- Update updated_at timestamp CREATE OR REPLACE FUNCTION update_updated_at() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Triggers for updated_at CREATE TRIGGER projects_updated_at BEFORE UPDATE ON projects FOR EACH ROW EXECUTE FUNCTION update_updated_at(); CREATE TRIGGER project_phases_updated_at BEFORE UPDATE ON project_phases FOR EACH ROW EXECUTE FUNCTION update_updated_at(); CREATE TRIGGER backlog_items_updated_at BEFORE UPDATE ON backlog_items FOR EACH ROW EXECUTE FUNCTION update_updated_at(); -- Function to calculate project health CREATE OR REPLACE FUNCTION calculate_project_health(p_project_id UUID) RETURNS INTEGER AS $$ DECLARE total_items INTEGER; done_items INTEGER; blocked_items INTEGER; overdue_items INTEGER; health INTEGER; BEGIN SELECT COUNT(*), COUNT(*) FILTER (WHERE status = 'done'), COUNT(*) FILTER (WHERE status = 'blocked'), COUNT(*) FILTER (WHERE due_date < CURRENT_DATE AND status NOT IN ('done', 'blocked')) INTO total_items, done_items, blocked_items, overdue_items FROM backlog_items WHERE project_id = p_project_id; IF total_items = 0 THEN RETURN 100; END IF; -- Health calculation: base 100, minus penalties health := 100; health := health - (blocked_items * 10); -- -10 per blocker health := health - (overdue_items * 5); -- -5 per overdue health := health + (done_items * 2); -- +2 per completed RETURN GREATEST(0, LEAST(100, health)); END; $$ LANGUAGE plpgsql; -- Function to record daily health snapshot CREATE OR REPLACE FUNCTION record_health_snapshot(p_project_id UUID) RETURNS VOID AS $$ DECLARE v_health INTEGER; v_velocity INTEGER; v_blockers INTEGER; v_overdue INTEGER; v_completion_rate INTEGER; v_total INTEGER; v_done INTEGER; BEGIN v_health := calculate_project_health(p_project_id); SELECT COUNT(*) FILTER (WHERE status = 'blocked'), COUNT(*) FILTER (WHERE due_date < CURRENT_DATE AND status NOT IN ('done', 'blocked')), COUNT(*), COUNT(*) FILTER (WHERE status = 'done') INTO v_blockers, v_overdue, v_total, v_done FROM backlog_items WHERE project_id = p_project_id; v_completion_rate := CASE WHEN v_total > 0 THEN (v_done * 100 / v_total) ELSE 0 END; -- Velocity: items completed in last 7 days SELECT COUNT(*) INTO v_velocity FROM backlog_items WHERE project_id = p_project_id AND status = 'done' AND updated_at >= NOW() - INTERVAL '7 days'; INSERT INTO project_health_snapshots (project_id, overall_score, velocity, blockers, overdue, completion_rate) VALUES (p_project_id, v_health, v_velocity, v_blockers, v_overdue, v_completion_rate) ON CONFLICT (project_id, snapshot_date) DO UPDATE SET overall_score = EXCLUDED.overall_score, velocity = EXCLUDED.velocity, blockers = EXCLUDED.blockers, overdue = EXCLUDED.overdue, completion_rate = EXCLUDED.completion_rate; -- Update project health_score UPDATE projects SET health_score = v_health WHERE id = p_project_id; END; $$ LANGUAGE plpgsql; -- Comments for documentation COMMENT ON TABLE projects IS 'User projects with design thinking phases'; COMMENT ON TABLE project_phases IS 'Track status of each design phase per project iteration'; COMMENT ON TABLE backlog_items IS 'Prioritized backlog with WSJF scoring'; COMMENT ON COLUMN backlog_items.priority_score IS 'WSJF: (user_value + time_criticality + risk_reduction) / effort'; COMMENT ON TABLE ai_recommendations IS 'AI-generated insights and action recommendations'; COMMENT ON TABLE project_health_snapshots IS 'Daily snapshots of project health metrics';