-- Migration: Document enhancements for file paths, positions, and kanban type -- Adds path column for Google Drive-like unique paths -- Adds position column for file ordering within folders -- Extends type enum to include 'kanban' for kanban boards as files -- Add path column (computed from parent hierarchy) ALTER TABLE documents ADD COLUMN IF NOT EXISTS path TEXT; -- Add position column for ordering files within a folder ALTER TABLE documents ADD COLUMN IF NOT EXISTS position INTEGER DEFAULT 0; -- Update the type constraint to allow 'kanban' -- First drop the existing constraint if it exists ALTER TABLE documents DROP CONSTRAINT IF EXISTS documents_type_check; -- Add new constraint with kanban type ALTER TABLE documents ADD CONSTRAINT documents_type_check CHECK (type IN ('folder', 'document', 'kanban')); -- Function to compute and update document path CREATE OR REPLACE FUNCTION compute_document_path(doc_id UUID) RETURNS TEXT AS $$ DECLARE result TEXT := ''; current_doc RECORD; path_parts TEXT[] := '{}'; BEGIN -- Start with the document itself SELECT * INTO current_doc FROM documents WHERE id = doc_id; IF NOT FOUND THEN RETURN NULL; END IF; -- Build path from document up to root WHILE current_doc IS NOT NULL LOOP path_parts := array_prepend(current_doc.name, path_parts); IF current_doc.parent_id IS NULL THEN EXIT; END IF; SELECT * INTO current_doc FROM documents WHERE id = current_doc.parent_id; END LOOP; -- Join with '/' separator result := '/' || array_to_string(path_parts, '/'); RETURN result; END; $$ LANGUAGE plpgsql; -- Function to update path on insert/update CREATE OR REPLACE FUNCTION update_document_path() RETURNS TRIGGER AS $$ BEGIN NEW.path := compute_document_path(NEW.id); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Trigger to auto-update path DROP TRIGGER IF EXISTS documents_path_trigger ON documents; CREATE TRIGGER documents_path_trigger BEFORE INSERT OR UPDATE OF name, parent_id ON documents FOR EACH ROW EXECUTE FUNCTION update_document_path(); -- Function to get next position in folder CREATE OR REPLACE FUNCTION get_next_document_position(folder_id UUID) RETURNS INTEGER AS $$ DECLARE max_pos INTEGER; BEGIN SELECT COALESCE(MAX(position), -1) + 1 INTO max_pos FROM documents WHERE parent_id IS NOT DISTINCT FROM folder_id; RETURN max_pos; END; $$ LANGUAGE plpgsql; -- Update existing documents to have computed paths UPDATE documents SET path = compute_document_path(id) WHERE path IS NULL; -- Update existing documents to have sequential positions within their folders WITH numbered AS ( SELECT id, ROW_NUMBER() OVER (PARTITION BY parent_id ORDER BY created_at) - 1 AS new_pos FROM documents WHERE position IS NULL OR position = 0 ) UPDATE documents d SET position = n.new_pos FROM numbered n WHERE d.id = n.id; -- Create index on path for faster lookups CREATE INDEX IF NOT EXISTS idx_documents_path ON documents(path); -- Create index on parent_id and position for faster ordering CREATE INDEX IF NOT EXISTS idx_documents_parent_position ON documents(parent_id, position);