Merge branch 'release-v2.1.4' into feature/task-activities-by-user
This commit is contained in:
@@ -0,0 +1,300 @@
|
||||
-- Fix Duplicate Sort Orders Script
|
||||
-- This script detects and fixes duplicate sort order values that break task ordering
|
||||
|
||||
-- 1. DETECTION QUERIES - Run these first to see the scope of the problem
|
||||
|
||||
-- Check for duplicates in main sort_order column
|
||||
SELECT
|
||||
project_id,
|
||||
sort_order,
|
||||
COUNT(*) as duplicate_count,
|
||||
STRING_AGG(id::text, ', ') as task_ids
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
GROUP BY project_id, sort_order
|
||||
HAVING COUNT(*) > 1
|
||||
ORDER BY project_id, sort_order;
|
||||
|
||||
-- Check for duplicates in status_sort_order
|
||||
SELECT
|
||||
project_id,
|
||||
status_sort_order,
|
||||
COUNT(*) as duplicate_count,
|
||||
STRING_AGG(id::text, ', ') as task_ids
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
GROUP BY project_id, status_sort_order
|
||||
HAVING COUNT(*) > 1
|
||||
ORDER BY project_id, status_sort_order;
|
||||
|
||||
-- Check for duplicates in priority_sort_order
|
||||
SELECT
|
||||
project_id,
|
||||
priority_sort_order,
|
||||
COUNT(*) as duplicate_count,
|
||||
STRING_AGG(id::text, ', ') as task_ids
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
GROUP BY project_id, priority_sort_order
|
||||
HAVING COUNT(*) > 1
|
||||
ORDER BY project_id, priority_sort_order;
|
||||
|
||||
-- Check for duplicates in phase_sort_order
|
||||
SELECT
|
||||
project_id,
|
||||
phase_sort_order,
|
||||
COUNT(*) as duplicate_count,
|
||||
STRING_AGG(id::text, ', ') as task_ids
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
GROUP BY project_id, phase_sort_order
|
||||
HAVING COUNT(*) > 1
|
||||
ORDER BY project_id, phase_sort_order;
|
||||
|
||||
-- Note: member_sort_order removed - no longer used
|
||||
|
||||
-- 2. CLEANUP FUNCTIONS
|
||||
|
||||
-- Fix duplicates in main sort_order column
|
||||
CREATE OR REPLACE FUNCTION fix_sort_order_duplicates() RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_project RECORD;
|
||||
_task RECORD;
|
||||
_counter INTEGER;
|
||||
BEGIN
|
||||
-- For each project, reassign sort_order values to ensure uniqueness
|
||||
FOR _project IN
|
||||
SELECT DISTINCT project_id
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
LOOP
|
||||
_counter := 0;
|
||||
|
||||
-- Reassign sort_order values sequentially for this project
|
||||
FOR _task IN
|
||||
SELECT id
|
||||
FROM tasks
|
||||
WHERE project_id = _project.project_id
|
||||
ORDER BY sort_order, created_at
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = _counter
|
||||
WHERE id = _task.id;
|
||||
|
||||
_counter := _counter + 1;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
RAISE NOTICE 'Fixed sort_order duplicates for all projects';
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Fix duplicates in status_sort_order column
|
||||
CREATE OR REPLACE FUNCTION fix_status_sort_order_duplicates() RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_project RECORD;
|
||||
_task RECORD;
|
||||
_counter INTEGER;
|
||||
BEGIN
|
||||
FOR _project IN
|
||||
SELECT DISTINCT project_id
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
LOOP
|
||||
_counter := 0;
|
||||
|
||||
FOR _task IN
|
||||
SELECT id
|
||||
FROM tasks
|
||||
WHERE project_id = _project.project_id
|
||||
ORDER BY status_sort_order, created_at
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET status_sort_order = _counter
|
||||
WHERE id = _task.id;
|
||||
|
||||
_counter := _counter + 1;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
RAISE NOTICE 'Fixed status_sort_order duplicates for all projects';
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Fix duplicates in priority_sort_order column
|
||||
CREATE OR REPLACE FUNCTION fix_priority_sort_order_duplicates() RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_project RECORD;
|
||||
_task RECORD;
|
||||
_counter INTEGER;
|
||||
BEGIN
|
||||
FOR _project IN
|
||||
SELECT DISTINCT project_id
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
LOOP
|
||||
_counter := 0;
|
||||
|
||||
FOR _task IN
|
||||
SELECT id
|
||||
FROM tasks
|
||||
WHERE project_id = _project.project_id
|
||||
ORDER BY priority_sort_order, created_at
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET priority_sort_order = _counter
|
||||
WHERE id = _task.id;
|
||||
|
||||
_counter := _counter + 1;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
RAISE NOTICE 'Fixed priority_sort_order duplicates for all projects';
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Fix duplicates in phase_sort_order column
|
||||
CREATE OR REPLACE FUNCTION fix_phase_sort_order_duplicates() RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_project RECORD;
|
||||
_task RECORD;
|
||||
_counter INTEGER;
|
||||
BEGIN
|
||||
FOR _project IN
|
||||
SELECT DISTINCT project_id
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
LOOP
|
||||
_counter := 0;
|
||||
|
||||
FOR _task IN
|
||||
SELECT id
|
||||
FROM tasks
|
||||
WHERE project_id = _project.project_id
|
||||
ORDER BY phase_sort_order, created_at
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET phase_sort_order = _counter
|
||||
WHERE id = _task.id;
|
||||
|
||||
_counter := _counter + 1;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
|
||||
RAISE NOTICE 'Fixed phase_sort_order duplicates for all projects';
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Note: fix_member_sort_order_duplicates() removed - no longer needed
|
||||
|
||||
-- Master function to fix all sort order duplicates
|
||||
CREATE OR REPLACE FUNCTION fix_all_duplicate_sort_orders() RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
RAISE NOTICE 'Starting sort order cleanup for all columns...';
|
||||
|
||||
PERFORM fix_sort_order_duplicates();
|
||||
PERFORM fix_status_sort_order_duplicates();
|
||||
PERFORM fix_priority_sort_order_duplicates();
|
||||
PERFORM fix_phase_sort_order_duplicates();
|
||||
|
||||
RAISE NOTICE 'Completed sort order cleanup for all columns';
|
||||
END
|
||||
$$;
|
||||
|
||||
-- 3. VERIFICATION FUNCTION
|
||||
|
||||
-- Verify that duplicates have been fixed
|
||||
CREATE OR REPLACE FUNCTION verify_sort_order_integrity() RETURNS TABLE(
|
||||
column_name text,
|
||||
project_id uuid,
|
||||
duplicate_count bigint,
|
||||
status text
|
||||
)
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
-- Check sort_order duplicates
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
'sort_order'::text as column_name,
|
||||
t.project_id,
|
||||
COUNT(*) as duplicate_count,
|
||||
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
|
||||
FROM tasks t
|
||||
WHERE t.project_id IS NOT NULL
|
||||
GROUP BY t.project_id, t.sort_order
|
||||
HAVING COUNT(*) > 1;
|
||||
|
||||
-- Check status_sort_order duplicates
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
'status_sort_order'::text as column_name,
|
||||
t.project_id,
|
||||
COUNT(*) as duplicate_count,
|
||||
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
|
||||
FROM tasks t
|
||||
WHERE t.project_id IS NOT NULL
|
||||
GROUP BY t.project_id, t.status_sort_order
|
||||
HAVING COUNT(*) > 1;
|
||||
|
||||
-- Check priority_sort_order duplicates
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
'priority_sort_order'::text as column_name,
|
||||
t.project_id,
|
||||
COUNT(*) as duplicate_count,
|
||||
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
|
||||
FROM tasks t
|
||||
WHERE t.project_id IS NOT NULL
|
||||
GROUP BY t.project_id, t.priority_sort_order
|
||||
HAVING COUNT(*) > 1;
|
||||
|
||||
-- Check phase_sort_order duplicates
|
||||
RETURN QUERY
|
||||
SELECT
|
||||
'phase_sort_order'::text as column_name,
|
||||
t.project_id,
|
||||
COUNT(*) as duplicate_count,
|
||||
CASE WHEN COUNT(*) > 1 THEN 'DUPLICATES FOUND' ELSE 'OK' END as status
|
||||
FROM tasks t
|
||||
WHERE t.project_id IS NOT NULL
|
||||
GROUP BY t.project_id, t.phase_sort_order
|
||||
HAVING COUNT(*) > 1;
|
||||
|
||||
-- Note: member_sort_order verification removed - column no longer used
|
||||
|
||||
END
|
||||
$$;
|
||||
|
||||
-- 4. USAGE INSTRUCTIONS
|
||||
|
||||
/*
|
||||
USAGE:
|
||||
|
||||
1. First, run the detection queries to see which projects have duplicates
|
||||
2. Then run this to fix all duplicates:
|
||||
SELECT fix_all_duplicate_sort_orders();
|
||||
3. Finally, verify the fix worked:
|
||||
SELECT * FROM verify_sort_order_integrity();
|
||||
|
||||
If verification returns no rows, all duplicates have been fixed successfully.
|
||||
|
||||
WARNING: This will reassign sort order values based on current order + creation time.
|
||||
Make sure to backup your database before running these functions.
|
||||
*/
|
||||
@@ -0,0 +1,37 @@
|
||||
-- Migration: Add separate sort order columns for different grouping types
|
||||
-- This allows users to maintain different task orders when switching between grouping views
|
||||
|
||||
-- Add new sort order columns
|
||||
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS status_sort_order INTEGER DEFAULT 0;
|
||||
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS priority_sort_order INTEGER DEFAULT 0;
|
||||
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS phase_sort_order INTEGER DEFAULT 0;
|
||||
ALTER TABLE tasks ADD COLUMN IF NOT EXISTS member_sort_order INTEGER DEFAULT 0;
|
||||
|
||||
-- Initialize new columns with current sort_order values
|
||||
UPDATE tasks SET
|
||||
status_sort_order = sort_order,
|
||||
priority_sort_order = sort_order,
|
||||
phase_sort_order = sort_order,
|
||||
member_sort_order = sort_order
|
||||
WHERE status_sort_order = 0
|
||||
OR priority_sort_order = 0
|
||||
OR phase_sort_order = 0
|
||||
OR member_sort_order = 0;
|
||||
|
||||
-- Add constraints to ensure non-negative values
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_status_sort_order_check CHECK (status_sort_order >= 0);
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_priority_sort_order_check CHECK (priority_sort_order >= 0);
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_phase_sort_order_check CHECK (phase_sort_order >= 0);
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_member_sort_order_check CHECK (member_sort_order >= 0);
|
||||
|
||||
-- Add indexes for performance (since these will be used for ordering)
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_status_sort_order ON tasks(project_id, status_sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_priority_sort_order ON tasks(project_id, priority_sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_phase_sort_order ON tasks(project_id, phase_sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_member_sort_order ON tasks(project_id, member_sort_order);
|
||||
|
||||
-- Update comments for documentation
|
||||
COMMENT ON COLUMN tasks.status_sort_order IS 'Sort order when grouped by status';
|
||||
COMMENT ON COLUMN tasks.priority_sort_order IS 'Sort order when grouped by priority';
|
||||
COMMENT ON COLUMN tasks.phase_sort_order IS 'Sort order when grouped by phase';
|
||||
COMMENT ON COLUMN tasks.member_sort_order IS 'Sort order when grouped by members/assignees';
|
||||
@@ -0,0 +1,172 @@
|
||||
-- Migration: Update database functions to handle grouping-specific sort orders
|
||||
|
||||
-- Function to get the appropriate sort column name based on grouping type
|
||||
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
CASE _group_by
|
||||
WHEN 'status' THEN RETURN 'status_sort_order';
|
||||
WHEN 'priority' THEN RETURN 'priority_sort_order';
|
||||
WHEN 'phase' THEN RETURN 'phase_sort_order';
|
||||
WHEN 'members' THEN RETURN 'member_sort_order';
|
||||
ELSE RETURN 'sort_order'; -- fallback to general sort_order
|
||||
END CASE;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Updated bulk sort order function to handle different sort columns
|
||||
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_update_record RECORD;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
-- Get the appropriate sort column based on grouping
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Simple approach: update each task's sort_order from the provided array
|
||||
FOR _update_record IN
|
||||
SELECT
|
||||
(item->>'task_id')::uuid as task_id,
|
||||
(item->>'sort_order')::int as sort_order,
|
||||
(item->>'status_id')::uuid as status_id,
|
||||
(item->>'priority_id')::uuid as priority_id,
|
||||
(item->>'phase_id')::uuid as phase_id
|
||||
FROM json_array_elements(_updates) as item
|
||||
LOOP
|
||||
-- Update the appropriate sort column and other fields using dynamic SQL
|
||||
-- Only update sort_order if we're using the default sorting
|
||||
IF _sort_column = 'sort_order' THEN
|
||||
UPDATE tasks SET
|
||||
sort_order = _update_record.sort_order,
|
||||
status_id = COALESCE(_update_record.status_id, status_id),
|
||||
priority_id = COALESCE(_update_record.priority_id, priority_id)
|
||||
WHERE id = _update_record.task_id;
|
||||
ELSE
|
||||
-- Update only the grouping-specific sort column, not the main sort_order
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
|
||||
'status_id = COALESCE($2, status_id), ' ||
|
||||
'priority_id = COALESCE($3, priority_id) ' ||
|
||||
'WHERE id = $4';
|
||||
|
||||
EXECUTE _sql USING
|
||||
_update_record.sort_order,
|
||||
_update_record.status_id,
|
||||
_update_record.priority_id,
|
||||
_update_record.task_id;
|
||||
END IF;
|
||||
|
||||
-- Handle phase updates separately since it's in a different table
|
||||
IF _update_record.phase_id IS NOT NULL THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_update_record.task_id, _update_record.phase_id)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Updated main sort order change handler
|
||||
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_from_index INT;
|
||||
_to_index INT;
|
||||
_task_id UUID;
|
||||
_project_id UUID;
|
||||
_from_group UUID;
|
||||
_to_group UUID;
|
||||
_group_by TEXT;
|
||||
_batch_size INT := 100;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
_project_id = (_body ->> 'project_id')::UUID;
|
||||
_task_id = (_body ->> 'task_id')::UUID;
|
||||
_from_index = (_body ->> 'from_index')::INT;
|
||||
_to_index = (_body ->> 'to_index')::INT;
|
||||
_from_group = (_body ->> 'from_group')::UUID;
|
||||
_to_group = (_body ->> 'to_group')::UUID;
|
||||
_group_by = (_body ->> 'group_by')::TEXT;
|
||||
|
||||
-- Get the appropriate sort column
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Handle group changes
|
||||
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
|
||||
IF (_group_by = 'status') THEN
|
||||
UPDATE tasks
|
||||
SET status_id = _to_group
|
||||
WHERE id = _task_id
|
||||
AND status_id = _from_group
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'priority') THEN
|
||||
UPDATE tasks
|
||||
SET priority_id = _to_group
|
||||
WHERE id = _task_id
|
||||
AND priority_id = _from_group
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'phase') THEN
|
||||
IF (is_null_or_empty(_to_group) IS FALSE) THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_task_id, _to_group)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
|
||||
ELSE
|
||||
DELETE FROM task_phase WHERE task_id = _task_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Handle sort order changes using dynamic SQL
|
||||
IF (_from_index <> _to_index) THEN
|
||||
-- For the main sort_order column, we need to be careful about unique constraints
|
||||
IF _sort_column = 'sort_order' THEN
|
||||
-- Use a transaction-safe approach for the main sort_order column
|
||||
IF (_to_index > _from_index) THEN
|
||||
-- Moving down: decrease sort_order for items between old and new position
|
||||
UPDATE tasks SET sort_order = sort_order - 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order > _from_index
|
||||
AND sort_order <= _to_index;
|
||||
ELSE
|
||||
-- Moving up: increase sort_order for items between new and old position
|
||||
UPDATE tasks SET sort_order = sort_order + 1
|
||||
WHERE project_id = _project_id
|
||||
AND sort_order >= _to_index
|
||||
AND sort_order < _from_index;
|
||||
END IF;
|
||||
|
||||
-- Set the new sort_order for the moved task
|
||||
UPDATE tasks SET sort_order = _to_index WHERE id = _task_id;
|
||||
ELSE
|
||||
-- For grouping-specific columns, use dynamic SQL since there's no unique constraint
|
||||
IF (_to_index > _from_index) THEN
|
||||
-- Moving down: decrease sort_order for items between old and new position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1 ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
|
||||
EXECUTE _sql USING _project_id, _from_index, _to_index;
|
||||
ELSE
|
||||
-- Moving up: increase sort_order for items between new and old position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1 ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
|
||||
EXECUTE _sql USING _project_id, _to_index, _from_index;
|
||||
END IF;
|
||||
|
||||
-- Set the new sort_order for the moved task
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1 WHERE id = $2';
|
||||
EXECUTE _sql USING _to_index, _task_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
@@ -0,0 +1,179 @@
|
||||
-- Migration: Fix sort order constraint violations
|
||||
|
||||
-- First, let's ensure all existing tasks have unique sort_order values within each project
|
||||
-- This is a one-time fix to ensure data consistency
|
||||
|
||||
DO $$
|
||||
DECLARE
|
||||
_project RECORD;
|
||||
_task RECORD;
|
||||
_counter INTEGER;
|
||||
BEGIN
|
||||
-- For each project, reassign sort_order values to ensure uniqueness
|
||||
FOR _project IN
|
||||
SELECT DISTINCT project_id
|
||||
FROM tasks
|
||||
WHERE project_id IS NOT NULL
|
||||
LOOP
|
||||
_counter := 0;
|
||||
|
||||
-- Reassign sort_order values sequentially for this project
|
||||
FOR _task IN
|
||||
SELECT id
|
||||
FROM tasks
|
||||
WHERE project_id = _project.project_id
|
||||
ORDER BY sort_order, created_at
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET sort_order = _counter
|
||||
WHERE id = _task.id;
|
||||
|
||||
_counter := _counter + 1;
|
||||
END LOOP;
|
||||
END LOOP;
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Now create a better version of our functions that properly handles the constraints
|
||||
|
||||
-- Updated bulk sort order function that avoids sort_order conflicts
|
||||
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_update_record RECORD;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
-- Get the appropriate sort column based on grouping
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Process each update record
|
||||
FOR _update_record IN
|
||||
SELECT
|
||||
(item->>'task_id')::uuid as task_id,
|
||||
(item->>'sort_order')::int as sort_order,
|
||||
(item->>'status_id')::uuid as status_id,
|
||||
(item->>'priority_id')::uuid as priority_id,
|
||||
(item->>'phase_id')::uuid as phase_id
|
||||
FROM json_array_elements(_updates) as item
|
||||
LOOP
|
||||
-- Update the grouping-specific sort column and other fields
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
|
||||
'status_id = COALESCE($2, status_id), ' ||
|
||||
'priority_id = COALESCE($3, priority_id), ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE id = $4';
|
||||
|
||||
EXECUTE _sql USING
|
||||
_update_record.sort_order,
|
||||
_update_record.status_id,
|
||||
_update_record.priority_id,
|
||||
_update_record.task_id;
|
||||
|
||||
-- Handle phase updates separately since it's in a different table
|
||||
IF _update_record.phase_id IS NOT NULL THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_update_record.task_id, _update_record.phase_id)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Also update the helper function to be more explicit
|
||||
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
CASE _group_by
|
||||
WHEN 'status' THEN RETURN 'status_sort_order';
|
||||
WHEN 'priority' THEN RETURN 'priority_sort_order';
|
||||
WHEN 'phase' THEN RETURN 'phase_sort_order';
|
||||
WHEN 'members' THEN RETURN 'member_sort_order';
|
||||
-- For backward compatibility, still support general sort_order but be explicit
|
||||
WHEN 'general' THEN RETURN 'sort_order';
|
||||
ELSE RETURN 'status_sort_order'; -- Default to status sorting
|
||||
END CASE;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Updated main sort order change handler that avoids conflicts
|
||||
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_from_index INT;
|
||||
_to_index INT;
|
||||
_task_id UUID;
|
||||
_project_id UUID;
|
||||
_from_group UUID;
|
||||
_to_group UUID;
|
||||
_group_by TEXT;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
_project_id = (_body ->> 'project_id')::UUID;
|
||||
_task_id = (_body ->> 'task_id')::UUID;
|
||||
_from_index = (_body ->> 'from_index')::INT;
|
||||
_to_index = (_body ->> 'to_index')::INT;
|
||||
_from_group = (_body ->> 'from_group')::UUID;
|
||||
_to_group = (_body ->> 'to_group')::UUID;
|
||||
_group_by = (_body ->> 'group_by')::TEXT;
|
||||
|
||||
-- Get the appropriate sort column
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Handle group changes first
|
||||
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
|
||||
IF (_group_by = 'status') THEN
|
||||
UPDATE tasks
|
||||
SET status_id = _to_group, updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'priority') THEN
|
||||
UPDATE tasks
|
||||
SET priority_id = _to_group, updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'phase') THEN
|
||||
IF (is_null_or_empty(_to_group) IS FALSE) THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_task_id, _to_group)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
|
||||
ELSE
|
||||
DELETE FROM task_phase WHERE task_id = _task_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Handle sort order changes for the grouping-specific column only
|
||||
IF (_from_index <> _to_index) THEN
|
||||
-- Update the grouping-specific sort order (no unique constraint issues)
|
||||
IF (_to_index > _from_index) THEN
|
||||
-- Moving down: decrease sort order for items between old and new position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1, ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
|
||||
EXECUTE _sql USING _project_id, _from_index, _to_index;
|
||||
ELSE
|
||||
-- Moving up: increase sort order for items between new and old position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1, ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
|
||||
EXECUTE _sql USING _project_id, _to_index, _from_index;
|
||||
END IF;
|
||||
|
||||
-- Set the new sort order for the moved task
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, updated_at = CURRENT_TIMESTAMP WHERE id = $2';
|
||||
EXECUTE _sql USING _to_index, _task_id;
|
||||
END IF;
|
||||
END;
|
||||
$$;
|
||||
@@ -0,0 +1,93 @@
|
||||
-- Migration: Add survey tables for account setup questionnaire
|
||||
-- Date: 2025-07-24
|
||||
-- Description: Creates tables to store survey questions and user responses for account setup flow
|
||||
|
||||
BEGIN;
|
||||
|
||||
-- Create surveys table to define different types of surveys
|
||||
CREATE TABLE IF NOT EXISTS surveys (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
survey_type VARCHAR(50) DEFAULT 'account_setup' NOT NULL, -- 'account_setup', 'onboarding', 'feedback'
|
||||
is_active BOOLEAN DEFAULT TRUE NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
-- Create survey_questions table to store individual questions
|
||||
CREATE TABLE IF NOT EXISTS survey_questions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL,
|
||||
question_key VARCHAR(100) NOT NULL, -- Used for localization keys
|
||||
question_type VARCHAR(50) NOT NULL, -- 'single_choice', 'multiple_choice', 'text'
|
||||
is_required BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
options JSONB, -- For choice questions, store options as JSON array
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
-- Create survey_responses table to track user responses to surveys
|
||||
CREATE TABLE IF NOT EXISTS survey_responses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES users(id) ON DELETE CASCADE NOT NULL,
|
||||
is_completed BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
started_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
completed_at TIMESTAMP,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
-- Create survey_answers table to store individual question answers
|
||||
CREATE TABLE IF NOT EXISTS survey_answers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
response_id UUID REFERENCES survey_responses(id) ON DELETE CASCADE NOT NULL,
|
||||
question_id UUID REFERENCES survey_questions(id) ON DELETE CASCADE NOT NULL,
|
||||
answer_text TEXT,
|
||||
answer_json JSONB, -- For multiple choice answers stored as array
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
-- Add performance indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_surveys_type_active ON surveys(survey_type, is_active);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_questions_survey_order ON survey_questions(survey_id, sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_responses_user_survey ON survey_responses(user_id, survey_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_responses_completed ON survey_responses(survey_id, is_completed);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_answers_response ON survey_answers(response_id);
|
||||
|
||||
-- Add constraints
|
||||
ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_sort_order_check CHECK (sort_order >= 0);
|
||||
ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_type_check CHECK (question_type IN ('single_choice', 'multiple_choice', 'text'));
|
||||
|
||||
-- Add unique constraint to prevent duplicate responses per user per survey
|
||||
ALTER TABLE survey_responses ADD CONSTRAINT unique_user_survey_response UNIQUE (user_id, survey_id);
|
||||
|
||||
-- Add unique constraint to prevent duplicate answers per question per response
|
||||
ALTER TABLE survey_answers ADD CONSTRAINT unique_response_question_answer UNIQUE (response_id, question_id);
|
||||
|
||||
-- Insert the default account setup survey
|
||||
INSERT INTO surveys (name, description, survey_type, is_active) VALUES
|
||||
('Account Setup Survey', 'Initial questionnaire during account setup to understand user needs', 'account_setup', true)
|
||||
ON CONFLICT DO NOTHING;
|
||||
|
||||
-- Get the survey ID for inserting questions
|
||||
DO $$
|
||||
DECLARE
|
||||
survey_uuid UUID;
|
||||
BEGIN
|
||||
SELECT id INTO survey_uuid FROM surveys WHERE survey_type = 'account_setup' AND name = 'Account Setup Survey' LIMIT 1;
|
||||
|
||||
-- Insert survey questions
|
||||
INSERT INTO survey_questions (survey_id, question_key, question_type, is_required, sort_order, options) VALUES
|
||||
(survey_uuid, 'organization_type', 'single_choice', true, 1, '["freelancer", "startup", "small_medium_business", "agency", "enterprise", "other"]'),
|
||||
(survey_uuid, 'user_role', 'single_choice', true, 2, '["founder_ceo", "project_manager", "software_developer", "designer", "operations", "other"]'),
|
||||
(survey_uuid, 'main_use_cases', 'multiple_choice', true, 3, '["task_management", "team_collaboration", "resource_planning", "client_communication", "time_tracking", "other"]'),
|
||||
(survey_uuid, 'previous_tools', 'text', false, 4, null),
|
||||
(survey_uuid, 'how_heard_about', 'single_choice', false, 5, '["google_search", "twitter", "linkedin", "friend_colleague", "blog_article", "other"]')
|
||||
ON CONFLICT DO NOTHING;
|
||||
END $$;
|
||||
|
||||
COMMIT;
|
||||
72
worklenz-backend/database/pg-migrations/README.md
Normal file
72
worklenz-backend/database/pg-migrations/README.md
Normal file
@@ -0,0 +1,72 @@
|
||||
# Node-pg-migrate Migrations
|
||||
|
||||
This directory contains database migrations managed by node-pg-migrate.
|
||||
|
||||
## Migration Commands
|
||||
|
||||
- `npm run migrate:create -- migration-name` - Create a new migration file
|
||||
- `npm run migrate:up` - Run all pending migrations
|
||||
- `npm run migrate:down` - Rollback the last migration
|
||||
- `npm run migrate:redo` - Rollback and re-run the last migration
|
||||
|
||||
## Migration File Format
|
||||
|
||||
Migrations are JavaScript files with timestamp prefixes (e.g., `20250115000000_performance-indexes.js`).
|
||||
|
||||
Each migration file exports two functions:
|
||||
- `exports.up` - Contains the forward migration logic
|
||||
- `exports.down` - Contains the rollback logic
|
||||
|
||||
## Best Practices
|
||||
|
||||
1. **Always use IF EXISTS/IF NOT EXISTS checks** to make migrations idempotent
|
||||
2. **Test migrations locally** before deploying to production
|
||||
3. **Include rollback logic** in the `down` function for all changes
|
||||
4. **Use descriptive names** for migration files
|
||||
5. **Keep migrations focused** - one logical change per migration
|
||||
|
||||
## Example Migration
|
||||
|
||||
```javascript
|
||||
exports.up = pgm => {
|
||||
// Create table with IF NOT EXISTS
|
||||
pgm.createTable('users', {
|
||||
id: 'id',
|
||||
name: { type: 'varchar(100)', notNull: true },
|
||||
created_at: {
|
||||
type: 'timestamp',
|
||||
notNull: true,
|
||||
default: pgm.func('current_timestamp')
|
||||
}
|
||||
}, { ifNotExists: true });
|
||||
|
||||
// Add index with IF NOT EXISTS
|
||||
pgm.createIndex('users', 'name', {
|
||||
name: 'idx_users_name',
|
||||
ifNotExists: true
|
||||
});
|
||||
};
|
||||
|
||||
exports.down = pgm => {
|
||||
// Drop in reverse order
|
||||
pgm.dropIndex('users', 'name', {
|
||||
name: 'idx_users_name',
|
||||
ifExists: true
|
||||
});
|
||||
|
||||
pgm.dropTable('users', { ifExists: true });
|
||||
};
|
||||
```
|
||||
|
||||
## Migration History
|
||||
|
||||
The `pgmigrations` table tracks which migrations have been run. Do not modify this table manually.
|
||||
|
||||
## Converting from SQL Migrations
|
||||
|
||||
When converting SQL migrations to node-pg-migrate format:
|
||||
|
||||
1. Wrap SQL statements in `pgm.sql()` calls
|
||||
2. Use node-pg-migrate helper methods where possible (createTable, addColumns, etc.)
|
||||
3. Always include `IF EXISTS/IF NOT EXISTS` checks
|
||||
4. Ensure proper rollback logic in the `down` function
|
||||
@@ -1391,27 +1391,30 @@ ALTER TABLE task_work_log
|
||||
CHECK (time_spent >= (0)::NUMERIC);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS tasks (
|
||||
id UUID DEFAULT uuid_generate_v4() NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
done BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
total_minutes NUMERIC DEFAULT 0 NOT NULL,
|
||||
archived BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
task_no BIGINT NOT NULL,
|
||||
start_date TIMESTAMP WITH TIME ZONE,
|
||||
end_date TIMESTAMP WITH TIME ZONE,
|
||||
priority_id UUID NOT NULL,
|
||||
project_id UUID NOT NULL,
|
||||
reporter_id UUID NOT NULL,
|
||||
parent_task_id UUID,
|
||||
status_id UUID NOT NULL,
|
||||
completed_at TIMESTAMP WITH TIME ZONE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
roadmap_sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
billable BOOLEAN DEFAULT TRUE,
|
||||
schedule_id UUID
|
||||
id UUID DEFAULT uuid_generate_v4() NOT NULL,
|
||||
name TEXT NOT NULL,
|
||||
description TEXT,
|
||||
done BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
total_minutes NUMERIC DEFAULT 0 NOT NULL,
|
||||
archived BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
task_no BIGINT NOT NULL,
|
||||
start_date TIMESTAMP WITH TIME ZONE,
|
||||
end_date TIMESTAMP WITH TIME ZONE,
|
||||
priority_id UUID NOT NULL,
|
||||
project_id UUID NOT NULL,
|
||||
reporter_id UUID NOT NULL,
|
||||
parent_task_id UUID,
|
||||
status_id UUID NOT NULL,
|
||||
completed_at TIMESTAMP WITH TIME ZONE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP NOT NULL,
|
||||
sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
roadmap_sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
status_sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
priority_sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
phase_sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
billable BOOLEAN DEFAULT TRUE,
|
||||
schedule_id UUID
|
||||
);
|
||||
|
||||
ALTER TABLE tasks
|
||||
@@ -1499,6 +1502,21 @@ ALTER TABLE tasks
|
||||
ADD CONSTRAINT tasks_total_minutes_check
|
||||
CHECK ((total_minutes >= (0)::NUMERIC) AND (total_minutes <= (999999)::NUMERIC));
|
||||
|
||||
-- Add constraints for new sort order columns
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_status_sort_order_check CHECK (status_sort_order >= 0);
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_priority_sort_order_check CHECK (priority_sort_order >= 0);
|
||||
ALTER TABLE tasks ADD CONSTRAINT tasks_phase_sort_order_check CHECK (phase_sort_order >= 0);
|
||||
|
||||
-- Add indexes for performance on new sort order columns
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_status_sort_order ON tasks(project_id, status_sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_priority_sort_order ON tasks(project_id, priority_sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_tasks_phase_sort_order ON tasks(project_id, phase_sort_order);
|
||||
|
||||
-- Add comments for documentation
|
||||
COMMENT ON COLUMN tasks.status_sort_order IS 'Sort order when grouped by status';
|
||||
COMMENT ON COLUMN tasks.priority_sort_order IS 'Sort order when grouped by priority';
|
||||
COMMENT ON COLUMN tasks.phase_sort_order IS 'Sort order when grouped by phase';
|
||||
|
||||
CREATE TABLE IF NOT EXISTS tasks_assignees (
|
||||
task_id UUID NOT NULL,
|
||||
project_member_id UUID NOT NULL,
|
||||
@@ -2279,3 +2297,60 @@ ALTER TABLE organization_working_days
|
||||
ALTER TABLE organization_working_days
|
||||
ADD CONSTRAINT org_organization_id_fk
|
||||
FOREIGN KEY (organization_id) REFERENCES organizations;
|
||||
|
||||
-- Survey tables for account setup questionnaire
|
||||
CREATE TABLE IF NOT EXISTS surveys (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
name VARCHAR(255) NOT NULL,
|
||||
description TEXT,
|
||||
survey_type VARCHAR(50) DEFAULT 'account_setup' NOT NULL,
|
||||
is_active BOOLEAN DEFAULT TRUE NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS survey_questions (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL,
|
||||
question_key VARCHAR(100) NOT NULL,
|
||||
question_type VARCHAR(50) NOT NULL,
|
||||
is_required BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
sort_order INTEGER DEFAULT 0 NOT NULL,
|
||||
options JSONB,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS survey_responses (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
survey_id UUID REFERENCES surveys(id) ON DELETE CASCADE NOT NULL,
|
||||
user_id UUID REFERENCES users(id) ON DELETE CASCADE NOT NULL,
|
||||
is_completed BOOLEAN DEFAULT FALSE NOT NULL,
|
||||
started_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
completed_at TIMESTAMP,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS survey_answers (
|
||||
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
|
||||
response_id UUID REFERENCES survey_responses(id) ON DELETE CASCADE NOT NULL,
|
||||
question_id UUID REFERENCES survey_questions(id) ON DELETE CASCADE NOT NULL,
|
||||
answer_text TEXT,
|
||||
answer_json JSONB,
|
||||
created_at TIMESTAMP DEFAULT now() NOT NULL,
|
||||
updated_at TIMESTAMP DEFAULT now() NOT NULL
|
||||
);
|
||||
|
||||
-- Survey table indexes
|
||||
CREATE INDEX IF NOT EXISTS idx_surveys_type_active ON surveys(survey_type, is_active);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_questions_survey_order ON survey_questions(survey_id, sort_order);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_responses_user_survey ON survey_responses(user_id, survey_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_responses_completed ON survey_responses(survey_id, is_completed);
|
||||
CREATE INDEX IF NOT EXISTS idx_survey_answers_response ON survey_answers(response_id);
|
||||
|
||||
-- Survey table constraints
|
||||
ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_sort_order_check CHECK (sort_order >= 0);
|
||||
ALTER TABLE survey_questions ADD CONSTRAINT survey_questions_type_check CHECK (question_type IN ('single_choice', 'multiple_choice', 'text'));
|
||||
ALTER TABLE survey_responses ADD CONSTRAINT unique_user_survey_response UNIQUE (user_id, survey_id);
|
||||
ALTER TABLE survey_answers ADD CONSTRAINT unique_response_question_answer UNIQUE (response_id, question_id);
|
||||
|
||||
@@ -142,3 +142,25 @@ DROP FUNCTION sys_insert_license_types();
|
||||
INSERT INTO timezones (name, abbrev, utc_offset)
|
||||
SELECT name, abbrev, utc_offset
|
||||
FROM pg_timezone_names;
|
||||
|
||||
-- Insert default account setup survey
|
||||
INSERT INTO surveys (name, description, survey_type, is_active) VALUES
|
||||
('Account Setup Survey', 'Initial questionnaire during account setup to understand user needs', 'account_setup', true)
|
||||
ON CONFLICT DO NOTHING;
|
||||
|
||||
-- Insert survey questions for account setup survey
|
||||
DO $$
|
||||
DECLARE
|
||||
survey_uuid UUID;
|
||||
BEGIN
|
||||
SELECT id INTO survey_uuid FROM surveys WHERE survey_type = 'account_setup' AND name = 'Account Setup Survey' LIMIT 1;
|
||||
|
||||
-- Insert survey questions
|
||||
INSERT INTO survey_questions (survey_id, question_key, question_type, is_required, sort_order, options) VALUES
|
||||
(survey_uuid, 'organization_type', 'single_choice', true, 1, '["freelancer", "startup", "small_medium_business", "agency", "enterprise", "other"]'),
|
||||
(survey_uuid, 'user_role', 'single_choice', true, 2, '["founder_ceo", "project_manager", "software_developer", "designer", "operations", "other"]'),
|
||||
(survey_uuid, 'main_use_cases', 'multiple_choice', true, 3, '["task_management", "team_collaboration", "resource_planning", "client_communication", "time_tracking", "other"]'),
|
||||
(survey_uuid, 'previous_tools', 'text', false, 4, null),
|
||||
(survey_uuid, 'how_heard_about', 'single_choice', false, 5, '["google_search", "twitter", "linkedin", "friend_colleague", "blog_article", "other"]')
|
||||
ON CONFLICT DO NOTHING;
|
||||
END $$;
|
||||
|
||||
@@ -4313,6 +4313,24 @@ BEGIN
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Helper function to get the appropriate sort column name based on grouping type
|
||||
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
CASE _group_by
|
||||
WHEN 'status' THEN RETURN 'status_sort_order';
|
||||
WHEN 'priority' THEN RETURN 'priority_sort_order';
|
||||
WHEN 'phase' THEN RETURN 'phase_sort_order';
|
||||
WHEN 'members' THEN RETURN 'member_sort_order';
|
||||
-- For backward compatibility, still support general sort_order but be explicit
|
||||
WHEN 'general' THEN RETURN 'sort_order';
|
||||
ELSE RETURN 'status_sort_order'; -- Default to status sorting
|
||||
END CASE;
|
||||
END;
|
||||
$$;
|
||||
|
||||
CREATE OR REPLACE FUNCTION handle_task_list_sort_order_change(_body json) RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
@@ -4325,66 +4343,67 @@ DECLARE
|
||||
_from_group UUID;
|
||||
_to_group UUID;
|
||||
_group_by TEXT;
|
||||
_batch_size INT := 100; -- PERFORMANCE OPTIMIZATION: Batch size for large updates
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
_project_id = (_body ->> 'project_id')::UUID;
|
||||
_task_id = (_body ->> 'task_id')::UUID;
|
||||
|
||||
_from_index = (_body ->> 'from_index')::INT; -- from sort_order
|
||||
_to_index = (_body ->> 'to_index')::INT; -- to sort_order
|
||||
|
||||
_from_index = (_body ->> 'from_index')::INT;
|
||||
_to_index = (_body ->> 'to_index')::INT;
|
||||
_from_group = (_body ->> 'from_group')::UUID;
|
||||
_to_group = (_body ->> 'to_group')::UUID;
|
||||
|
||||
_group_by = (_body ->> 'group_by')::TEXT;
|
||||
|
||||
-- PERFORMANCE OPTIMIZATION: Use CTE for better query planning
|
||||
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL)
|
||||
THEN
|
||||
-- PERFORMANCE OPTIMIZATION: Batch update group changes
|
||||
IF (_group_by = 'status')
|
||||
THEN
|
||||
|
||||
-- Get the appropriate sort column
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Handle group changes first
|
||||
IF (_from_group <> _to_group OR (_from_group <> _to_group) IS NULL) THEN
|
||||
IF (_group_by = 'status') THEN
|
||||
UPDATE tasks
|
||||
SET status_id = _to_group
|
||||
SET status_id = _to_group, updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id
|
||||
AND status_id = _from_group
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'priority')
|
||||
THEN
|
||||
|
||||
IF (_group_by = 'priority') THEN
|
||||
UPDATE tasks
|
||||
SET priority_id = _to_group
|
||||
SET priority_id = _to_group, updated_at = CURRENT_TIMESTAMP
|
||||
WHERE id = _task_id
|
||||
AND priority_id = _from_group
|
||||
AND project_id = _project_id;
|
||||
END IF;
|
||||
|
||||
IF (_group_by = 'phase')
|
||||
THEN
|
||||
IF (is_null_or_empty(_to_group) IS FALSE)
|
||||
THEN
|
||||
|
||||
IF (_group_by = 'phase') THEN
|
||||
IF (is_null_or_empty(_to_group) IS FALSE) THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_task_id, _to_group)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _to_group;
|
||||
END IF;
|
||||
IF (is_null_or_empty(_to_group) IS TRUE)
|
||||
THEN
|
||||
DELETE
|
||||
FROM task_phase
|
||||
WHERE task_id = _task_id;
|
||||
ELSE
|
||||
DELETE FROM task_phase WHERE task_id = _task_id;
|
||||
END IF;
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- PERFORMANCE OPTIMIZATION: Optimized sort order handling
|
||||
IF ((_body ->> 'to_last_index')::BOOLEAN IS TRUE AND _from_index < _to_index)
|
||||
THEN
|
||||
PERFORM handle_task_list_sort_inside_group_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size);
|
||||
-- Handle sort order changes for the grouping-specific column only
|
||||
IF (_from_index <> _to_index) THEN
|
||||
-- Update the grouping-specific sort order (no unique constraint issues)
|
||||
IF (_to_index > _from_index) THEN
|
||||
-- Moving down: decrease sort order for items between old and new position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' - 1, ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' > $2 AND ' || _sort_column || ' <= $3';
|
||||
EXECUTE _sql USING _project_id, _from_index, _to_index;
|
||||
ELSE
|
||||
PERFORM handle_task_list_sort_between_groups_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size);
|
||||
-- Moving up: increase sort order for items between new and old position
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = ' || _sort_column || ' + 1, ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE project_id = $1 AND ' || _sort_column || ' >= $2 AND ' || _sort_column || ' < $3';
|
||||
EXECUTE _sql USING _project_id, _to_index, _from_index;
|
||||
END IF;
|
||||
ELSE
|
||||
PERFORM handle_task_list_sort_inside_group_optimized(_from_index, _to_index, _task_id, _project_id, _batch_size);
|
||||
|
||||
-- Set the new sort order for the moved task
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, updated_at = CURRENT_TIMESTAMP WHERE id = $2';
|
||||
EXECUTE _sql USING _to_index, _task_id;
|
||||
END IF;
|
||||
END
|
||||
$$;
|
||||
@@ -4589,31 +4608,31 @@ BEGIN
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Progress', 'PROGRESS', 3, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Members', 'ASSIGNEES', 4, TRUE);
|
||||
VALUES (_project_id, 'Status', 'STATUS', 4, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Labels', 'LABELS', 5, TRUE);
|
||||
VALUES (_project_id, 'Members', 'ASSIGNEES', 5, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Status', 'STATUS', 6, TRUE);
|
||||
VALUES (_project_id, 'Labels', 'LABELS', 6, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Priority', 'PRIORITY', 7, TRUE);
|
||||
VALUES (_project_id, 'Phase', 'PHASE', 7, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Time Tracking', 'TIME_TRACKING', 8, TRUE);
|
||||
VALUES (_project_id, 'Priority', 'PRIORITY', 8, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Estimation', 'ESTIMATION', 9, FALSE);
|
||||
VALUES (_project_id, 'Time Tracking', 'TIME_TRACKING', 9, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Start Date', 'START_DATE', 10, FALSE);
|
||||
VALUES (_project_id, 'Estimation', 'ESTIMATION', 10, FALSE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Due Date', 'DUE_DATE', 11, TRUE);
|
||||
VALUES (_project_id, 'Start Date', 'START_DATE', 11, FALSE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Completed Date', 'COMPLETED_DATE', 12, FALSE);
|
||||
VALUES (_project_id, 'Due Date', 'DUE_DATE', 12, TRUE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Created Date', 'CREATED_DATE', 13, FALSE);
|
||||
VALUES (_project_id, 'Completed Date', 'COMPLETED_DATE', 13, FALSE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Last Updated', 'LAST_UPDATED', 14, FALSE);
|
||||
VALUES (_project_id, 'Created Date', 'CREATED_DATE', 14, FALSE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Reporter', 'REPORTER', 15, FALSE);
|
||||
VALUES (_project_id, 'Last Updated', 'LAST_UPDATED', 15, FALSE);
|
||||
INSERT INTO project_task_list_cols (project_id, name, key, index, pinned)
|
||||
VALUES (_project_id, 'Phase', 'PHASE', 16, FALSE);
|
||||
VALUES (_project_id, 'Reporter', 'REPORTER', 16, FALSE);
|
||||
END
|
||||
$$;
|
||||
|
||||
@@ -6521,15 +6540,20 @@ BEGIN
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Simple function to update task sort orders in bulk
|
||||
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json) RETURNS void
|
||||
-- Updated bulk sort order function that avoids sort_order conflicts
|
||||
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_update_record RECORD;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
-- Simple approach: update each task's sort_order from the provided array
|
||||
-- Get the appropriate sort column based on grouping
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Process each update record
|
||||
FOR _update_record IN
|
||||
SELECT
|
||||
(item->>'task_id')::uuid as task_id,
|
||||
@@ -6539,12 +6563,18 @@ BEGIN
|
||||
(item->>'phase_id')::uuid as phase_id
|
||||
FROM json_array_elements(_updates) as item
|
||||
LOOP
|
||||
UPDATE tasks
|
||||
SET
|
||||
sort_order = _update_record.sort_order,
|
||||
status_id = COALESCE(_update_record.status_id, status_id),
|
||||
priority_id = COALESCE(_update_record.priority_id, priority_id)
|
||||
WHERE id = _update_record.task_id;
|
||||
-- Update the grouping-specific sort column and other fields
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
|
||||
'status_id = COALESCE($2, status_id), ' ||
|
||||
'priority_id = COALESCE($3, priority_id), ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE id = $4';
|
||||
|
||||
EXECUTE _sql USING
|
||||
_update_record.sort_order,
|
||||
_update_record.status_id,
|
||||
_update_record.priority_id,
|
||||
_update_record.task_id;
|
||||
|
||||
-- Handle phase updates separately since it's in a different table
|
||||
IF _update_record.phase_id IS NOT NULL THEN
|
||||
@@ -6555,3 +6585,66 @@ BEGIN
|
||||
END LOOP;
|
||||
END
|
||||
$$;
|
||||
|
||||
-- Function to get the appropriate sort column name based on grouping type
|
||||
CREATE OR REPLACE FUNCTION get_sort_column_name(_group_by TEXT) RETURNS TEXT
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
BEGIN
|
||||
CASE _group_by
|
||||
WHEN 'status' THEN RETURN 'status_sort_order';
|
||||
WHEN 'priority' THEN RETURN 'priority_sort_order';
|
||||
WHEN 'phase' THEN RETURN 'phase_sort_order';
|
||||
-- For backward compatibility, still support general sort_order but be explicit
|
||||
WHEN 'general' THEN RETURN 'sort_order';
|
||||
ELSE RETURN 'status_sort_order'; -- Default to status sorting
|
||||
END CASE;
|
||||
END;
|
||||
$$;
|
||||
|
||||
-- Updated bulk sort order function to handle different sort columns
|
||||
CREATE OR REPLACE FUNCTION update_task_sort_orders_bulk(_updates json, _group_by text DEFAULT 'status') RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS
|
||||
$$
|
||||
DECLARE
|
||||
_update_record RECORD;
|
||||
_sort_column TEXT;
|
||||
_sql TEXT;
|
||||
BEGIN
|
||||
-- Get the appropriate sort column based on grouping
|
||||
_sort_column := get_sort_column_name(_group_by);
|
||||
|
||||
-- Process each update record
|
||||
FOR _update_record IN
|
||||
SELECT
|
||||
(item->>'task_id')::uuid as task_id,
|
||||
(item->>'sort_order')::int as sort_order,
|
||||
(item->>'status_id')::uuid as status_id,
|
||||
(item->>'priority_id')::uuid as priority_id,
|
||||
(item->>'phase_id')::uuid as phase_id
|
||||
FROM json_array_elements(_updates) as item
|
||||
LOOP
|
||||
-- Update the grouping-specific sort column and other fields
|
||||
_sql := 'UPDATE tasks SET ' || _sort_column || ' = $1, ' ||
|
||||
'status_id = COALESCE($2, status_id), ' ||
|
||||
'priority_id = COALESCE($3, priority_id), ' ||
|
||||
'updated_at = CURRENT_TIMESTAMP ' ||
|
||||
'WHERE id = $4';
|
||||
|
||||
EXECUTE _sql USING
|
||||
_update_record.sort_order,
|
||||
_update_record.status_id,
|
||||
_update_record.priority_id,
|
||||
_update_record.task_id;
|
||||
|
||||
-- Handle phase updates separately since it's in a different table
|
||||
IF _update_record.phase_id IS NOT NULL THEN
|
||||
INSERT INTO task_phase (task_id, phase_id)
|
||||
VALUES (_update_record.task_id, _update_record.phase_id)
|
||||
ON CONFLICT (task_id) DO UPDATE SET phase_id = _update_record.phase_id;
|
||||
END IF;
|
||||
END LOOP;
|
||||
END;
|
||||
$$;
|
||||
|
||||
@@ -132,3 +132,139 @@ CREATE INDEX IF NOT EXISTS projects_team_id_index
|
||||
CREATE INDEX IF NOT EXISTS projects_team_id_name_index
|
||||
ON projects (team_id, name);
|
||||
|
||||
-- Performance indexes for optimized tasks queries
|
||||
-- From migration: 20250115000000-performance-indexes.sql
|
||||
|
||||
-- Composite index for main task filtering
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_archived_parent
|
||||
ON tasks(project_id, archived, parent_task_id)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for status joins
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_status_project
|
||||
ON tasks(status_id, project_id)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for assignees lookup
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_assignees_task_member
|
||||
ON tasks_assignees(task_id, team_member_id);
|
||||
|
||||
-- Index for phase lookup
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_phase_task_phase
|
||||
ON task_phase(task_id, phase_id);
|
||||
|
||||
-- Index for subtask counting
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_parent_archived
|
||||
ON tasks(parent_task_id, archived)
|
||||
WHERE parent_task_id IS NOT NULL AND archived = FALSE;
|
||||
|
||||
-- Index for labels
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_labels_task_label
|
||||
ON task_labels(task_id, label_id);
|
||||
|
||||
-- Index for comments count
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_comments_task
|
||||
ON task_comments(task_id);
|
||||
|
||||
-- Index for attachments count
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_attachments_task
|
||||
ON task_attachments(task_id);
|
||||
|
||||
-- Index for work log aggregation
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_work_log_task
|
||||
ON task_work_log(task_id);
|
||||
|
||||
-- Index for subscribers check
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_subscribers_task
|
||||
ON task_subscribers(task_id);
|
||||
|
||||
-- Index for dependencies check
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_dependencies_task
|
||||
ON task_dependencies(task_id);
|
||||
|
||||
-- Index for timers lookup
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_timers_task_user
|
||||
ON task_timers(task_id, user_id);
|
||||
|
||||
-- Index for custom columns
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_cc_column_values_task
|
||||
ON cc_column_values(task_id);
|
||||
|
||||
-- Index for team member info view optimization
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_members_team_user
|
||||
ON team_members(team_id, user_id)
|
||||
WHERE active = TRUE;
|
||||
|
||||
-- Index for notification settings
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_notification_settings_user_team
|
||||
ON notification_settings(user_id, team_id);
|
||||
|
||||
-- Index for task status categories
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_statuses_category
|
||||
ON task_statuses(category_id, project_id);
|
||||
|
||||
-- Index for project phases
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_project_phases_project_sort
|
||||
ON project_phases(project_id, sort_index);
|
||||
|
||||
-- Index for task priorities
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_priorities_value
|
||||
ON task_priorities(value);
|
||||
|
||||
-- Index for team labels
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_labels_team
|
||||
ON team_labels(team_id);
|
||||
|
||||
-- Advanced performance indexes for task optimization
|
||||
|
||||
-- Composite index for task main query optimization (covers most WHERE conditions)
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_performance_main
|
||||
ON tasks(project_id, archived, parent_task_id, status_id, priority_id)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for sorting by sort_order with project filter
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_project_sort_order
|
||||
ON tasks(project_id, sort_order)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for email_invitations to optimize team_member_info_view
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_email_invitations_team_member
|
||||
ON email_invitations(team_member_id);
|
||||
|
||||
-- Covering index for task status with category information
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_statuses_covering
|
||||
ON task_statuses(id, category_id, project_id);
|
||||
|
||||
-- Index for task aggregation queries (parent task progress calculation)
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_parent_status_archived
|
||||
ON tasks(parent_task_id, status_id, archived)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for project team member filtering
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_team_members_project_lookup
|
||||
ON team_members(team_id, active, user_id)
|
||||
WHERE active = TRUE;
|
||||
|
||||
-- Covering index for tasks with frequently accessed columns
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_covering_main
|
||||
ON tasks(id, project_id, archived, parent_task_id, status_id, priority_id, sort_order, name)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for task search functionality
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_name_search
|
||||
ON tasks USING gin(to_tsvector('english', name))
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for date-based filtering (if used)
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_tasks_dates
|
||||
ON tasks(project_id, start_date, end_date)
|
||||
WHERE archived = FALSE;
|
||||
|
||||
-- Index for task timers with user filtering
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_task_timers_user_task
|
||||
ON task_timers(user_id, task_id);
|
||||
|
||||
-- Index for sys_task_status_categories lookups
|
||||
CREATE INDEX CONCURRENTLY IF NOT EXISTS idx_sys_task_status_categories_covering
|
||||
ON sys_task_status_categories(id, color_code, color_code_dark, is_done, is_doing, is_todo);
|
||||
|
||||
|
||||
@@ -71,7 +71,7 @@ export default class ProjectsController extends WorklenzControllerBase {
|
||||
return res.status(200).send(new ServerResponse(false, [], `Sorry, the free plan cannot have more than ${projectsLimit} projects.`));
|
||||
}
|
||||
}
|
||||
|
||||
|
||||
const q = `SELECT create_project($1) AS project`;
|
||||
|
||||
req.body.team_id = req.user?.team_id || null;
|
||||
@@ -317,65 +317,58 @@ export default class ProjectsController extends WorklenzControllerBase {
|
||||
@HandleExceptions()
|
||||
public static async getMembersByProjectId(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const {sortField, sortOrder, size, offset} = this.toPaginationOptions(req.query, "name");
|
||||
const search = (req.query.search || "").toString().trim();
|
||||
|
||||
let searchFilter = "";
|
||||
const params = [req.params.id, req.user?.team_id ?? null, size, offset];
|
||||
if (search) {
|
||||
searchFilter = `
|
||||
AND (
|
||||
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) ILIKE '%' || $5 || '%'
|
||||
OR (SELECT email FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) ILIKE '%' || $5 || '%'
|
||||
)
|
||||
`;
|
||||
params.push(search);
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT ROW_TO_JSON(rec) AS members
|
||||
FROM (SELECT COUNT(*) AS total,
|
||||
(SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(t))), '[]'::JSON)
|
||||
FROM (SELECT project_members.id,
|
||||
team_member_id,
|
||||
(SELECT name
|
||||
FROM team_member_info_view
|
||||
WHERE team_member_info_view.team_member_id = tm.id),
|
||||
(SELECT email
|
||||
FROM team_member_info_view
|
||||
WHERE team_member_info_view.team_member_id = tm.id) AS email,
|
||||
u.avatar_url,
|
||||
(SELECT COUNT(*)
|
||||
FROM tasks
|
||||
WHERE archived IS FALSE
|
||||
AND project_id = project_members.project_id
|
||||
AND id IN (SELECT task_id
|
||||
FROM tasks_assignees
|
||||
WHERE tasks_assignees.project_member_id = project_members.id)) AS all_tasks_count,
|
||||
(SELECT COUNT(*)
|
||||
FROM tasks
|
||||
WHERE archived IS FALSE
|
||||
AND project_id = project_members.project_id
|
||||
AND id IN (SELECT task_id
|
||||
FROM tasks_assignees
|
||||
WHERE tasks_assignees.project_member_id = project_members.id)
|
||||
AND status_id IN (SELECT id
|
||||
FROM task_statuses
|
||||
WHERE category_id = (SELECT id
|
||||
FROM sys_task_status_categories
|
||||
WHERE is_done IS TRUE))) AS completed_tasks_count,
|
||||
EXISTS(SELECT email
|
||||
FROM email_invitations
|
||||
WHERE team_member_id = project_members.team_member_id
|
||||
AND email_invitations.team_id = $2) AS pending_invitation,
|
||||
(SELECT project_access_levels.name
|
||||
FROM project_access_levels
|
||||
WHERE project_access_levels.id = project_members.project_access_level_id) AS access,
|
||||
(SELECT name FROM job_titles WHERE id = tm.job_title_id) AS job_title
|
||||
FROM project_members
|
||||
INNER JOIN team_members tm ON project_members.team_member_id = tm.id
|
||||
LEFT JOIN users u ON tm.user_id = u.id
|
||||
WHERE project_id = $1
|
||||
ORDER BY ${sortField} ${sortOrder}
|
||||
LIMIT $3 OFFSET $4) t) AS data
|
||||
FROM project_members
|
||||
WHERE project_id = $1) rec;
|
||||
WITH filtered_members AS (
|
||||
SELECT project_members.id,
|
||||
team_member_id,
|
||||
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) AS name,
|
||||
(SELECT email FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id) AS email,
|
||||
u.avatar_url,
|
||||
(SELECT COUNT(*) FROM tasks WHERE archived IS FALSE AND project_id = project_members.project_id AND id IN (SELECT task_id FROM tasks_assignees WHERE tasks_assignees.project_member_id = project_members.id)) AS all_tasks_count,
|
||||
(SELECT COUNT(*) FROM tasks WHERE archived IS FALSE AND project_id = project_members.project_id AND id IN (SELECT task_id FROM tasks_assignees WHERE tasks_assignees.project_member_id = project_members.id) AND status_id IN (SELECT id FROM task_statuses WHERE category_id = (SELECT id FROM sys_task_status_categories WHERE is_done IS TRUE))) AS completed_tasks_count,
|
||||
EXISTS(SELECT email FROM email_invitations WHERE team_member_id = project_members.team_member_id AND email_invitations.team_id = $2) AS pending_invitation,
|
||||
(SELECT project_access_levels.name FROM project_access_levels WHERE project_access_levels.id = project_members.project_access_level_id) AS access,
|
||||
(SELECT name FROM job_titles WHERE id = tm.job_title_id) AS job_title
|
||||
FROM project_members
|
||||
INNER JOIN team_members tm ON project_members.team_member_id = tm.id
|
||||
LEFT JOIN users u ON tm.user_id = u.id
|
||||
WHERE project_id = $1
|
||||
${search ? searchFilter : ""}
|
||||
)
|
||||
SELECT
|
||||
(SELECT COUNT(*) FROM filtered_members) AS total,
|
||||
(SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(t))), '[]'::JSON)
|
||||
FROM (
|
||||
SELECT * FROM filtered_members
|
||||
ORDER BY ${sortField} ${sortOrder}
|
||||
LIMIT $3 OFFSET $4
|
||||
) t
|
||||
) AS data
|
||||
`;
|
||||
const result = await db.query(q, [req.params.id, req.user?.team_id ?? null, size, offset]);
|
||||
|
||||
const result = await db.query(q, params);
|
||||
const [data] = result.rows;
|
||||
|
||||
for (const member of data?.members.data || []) {
|
||||
for (const member of data?.data || []) {
|
||||
member.progress = member.all_tasks_count > 0
|
||||
? ((member.completed_tasks_count / member.all_tasks_count) * 100).toFixed(0) : 0;
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, data?.members || this.paginatedDatasetDefaultStruct));
|
||||
return res.status(200).send(new ServerResponse(true, data || this.paginatedDatasetDefaultStruct));
|
||||
}
|
||||
|
||||
@HandleExceptions()
|
||||
@@ -779,7 +772,7 @@ export default class ProjectsController extends WorklenzControllerBase {
|
||||
let groupJoin = "";
|
||||
let groupByFields = "";
|
||||
let groupOrderBy = "";
|
||||
|
||||
|
||||
switch (groupBy) {
|
||||
case "client":
|
||||
groupField = "COALESCE(projects.client_id::text, 'no-client')";
|
||||
@@ -888,13 +881,13 @@ export default class ProjectsController extends WorklenzControllerBase {
|
||||
ELSE p2.updated_at END) AS updated_at
|
||||
FROM projects p2
|
||||
${groupJoin.replace("projects.", "p2.")}
|
||||
WHERE p2.team_id = $1
|
||||
WHERE p2.team_id = $1
|
||||
AND ${groupField.replace("projects.", "p2.")} = ${groupField}
|
||||
${categories.replace("projects.", "p2.")}
|
||||
${statuses.replace("projects.", "p2.")}
|
||||
${isArchived.replace("projects.", "p2.")}
|
||||
${isFavorites.replace("projects.", "p2.")}
|
||||
${filterByMember.replace("projects.", "p2.")}
|
||||
${categories.replace("projects.", "p2.")}
|
||||
${statuses.replace("projects.", "p2.")}
|
||||
${isArchived.replace("projects.", "p2.")}
|
||||
${isFavorites.replace("projects.", "p2.")}
|
||||
${filterByMember.replace("projects.", "p2.")}
|
||||
${searchQuery.replace("projects.", "p2.")}
|
||||
ORDER BY ${innerSortField} ${sortOrder}
|
||||
) project_data
|
||||
|
||||
@@ -0,0 +1,179 @@
|
||||
// Example of updated getMemberTimeSheets method with timezone support
|
||||
// This shows the key changes needed to handle timezones properly
|
||||
|
||||
import moment from "moment-timezone";
|
||||
import db from "../../config/db";
|
||||
import { IWorkLenzRequest } from "../../interfaces/worklenz-request";
|
||||
import { IWorkLenzResponse } from "../../interfaces/worklenz-response";
|
||||
import { ServerResponse } from "../../models/server-response";
|
||||
import { DATE_RANGES } from "../../shared/constants";
|
||||
|
||||
export async function getMemberTimeSheets(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const archived = req.query.archived === "true";
|
||||
const teams = (req.body.teams || []) as string[];
|
||||
const teamIds = teams.map(id => `'${id}'`).join(",");
|
||||
const projects = (req.body.projects || []) as string[];
|
||||
const projectIds = projects.map(p => `'${p}'`).join(",");
|
||||
const {billable} = req.body;
|
||||
|
||||
// Get user timezone from request or database
|
||||
const userTimezone = req.body.timezone || await getUserTimezone(req.user?.id || "");
|
||||
|
||||
if (!teamIds || !projectIds.length)
|
||||
return res.status(200).send(new ServerResponse(true, { users: [], projects: [] }));
|
||||
|
||||
const { duration, date_range } = req.body;
|
||||
|
||||
// Calculate date range with timezone support
|
||||
let startDate: moment.Moment;
|
||||
let endDate: moment.Moment;
|
||||
|
||||
if (date_range && date_range.length === 2) {
|
||||
// Convert user's local dates to their timezone's start/end of day
|
||||
startDate = moment.tz(date_range[0], userTimezone).startOf("day");
|
||||
endDate = moment.tz(date_range[1], userTimezone).endOf("day");
|
||||
} else if (duration === DATE_RANGES.ALL_TIME) {
|
||||
const minDateQuery = `SELECT MIN(COALESCE(start_date, created_at)) as min_date FROM projects WHERE id IN (${projectIds})`;
|
||||
const minDateResult = await db.query(minDateQuery, []);
|
||||
const minDate = minDateResult.rows[0]?.min_date;
|
||||
startDate = minDate ? moment.tz(minDate, userTimezone) : moment.tz("2000-01-01", userTimezone);
|
||||
endDate = moment.tz(userTimezone);
|
||||
} else {
|
||||
// Calculate ranges based on user's timezone
|
||||
const now = moment.tz(userTimezone);
|
||||
|
||||
switch (duration) {
|
||||
case DATE_RANGES.YESTERDAY:
|
||||
startDate = now.clone().subtract(1, "day").startOf("day");
|
||||
endDate = now.clone().subtract(1, "day").endOf("day");
|
||||
break;
|
||||
case DATE_RANGES.LAST_WEEK:
|
||||
startDate = now.clone().subtract(1, "week").startOf("isoWeek");
|
||||
endDate = now.clone().subtract(1, "week").endOf("isoWeek");
|
||||
break;
|
||||
case DATE_RANGES.LAST_MONTH:
|
||||
startDate = now.clone().subtract(1, "month").startOf("month");
|
||||
endDate = now.clone().subtract(1, "month").endOf("month");
|
||||
break;
|
||||
case DATE_RANGES.LAST_QUARTER:
|
||||
startDate = now.clone().subtract(3, "months").startOf("day");
|
||||
endDate = now.clone().endOf("day");
|
||||
break;
|
||||
default:
|
||||
startDate = now.clone().startOf("day");
|
||||
endDate = now.clone().endOf("day");
|
||||
}
|
||||
}
|
||||
|
||||
// Convert to UTC for database queries
|
||||
const startUtc = startDate.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
const endUtc = endDate.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
|
||||
// Calculate working days in user's timezone
|
||||
const totalDays = endDate.diff(startDate, "days") + 1;
|
||||
let workingDays = 0;
|
||||
|
||||
const current = startDate.clone();
|
||||
while (current.isSameOrBefore(endDate, "day")) {
|
||||
if (current.isoWeekday() >= 1 && current.isoWeekday() <= 5) {
|
||||
workingDays++;
|
||||
}
|
||||
current.add(1, "day");
|
||||
}
|
||||
|
||||
// Updated SQL query with proper timezone handling
|
||||
const billableQuery = buildBillableQuery(billable);
|
||||
const archivedClause = archived ? "" : `AND projects.id NOT IN (SELECT project_id FROM archived_projects WHERE project_id = projects.id AND user_id = '${req.user?.id}')`;
|
||||
|
||||
const q = `
|
||||
WITH project_hours AS (
|
||||
SELECT
|
||||
id,
|
||||
COALESCE(hours_per_day, 8) as hours_per_day
|
||||
FROM projects
|
||||
WHERE id IN (${projectIds})
|
||||
),
|
||||
total_working_hours AS (
|
||||
SELECT
|
||||
SUM(hours_per_day) * ${workingDays} as total_hours
|
||||
FROM project_hours
|
||||
)
|
||||
SELECT
|
||||
u.id,
|
||||
u.email,
|
||||
tm.name,
|
||||
tm.color_code,
|
||||
COALESCE(SUM(twl.time_spent), 0) as logged_time,
|
||||
COALESCE(SUM(twl.time_spent), 0) / 3600.0 as value,
|
||||
(SELECT total_hours FROM total_working_hours) as total_working_hours,
|
||||
CASE
|
||||
WHEN (SELECT total_hours FROM total_working_hours) > 0
|
||||
THEN ROUND((COALESCE(SUM(twl.time_spent), 0) / 3600.0) / (SELECT total_hours FROM total_working_hours) * 100, 2)
|
||||
ELSE 0
|
||||
END as utilization_percent,
|
||||
ROUND(COALESCE(SUM(twl.time_spent), 0) / 3600.0, 2) as utilized_hours,
|
||||
ROUND(COALESCE(SUM(twl.time_spent), 0) / 3600.0 - (SELECT total_hours FROM total_working_hours), 2) as over_under_utilized_hours,
|
||||
'${userTimezone}' as user_timezone,
|
||||
'${startDate.format("YYYY-MM-DD")}' as report_start_date,
|
||||
'${endDate.format("YYYY-MM-DD")}' as report_end_date
|
||||
FROM team_members tm
|
||||
LEFT JOIN users u ON tm.user_id = u.id
|
||||
LEFT JOIN task_work_log twl ON twl.user_id = u.id
|
||||
LEFT JOIN tasks t ON twl.task_id = t.id ${billableQuery}
|
||||
LEFT JOIN projects p ON t.project_id = p.id
|
||||
WHERE tm.team_id IN (${teamIds})
|
||||
AND (
|
||||
twl.id IS NULL
|
||||
OR (
|
||||
p.id IN (${projectIds})
|
||||
AND twl.created_at >= '${startUtc}'::TIMESTAMP
|
||||
AND twl.created_at <= '${endUtc}'::TIMESTAMP
|
||||
${archivedClause}
|
||||
)
|
||||
)
|
||||
GROUP BY u.id, u.email, tm.name, tm.color_code
|
||||
ORDER BY logged_time DESC`;
|
||||
|
||||
const result = await db.query(q, []);
|
||||
|
||||
// Add timezone context to response
|
||||
const response = {
|
||||
data: result.rows,
|
||||
timezone_info: {
|
||||
user_timezone: userTimezone,
|
||||
report_period: {
|
||||
start: startDate.format("YYYY-MM-DD HH:mm:ss z"),
|
||||
end: endDate.format("YYYY-MM-DD HH:mm:ss z"),
|
||||
working_days: workingDays,
|
||||
total_days: totalDays
|
||||
}
|
||||
}
|
||||
};
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, response));
|
||||
}
|
||||
|
||||
async function getUserTimezone(userId: string): Promise<string> {
|
||||
const q = `SELECT tz.name as timezone
|
||||
FROM users u
|
||||
JOIN timezones tz ON u.timezone_id = tz.id
|
||||
WHERE u.id = $1`;
|
||||
const result = await db.query(q, [userId]);
|
||||
return result.rows[0]?.timezone || "UTC";
|
||||
}
|
||||
|
||||
function buildBillableQuery(billable: { billable: boolean; nonBillable: boolean }): string {
|
||||
if (!billable) return "";
|
||||
|
||||
const { billable: isBillable, nonBillable } = billable;
|
||||
|
||||
if (isBillable && nonBillable) {
|
||||
return "";
|
||||
} else if (isBillable) {
|
||||
return " AND tasks.billable IS TRUE";
|
||||
} else if (nonBillable) {
|
||||
return " AND tasks.billable IS FALSE";
|
||||
}
|
||||
|
||||
return "";
|
||||
}
|
||||
@@ -0,0 +1,117 @@
|
||||
import WorklenzControllerBase from "../worklenz-controller-base";
|
||||
import { IWorkLenzRequest } from "../../interfaces/worklenz-request";
|
||||
import db from "../../config/db";
|
||||
import moment from "moment-timezone";
|
||||
import { DATE_RANGES } from "../../shared/constants";
|
||||
|
||||
export default abstract class ReportingControllerBaseWithTimezone extends WorklenzControllerBase {
|
||||
|
||||
/**
|
||||
* Get the user's timezone from the database or request
|
||||
* @param userId - The user ID
|
||||
* @returns The user's timezone or 'UTC' as default
|
||||
*/
|
||||
protected static async getUserTimezone(userId: string): Promise<string> {
|
||||
const q = `SELECT tz.name as timezone
|
||||
FROM users u
|
||||
JOIN timezones tz ON u.timezone_id = tz.id
|
||||
WHERE u.id = $1`;
|
||||
const result = await db.query(q, [userId]);
|
||||
return result.rows[0]?.timezone || 'UTC';
|
||||
}
|
||||
|
||||
/**
|
||||
* Generate date range clause with timezone support
|
||||
* @param key - Date range key (e.g., YESTERDAY, LAST_WEEK)
|
||||
* @param dateRange - Array of date strings
|
||||
* @param userTimezone - User's timezone (e.g., 'America/New_York')
|
||||
* @returns SQL clause for date filtering
|
||||
*/
|
||||
protected static getDateRangeClauseWithTimezone(key: string, dateRange: string[], userTimezone: string) {
|
||||
// For custom date ranges
|
||||
if (dateRange.length === 2) {
|
||||
// Convert dates to user's timezone start/end of day
|
||||
const start = moment.tz(dateRange[0], userTimezone).startOf('day');
|
||||
const end = moment.tz(dateRange[1], userTimezone).endOf('day');
|
||||
|
||||
// Convert to UTC for database comparison
|
||||
const startUtc = start.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
const endUtc = end.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
|
||||
if (start.isSame(end, 'day')) {
|
||||
// Single day selection
|
||||
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
|
||||
}
|
||||
|
||||
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
|
||||
}
|
||||
|
||||
// For predefined ranges, calculate based on user's timezone
|
||||
const now = moment.tz(userTimezone);
|
||||
let startDate, endDate;
|
||||
|
||||
switch (key) {
|
||||
case DATE_RANGES.YESTERDAY:
|
||||
startDate = now.clone().subtract(1, 'day').startOf('day');
|
||||
endDate = now.clone().subtract(1, 'day').endOf('day');
|
||||
break;
|
||||
case DATE_RANGES.LAST_WEEK:
|
||||
startDate = now.clone().subtract(1, 'week').startOf('week');
|
||||
endDate = now.clone().subtract(1, 'week').endOf('week');
|
||||
break;
|
||||
case DATE_RANGES.LAST_MONTH:
|
||||
startDate = now.clone().subtract(1, 'month').startOf('month');
|
||||
endDate = now.clone().subtract(1, 'month').endOf('month');
|
||||
break;
|
||||
case DATE_RANGES.LAST_QUARTER:
|
||||
startDate = now.clone().subtract(3, 'months').startOf('day');
|
||||
endDate = now.clone().endOf('day');
|
||||
break;
|
||||
default:
|
||||
return "";
|
||||
}
|
||||
|
||||
if (startDate && endDate) {
|
||||
const startUtc = startDate.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
const endUtc = endDate.utc().format("YYYY-MM-DD HH:mm:ss");
|
||||
return `AND task_work_log.created_at >= '${startUtc}'::TIMESTAMP AND task_work_log.created_at <= '${endUtc}'::TIMESTAMP`;
|
||||
}
|
||||
|
||||
return "";
|
||||
}
|
||||
|
||||
/**
|
||||
* Format dates for display in user's timezone
|
||||
* @param date - Date to format
|
||||
* @param userTimezone - User's timezone
|
||||
* @param format - Moment format string
|
||||
* @returns Formatted date string
|
||||
*/
|
||||
protected static formatDateInTimezone(date: string | Date, userTimezone: string, format: string = "YYYY-MM-DD HH:mm:ss") {
|
||||
return moment.tz(date, userTimezone).format(format);
|
||||
}
|
||||
|
||||
/**
|
||||
* Get working days count between two dates in user's timezone
|
||||
* @param startDate - Start date
|
||||
* @param endDate - End date
|
||||
* @param userTimezone - User's timezone
|
||||
* @returns Number of working days
|
||||
*/
|
||||
protected static getWorkingDaysInTimezone(startDate: string, endDate: string, userTimezone: string): number {
|
||||
const start = moment.tz(startDate, userTimezone);
|
||||
const end = moment.tz(endDate, userTimezone);
|
||||
let workingDays = 0;
|
||||
|
||||
const current = start.clone();
|
||||
while (current.isSameOrBefore(end, 'day')) {
|
||||
// Monday = 1, Friday = 5
|
||||
if (current.isoWeekday() >= 1 && current.isoWeekday() <= 5) {
|
||||
workingDays++;
|
||||
}
|
||||
current.add(1, 'day');
|
||||
}
|
||||
|
||||
return workingDays;
|
||||
}
|
||||
}
|
||||
@@ -6,10 +6,69 @@ import { IWorkLenzResponse } from "../../interfaces/worklenz-response";
|
||||
import { ServerResponse } from "../../models/server-response";
|
||||
import { DATE_RANGES, TASK_PRIORITY_COLOR_ALPHA } from "../../shared/constants";
|
||||
import { formatDuration, getColor, int } from "../../shared/utils";
|
||||
import ReportingControllerBase from "./reporting-controller-base";
|
||||
import ReportingControllerBaseWithTimezone from "./reporting-controller-base-with-timezone";
|
||||
import Excel from "exceljs";
|
||||
|
||||
export default class ReportingMembersController extends ReportingControllerBase {
|
||||
export default class ReportingMembersController extends ReportingControllerBaseWithTimezone {
|
||||
|
||||
protected static getPercentage(n: number, total: number) {
|
||||
return +(n ? (n / total) * 100 : 0).toFixed();
|
||||
}
|
||||
|
||||
protected static getCurrentTeamId(req: IWorkLenzRequest): string | null {
|
||||
return req.user?.team_id ?? null;
|
||||
}
|
||||
|
||||
public static convertMinutesToHoursAndMinutes(totalMinutes: number) {
|
||||
const hours = Math.floor(totalMinutes / 60);
|
||||
const minutes = totalMinutes % 60;
|
||||
return `${hours}h ${minutes}m`;
|
||||
}
|
||||
|
||||
public static convertSecondsToHoursAndMinutes(seconds: number) {
|
||||
const hours = Math.floor(seconds / 3600);
|
||||
const minutes = Math.floor((seconds % 3600) / 60);
|
||||
return `${hours}h ${minutes}m`;
|
||||
}
|
||||
|
||||
protected static formatEndDate(endDate: string) {
|
||||
const end = moment(endDate).format("YYYY-MM-DD");
|
||||
const fEndDate = moment(end);
|
||||
return fEndDate;
|
||||
}
|
||||
|
||||
protected static formatCurrentDate() {
|
||||
const current = moment().format("YYYY-MM-DD");
|
||||
const fCurrentDate = moment(current);
|
||||
return fCurrentDate;
|
||||
}
|
||||
|
||||
protected static getDaysLeft(endDate: string): number | null {
|
||||
if (!endDate) return null;
|
||||
|
||||
const fCurrentDate = this.formatCurrentDate();
|
||||
const fEndDate = this.formatEndDate(endDate);
|
||||
|
||||
return fEndDate.diff(fCurrentDate, "days");
|
||||
}
|
||||
|
||||
protected static isOverdue(endDate: string): boolean {
|
||||
if (!endDate) return false;
|
||||
|
||||
const fCurrentDate = this.formatCurrentDate();
|
||||
const fEndDate = this.formatEndDate(endDate);
|
||||
|
||||
return fEndDate.isBefore(fCurrentDate);
|
||||
}
|
||||
|
||||
protected static isToday(endDate: string): boolean {
|
||||
if (!endDate) return false;
|
||||
|
||||
const fCurrentDate = this.formatCurrentDate();
|
||||
const fEndDate = this.formatEndDate(endDate);
|
||||
|
||||
return fEndDate.isSame(fCurrentDate);
|
||||
}
|
||||
|
||||
private static async getMembers(
|
||||
teamId: string, searchQuery = "",
|
||||
@@ -487,7 +546,9 @@ export default class ReportingMembersController extends ReportingControllerBase
|
||||
dateRange = date_range.split(",");
|
||||
}
|
||||
|
||||
const durationClause = ReportingMembersController.getDateRangeClauseMembers(duration as string || DATE_RANGES.LAST_WEEK, dateRange, "twl");
|
||||
// Get user timezone for proper date filtering
|
||||
const userTimezone = await this.getUserTimezone(req.user?.id as string);
|
||||
const durationClause = this.getDateRangeClauseWithTimezone(duration as string || DATE_RANGES.LAST_WEEK, dateRange, userTimezone);
|
||||
const minMaxDateClause = this.getMinMaxDates(duration as string || DATE_RANGES.LAST_WEEK, dateRange, "task_work_log");
|
||||
const memberName = (req.query.member_name as string)?.trim() || null;
|
||||
|
||||
@@ -1038,7 +1099,9 @@ export default class ReportingMembersController extends ReportingControllerBase
|
||||
public static async getMemberTimelogs(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const { team_member_id, team_id, duration, date_range, archived, billable } = req.body;
|
||||
|
||||
const durationClause = ReportingMembersController.getDateRangeClauseMembers(duration || DATE_RANGES.LAST_WEEK, date_range, "twl");
|
||||
// Get user timezone for proper date filtering
|
||||
const userTimezone = await this.getUserTimezone(req.user?.id as string);
|
||||
const durationClause = this.getDateRangeClauseWithTimezone(duration || DATE_RANGES.LAST_WEEK, date_range, userTimezone);
|
||||
const minMaxDateClause = this.getMinMaxDates(duration || DATE_RANGES.LAST_WEEK, date_range, "task_work_log");
|
||||
|
||||
const billableQuery = this.buildBillableQuery(billable);
|
||||
@@ -1230,8 +1293,8 @@ public static async getSingleMemberProjects(req: IWorkLenzRequest, res: IWorkLen
|
||||
row.actual_time = int(row.actual_time);
|
||||
row.estimated_time_string = this.convertMinutesToHoursAndMinutes(int(row.estimated_time));
|
||||
row.actual_time_string = this.convertSecondsToHoursAndMinutes(int(row.actual_time));
|
||||
row.days_left = ReportingControllerBase.getDaysLeft(row.end_date);
|
||||
row.is_overdue = ReportingControllerBase.isOverdue(row.end_date);
|
||||
row.days_left = this.getDaysLeft(row.end_date);
|
||||
row.is_overdue = this.isOverdue(row.end_date);
|
||||
if (row.days_left && row.is_overdue) {
|
||||
row.days_left = row.days_left.toString().replace(/-/g, "");
|
||||
}
|
||||
|
||||
201
worklenz-backend/src/controllers/survey-controller.ts
Normal file
201
worklenz-backend/src/controllers/survey-controller.ts
Normal file
@@ -0,0 +1,201 @@
|
||||
import { IWorkLenzRequest } from "../interfaces/worklenz-request";
|
||||
import { IWorkLenzResponse } from "../interfaces/worklenz-response";
|
||||
import { ServerResponse } from "../models/server-response";
|
||||
import WorklenzControllerBase from "./worklenz-controller-base";
|
||||
import HandleExceptions from "../decorators/handle-exceptions";
|
||||
import { ISurveySubmissionRequest } from "../interfaces/survey";
|
||||
import db from "../config/db";
|
||||
|
||||
export default class SurveyController extends WorklenzControllerBase {
|
||||
@HandleExceptions()
|
||||
public static async getAccountSetupSurvey(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const q = `
|
||||
SELECT
|
||||
s.id,
|
||||
s.name,
|
||||
s.description,
|
||||
s.survey_type,
|
||||
s.is_active,
|
||||
COALESCE(
|
||||
json_agg(
|
||||
json_build_object(
|
||||
'id', sq.id,
|
||||
'survey_id', sq.survey_id,
|
||||
'question_key', sq.question_key,
|
||||
'question_type', sq.question_type,
|
||||
'is_required', sq.is_required,
|
||||
'sort_order', sq.sort_order,
|
||||
'options', sq.options
|
||||
) ORDER BY sq.sort_order
|
||||
) FILTER (WHERE sq.id IS NOT NULL),
|
||||
'[]'
|
||||
) AS questions
|
||||
FROM surveys s
|
||||
LEFT JOIN survey_questions sq ON s.id = sq.survey_id
|
||||
WHERE s.survey_type = 'account_setup' AND s.is_active = true
|
||||
GROUP BY s.id, s.name, s.description, s.survey_type, s.is_active
|
||||
LIMIT 1;
|
||||
`;
|
||||
|
||||
const result = await db.query(q);
|
||||
const [survey] = result.rows;
|
||||
|
||||
if (!survey) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Account setup survey not found"));
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, survey));
|
||||
}
|
||||
|
||||
@HandleExceptions()
|
||||
public static async submitSurveyResponse(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const userId = req.user?.id;
|
||||
const body = req.body as ISurveySubmissionRequest;
|
||||
|
||||
if (!userId) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "User not authenticated"));
|
||||
}
|
||||
|
||||
if (!body.survey_id || !body.answers || !Array.isArray(body.answers)) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Invalid survey submission data"));
|
||||
}
|
||||
|
||||
// Check if user has already submitted a response for this survey
|
||||
const existingResponseQuery = `
|
||||
SELECT id FROM survey_responses
|
||||
WHERE user_id = $1 AND survey_id = $2;
|
||||
`;
|
||||
const existingResult = await db.query(existingResponseQuery, [userId, body.survey_id]);
|
||||
|
||||
let responseId: string;
|
||||
|
||||
if (existingResult.rows.length > 0) {
|
||||
// Update existing response
|
||||
responseId = existingResult.rows[0].id;
|
||||
|
||||
const updateResponseQuery = `
|
||||
UPDATE survey_responses
|
||||
SET is_completed = true, completed_at = NOW(), updated_at = NOW()
|
||||
WHERE id = $1;
|
||||
`;
|
||||
await db.query(updateResponseQuery, [responseId]);
|
||||
|
||||
// Delete existing answers
|
||||
const deleteAnswersQuery = `DELETE FROM survey_answers WHERE response_id = $1;`;
|
||||
await db.query(deleteAnswersQuery, [responseId]);
|
||||
} else {
|
||||
// Create new response
|
||||
const createResponseQuery = `
|
||||
INSERT INTO survey_responses (survey_id, user_id, is_completed, completed_at)
|
||||
VALUES ($1, $2, true, NOW())
|
||||
RETURNING id;
|
||||
`;
|
||||
const responseResult = await db.query(createResponseQuery, [body.survey_id, userId]);
|
||||
responseId = responseResult.rows[0].id;
|
||||
}
|
||||
|
||||
// Insert new answers
|
||||
if (body.answers.length > 0) {
|
||||
const answerValues: string[] = [];
|
||||
const params: any[] = [];
|
||||
|
||||
body.answers.forEach((answer, index) => {
|
||||
const baseIndex = index * 4;
|
||||
answerValues.push(`($${baseIndex + 1}, $${baseIndex + 2}, $${baseIndex + 3}, $${baseIndex + 4})`);
|
||||
|
||||
params.push(
|
||||
responseId,
|
||||
answer.question_id,
|
||||
answer.answer_text || null,
|
||||
answer.answer_json ? JSON.stringify(answer.answer_json) : null
|
||||
);
|
||||
});
|
||||
|
||||
const insertAnswersQuery = `
|
||||
INSERT INTO survey_answers (response_id, question_id, answer_text, answer_json)
|
||||
VALUES ${answerValues.join(', ')};
|
||||
`;
|
||||
|
||||
await db.query(insertAnswersQuery, params);
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, { response_id: responseId }));
|
||||
}
|
||||
|
||||
@HandleExceptions()
|
||||
public static async getUserSurveyResponse(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const userId = req.user?.id;
|
||||
const surveyId = req.params.survey_id;
|
||||
|
||||
if (!userId) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "User not authenticated"));
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT
|
||||
sr.id,
|
||||
sr.survey_id,
|
||||
sr.user_id,
|
||||
sr.is_completed,
|
||||
sr.started_at,
|
||||
sr.completed_at,
|
||||
COALESCE(
|
||||
json_agg(
|
||||
json_build_object(
|
||||
'question_id', sa.question_id,
|
||||
'answer_text', sa.answer_text,
|
||||
'answer_json', sa.answer_json
|
||||
)
|
||||
) FILTER (WHERE sa.id IS NOT NULL),
|
||||
'[]'
|
||||
) AS answers
|
||||
FROM survey_responses sr
|
||||
LEFT JOIN survey_answers sa ON sr.id = sa.response_id
|
||||
WHERE sr.user_id = $1 AND sr.survey_id = $2
|
||||
GROUP BY sr.id, sr.survey_id, sr.user_id, sr.is_completed, sr.started_at, sr.completed_at;
|
||||
`;
|
||||
|
||||
const result = await db.query(q, [userId, surveyId]);
|
||||
const [response] = result.rows;
|
||||
|
||||
if (!response) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Survey response not found"));
|
||||
}
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, response));
|
||||
}
|
||||
|
||||
@HandleExceptions()
|
||||
public static async checkAccountSetupSurveyStatus(req: IWorkLenzRequest, res: IWorkLenzResponse): Promise<IWorkLenzResponse> {
|
||||
const userId = req.user?.id;
|
||||
|
||||
if (!userId) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "User not authenticated"));
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT EXISTS(
|
||||
SELECT 1
|
||||
FROM survey_responses sr
|
||||
INNER JOIN surveys s ON sr.survey_id = s.id
|
||||
WHERE sr.user_id = $1
|
||||
AND s.survey_type = 'account_setup'
|
||||
AND sr.is_completed = true
|
||||
) as is_completed,
|
||||
(
|
||||
SELECT sr.completed_at
|
||||
FROM survey_responses sr
|
||||
INNER JOIN surveys s ON sr.survey_id = s.id
|
||||
WHERE sr.user_id = $1
|
||||
AND s.survey_type = 'account_setup'
|
||||
AND sr.is_completed = true
|
||||
LIMIT 1
|
||||
) as completed_at;
|
||||
`;
|
||||
|
||||
const result = await db.query(q, [userId]);
|
||||
const status = result.rows[0] || { is_completed: false, completed_at: null };
|
||||
|
||||
return res.status(200).send(new ServerResponse(true, status));
|
||||
}
|
||||
}
|
||||
@@ -16,6 +16,7 @@ export interface ITaskGroup {
|
||||
start_date?: string;
|
||||
end_date?: string;
|
||||
color_code: string;
|
||||
color_code_dark: string;
|
||||
category_id: string | null;
|
||||
old_category_id?: string;
|
||||
todo_progress?: number;
|
||||
|
||||
File diff suppressed because it is too large
Load Diff
37
worklenz-backend/src/interfaces/survey.ts
Normal file
37
worklenz-backend/src/interfaces/survey.ts
Normal file
@@ -0,0 +1,37 @@
|
||||
export interface ISurveyQuestion {
|
||||
id: string;
|
||||
survey_id: string;
|
||||
question_key: string;
|
||||
question_type: 'single_choice' | 'multiple_choice' | 'text';
|
||||
is_required: boolean;
|
||||
sort_order: number;
|
||||
options?: string[];
|
||||
}
|
||||
|
||||
export interface ISurvey {
|
||||
id: string;
|
||||
name: string;
|
||||
description?: string;
|
||||
survey_type: 'account_setup' | 'onboarding' | 'feedback';
|
||||
is_active: boolean;
|
||||
questions?: ISurveyQuestion[];
|
||||
}
|
||||
|
||||
export interface ISurveyAnswer {
|
||||
question_id: string;
|
||||
answer_text?: string;
|
||||
answer_json?: string[];
|
||||
}
|
||||
|
||||
export interface ISurveyResponse {
|
||||
id?: string;
|
||||
survey_id: string;
|
||||
user_id?: string;
|
||||
is_completed: boolean;
|
||||
answers: ISurveyAnswer[];
|
||||
}
|
||||
|
||||
export interface ISurveySubmissionRequest {
|
||||
survey_id: string;
|
||||
answers: ISurveyAnswer[];
|
||||
}
|
||||
@@ -0,0 +1,53 @@
|
||||
import { NextFunction } from "express";
|
||||
import { IWorkLenzRequest } from "../../interfaces/worklenz-request";
|
||||
import { IWorkLenzResponse } from "../../interfaces/worklenz-response";
|
||||
import { ServerResponse } from "../../models/server-response";
|
||||
import { ISurveySubmissionRequest } from "../../interfaces/survey";
|
||||
|
||||
export default function surveySubmissionValidator(req: IWorkLenzRequest, res: IWorkLenzResponse, next: NextFunction): IWorkLenzResponse | void {
|
||||
const body = req.body as ISurveySubmissionRequest;
|
||||
|
||||
if (!body) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Request body is required"));
|
||||
}
|
||||
|
||||
if (!body.survey_id || typeof body.survey_id !== 'string') {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Survey ID is required and must be a string"));
|
||||
}
|
||||
|
||||
if (!body.answers || !Array.isArray(body.answers)) {
|
||||
return res.status(200).send(new ServerResponse(false, null, "Answers are required and must be an array"));
|
||||
}
|
||||
|
||||
// Validate each answer
|
||||
for (let i = 0; i < body.answers.length; i++) {
|
||||
const answer = body.answers[i];
|
||||
|
||||
if (!answer.question_id || typeof answer.question_id !== 'string') {
|
||||
return res.status(200).send(new ServerResponse(false, null, `Answer ${i + 1}: Question ID is required and must be a string`));
|
||||
}
|
||||
|
||||
// answer_text and answer_json are both optional - users can submit empty answers
|
||||
|
||||
// Validate answer_text if provided
|
||||
if (answer.answer_text && typeof answer.answer_text !== 'string') {
|
||||
return res.status(200).send(new ServerResponse(false, null, `Answer ${i + 1}: answer_text must be a string`));
|
||||
}
|
||||
|
||||
// Validate answer_json if provided
|
||||
if (answer.answer_json && !Array.isArray(answer.answer_json)) {
|
||||
return res.status(200).send(new ServerResponse(false, null, `Answer ${i + 1}: answer_json must be an array`));
|
||||
}
|
||||
|
||||
// Validate answer_json items are strings
|
||||
if (answer.answer_json) {
|
||||
for (let j = 0; j < answer.answer_json.length; j++) {
|
||||
if (typeof answer.answer_json[j] !== 'string') {
|
||||
return res.status(200).send(new ServerResponse(false, null, `Answer ${i + 1}: answer_json items must be strings`));
|
||||
}
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
return next();
|
||||
}
|
||||
@@ -81,5 +81,12 @@
|
||||
"delete": "Fshi",
|
||||
"enterStatusName": "Shkruani emrin e statusit",
|
||||
"selectCategory": "Zgjidh kategorinë",
|
||||
"close": "Mbyll"
|
||||
"close": "Mbyll",
|
||||
"clearSort": "Pastro Renditjen",
|
||||
"sortAscending": "Rendit në Rritje",
|
||||
"sortDescending": "Rendit në Zbritje",
|
||||
"sortByField": "Rendit sipas {{field}}",
|
||||
"ascendingOrder": "Rritës",
|
||||
"descendingOrder": "Zbritës",
|
||||
"currentSort": "Renditja aktuale: {{field}} {{order}}"
|
||||
}
|
||||
|
||||
@@ -81,5 +81,12 @@
|
||||
"delete": "Löschen",
|
||||
"enterStatusName": "Statusnamen eingeben",
|
||||
"selectCategory": "Kategorie auswählen",
|
||||
"close": "Schließen"
|
||||
"close": "Schließen",
|
||||
"clearSort": "Sortierung löschen",
|
||||
"sortAscending": "Aufsteigend sortieren",
|
||||
"sortDescending": "Absteigend sortieren",
|
||||
"sortByField": "Sortieren nach {{field}}",
|
||||
"ascendingOrder": "Aufsteigend",
|
||||
"descendingOrder": "Absteigend",
|
||||
"currentSort": "Aktuelle Sortierung: {{field}} {{order}}"
|
||||
}
|
||||
|
||||
@@ -1,7 +1,7 @@
|
||||
{
|
||||
"continue": "Continue",
|
||||
|
||||
"setupYourAccount": "Setup Your Worklenz Account.",
|
||||
"setupYourAccount": "Setup Your Account.",
|
||||
"organizationStepTitle": "Name Your Organization",
|
||||
"organizationStepLabel": "Pick a name for your Worklenz account.",
|
||||
|
||||
|
||||
@@ -81,5 +81,12 @@
|
||||
"delete": "Delete",
|
||||
"enterStatusName": "Enter status name",
|
||||
"selectCategory": "Select category",
|
||||
"close": "Close"
|
||||
"close": "Close",
|
||||
"clearSort": "Clear Sort",
|
||||
"sortAscending": "Sort Ascending",
|
||||
"sortDescending": "Sort Descending",
|
||||
"sortByField": "Sort by {{field}}",
|
||||
"ascendingOrder": "Ascending",
|
||||
"descendingOrder": "Descending",
|
||||
"currentSort": "Current sort: {{field}} {{order}}"
|
||||
}
|
||||
|
||||
@@ -77,5 +77,12 @@
|
||||
"delete": "Eliminar",
|
||||
"enterStatusName": "Introducir nombre del estado",
|
||||
"selectCategory": "Seleccionar categoría",
|
||||
"close": "Cerrar"
|
||||
"close": "Cerrar",
|
||||
"clearSort": "Limpiar Ordenamiento",
|
||||
"sortAscending": "Ordenar Ascendente",
|
||||
"sortDescending": "Ordenar Descendente",
|
||||
"sortByField": "Ordenar por {{field}}",
|
||||
"ascendingOrder": "Ascendente",
|
||||
"descendingOrder": "Descendente",
|
||||
"currentSort": "Ordenamiento actual: {{field}} {{order}}"
|
||||
}
|
||||
|
||||
@@ -78,5 +78,12 @@
|
||||
"delete": "Excluir",
|
||||
"enterStatusName": "Digite o nome do status",
|
||||
"selectCategory": "Selecionar categoria",
|
||||
"close": "Fechar"
|
||||
"close": "Fechar",
|
||||
"clearSort": "Limpar Ordenação",
|
||||
"sortAscending": "Ordenar Crescente",
|
||||
"sortDescending": "Ordenar Decrescente",
|
||||
"sortByField": "Ordenar por {{field}}",
|
||||
"ascendingOrder": "Crescente",
|
||||
"descendingOrder": "Decrescente",
|
||||
"currentSort": "Ordenação atual: {{field}} {{order}}"
|
||||
}
|
||||
|
||||
@@ -75,5 +75,12 @@
|
||||
"delete": "删除",
|
||||
"enterStatusName": "输入状态名称",
|
||||
"selectCategory": "选择类别",
|
||||
"close": "关闭"
|
||||
"close": "关闭",
|
||||
"clearSort": "清除排序",
|
||||
"sortAscending": "升序排列",
|
||||
"sortDescending": "降序排列",
|
||||
"sortByField": "按{{field}}排序",
|
||||
"ascendingOrder": "升序",
|
||||
"descendingOrder": "降序",
|
||||
"currentSort": "当前排序:{{field}} {{order}}"
|
||||
}
|
||||
@@ -51,6 +51,7 @@ import roadmapApiRouter from "./gannt-apis/roadmap-api-router";
|
||||
import scheduleApiRouter from "./gannt-apis/schedule-api-router";
|
||||
import scheduleApiV2Router from "./gannt-apis/schedule-api-v2-router";
|
||||
import projectManagerApiRouter from "./project-managers-api-router";
|
||||
import surveyApiRouter from "./survey-api-router";
|
||||
|
||||
import billingApiRouter from "./billing-api-router";
|
||||
import taskDependenciesApiRouter from "./task-dependencies-api-router";
|
||||
@@ -58,7 +59,6 @@ import taskDependenciesApiRouter from "./task-dependencies-api-router";
|
||||
import taskRecurringApiRouter from "./task-recurring-api-router";
|
||||
|
||||
import customColumnsApiRouter from "./custom-columns-api-router";
|
||||
|
||||
import userActivityLogsApiRouter from "./user-activity-logs-api-router";
|
||||
|
||||
const api = express.Router();
|
||||
@@ -106,6 +106,7 @@ api.use("/roadmap-gannt", roadmapApiRouter);
|
||||
api.use("/schedule-gannt", scheduleApiRouter);
|
||||
api.use("/schedule-gannt-v2", scheduleApiV2Router);
|
||||
api.use("/project-managers", projectManagerApiRouter);
|
||||
api.use("/surveys", surveyApiRouter);
|
||||
|
||||
api.get("/overview/:id", safeControllerFunction(OverviewController.getById));
|
||||
api.get("/task-priorities", safeControllerFunction(TaskPrioritiesController.get));
|
||||
@@ -121,5 +122,4 @@ api.use("/task-recurring", taskRecurringApiRouter);
|
||||
api.use("/custom-columns", customColumnsApiRouter);
|
||||
|
||||
api.use("/logs", userActivityLogsApiRouter);
|
||||
|
||||
export default api;
|
||||
|
||||
20
worklenz-backend/src/routes/apis/survey-api-router.ts
Normal file
20
worklenz-backend/src/routes/apis/survey-api-router.ts
Normal file
@@ -0,0 +1,20 @@
|
||||
import express from "express";
|
||||
import SurveyController from "../../controllers/survey-controller";
|
||||
import surveySubmissionValidator from "../../middlewares/validators/survey-submission-validator";
|
||||
import safeControllerFunction from "../../shared/safe-controller-function";
|
||||
|
||||
const surveyApiRouter = express.Router();
|
||||
|
||||
// Get account setup survey with questions
|
||||
surveyApiRouter.get("/account-setup", safeControllerFunction(SurveyController.getAccountSetupSurvey));
|
||||
|
||||
// Check if user has completed account setup survey
|
||||
surveyApiRouter.get("/account-setup/status", safeControllerFunction(SurveyController.checkAccountSetupSurveyStatus));
|
||||
|
||||
// Submit survey response
|
||||
surveyApiRouter.post("/responses", surveySubmissionValidator, safeControllerFunction(SurveyController.submitSurveyResponse));
|
||||
|
||||
// Get user's survey response for a specific survey
|
||||
surveyApiRouter.get("/responses/:survey_id", safeControllerFunction(SurveyController.getUserSurveyResponse));
|
||||
|
||||
export default surveyApiRouter;
|
||||
@@ -89,24 +89,24 @@ export const NumbersColorMap: { [x: string]: string } = {
|
||||
};
|
||||
|
||||
export const PriorityColorCodes: { [x: number]: string; } = {
|
||||
0: "#75c997",
|
||||
1: "#fbc84c",
|
||||
2: "#f37070"
|
||||
0: "#2E8B57",
|
||||
1: "#DAA520",
|
||||
2: "#CD5C5C"
|
||||
};
|
||||
|
||||
export const PriorityColorCodesDark: { [x: number]: string; } = {
|
||||
0: "#46D980",
|
||||
1: "#FFC227",
|
||||
2: "#FF4141"
|
||||
0: "#3CB371",
|
||||
1: "#B8860B",
|
||||
2: "#F08080"
|
||||
};
|
||||
|
||||
export const TASK_STATUS_TODO_COLOR = "#a9a9a9";
|
||||
export const TASK_STATUS_DOING_COLOR = "#70a6f3";
|
||||
export const TASK_STATUS_DONE_COLOR = "#75c997";
|
||||
|
||||
export const TASK_PRIORITY_LOW_COLOR = "#75c997";
|
||||
export const TASK_PRIORITY_MEDIUM_COLOR = "#fbc84c";
|
||||
export const TASK_PRIORITY_HIGH_COLOR = "#f37070";
|
||||
export const TASK_PRIORITY_LOW_COLOR = "#2E8B57";
|
||||
export const TASK_PRIORITY_MEDIUM_COLOR = "#DAA520";
|
||||
export const TASK_PRIORITY_HIGH_COLOR = "#CD5C5C";
|
||||
|
||||
export const TASK_DUE_COMPLETED_COLOR = "#75c997";
|
||||
export const TASK_DUE_UPCOMING_COLOR = "#70a6f3";
|
||||
|
||||
@@ -53,11 +53,27 @@ function notifyStatusChange(socket: Socket, config: Config) {
|
||||
}
|
||||
|
||||
async function emitSortOrderChange(data: ChangeRequest, socket: Socket) {
|
||||
// Determine which sort column to use based on group_by
|
||||
let sortColumn = "sort_order";
|
||||
switch (data.group_by) {
|
||||
case "status":
|
||||
sortColumn = "status_sort_order";
|
||||
break;
|
||||
case "priority":
|
||||
sortColumn = "priority_sort_order";
|
||||
break;
|
||||
case "phase":
|
||||
sortColumn = "phase_sort_order";
|
||||
break;
|
||||
default:
|
||||
sortColumn = "sort_order";
|
||||
}
|
||||
|
||||
const q = `
|
||||
SELECT id, sort_order, completed_at
|
||||
SELECT id, sort_order, ${sortColumn} as current_sort_order, completed_at
|
||||
FROM tasks
|
||||
WHERE project_id = $1
|
||||
ORDER BY sort_order;
|
||||
ORDER BY ${sortColumn};
|
||||
`;
|
||||
const tasks = await db.query(q, [data.project_id]);
|
||||
socket.emit(SocketEvents.TASK_SORT_ORDER_CHANGE.toString(), tasks.rows);
|
||||
@@ -84,9 +100,9 @@ export async function on_task_sort_order_change(_io: Server, socket: Socket, dat
|
||||
}
|
||||
}
|
||||
|
||||
// Use the simple bulk update function
|
||||
const q = `SELECT update_task_sort_orders_bulk($1);`;
|
||||
await db.query(q, [JSON.stringify(data.task_updates)]);
|
||||
// Use the simple bulk update function with group_by parameter
|
||||
const q = `SELECT update_task_sort_orders_bulk($1, $2);`;
|
||||
await db.query(q, [JSON.stringify(data.task_updates), data.group_by || "status"]);
|
||||
await emitSortOrderChange(data, socket);
|
||||
|
||||
// Handle notifications and logging
|
||||
|
||||
Reference in New Issue
Block a user