feat(recurring-tasks): implement recurring tasks service with timezone support and notifications
- Added a new service for managing recurring tasks, allowing configuration of task schedules with timezone support. - Introduced job queues for processing recurring tasks and handling task creation in bulk. - Implemented notification system to alert users about newly created recurring tasks, including email and in-app notifications. - Enhanced database schema with new tables for notifications and audit logs to track recurring task operations. - Updated frontend components to support timezone selection and manage excluded dates for recurring tasks. - Refactored existing code to integrate new features and improve overall task management experience.
This commit is contained in:
@@ -0,0 +1,185 @@
|
||||
-- Function to create multiple recurring tasks in bulk
|
||||
CREATE OR REPLACE FUNCTION create_bulk_recurring_tasks(
|
||||
p_tasks JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
task_id UUID,
|
||||
task_name TEXT,
|
||||
created BOOLEAN,
|
||||
error_message TEXT
|
||||
) AS $$
|
||||
DECLARE
|
||||
v_task JSONB;
|
||||
v_task_id UUID;
|
||||
v_existing_id UUID;
|
||||
v_error_message TEXT;
|
||||
BEGIN
|
||||
-- Create a temporary table to store results
|
||||
CREATE TEMP TABLE IF NOT EXISTS bulk_task_results (
|
||||
task_id UUID,
|
||||
task_name TEXT,
|
||||
created BOOLEAN,
|
||||
error_message TEXT
|
||||
) ON COMMIT DROP;
|
||||
|
||||
-- Iterate through each task in the array
|
||||
FOR v_task IN SELECT * FROM jsonb_array_elements(p_tasks)
|
||||
LOOP
|
||||
BEGIN
|
||||
-- Check if task already exists for this schedule and date
|
||||
SELECT id INTO v_existing_id
|
||||
FROM tasks
|
||||
WHERE schedule_id = (v_task->>'schedule_id')::UUID
|
||||
AND end_date::DATE = (v_task->>'end_date')::DATE
|
||||
LIMIT 1;
|
||||
|
||||
IF v_existing_id IS NOT NULL THEN
|
||||
-- Task already exists
|
||||
INSERT INTO bulk_task_results (task_id, task_name, created, error_message)
|
||||
VALUES (v_existing_id, v_task->>'name', FALSE, 'Task already exists for this date');
|
||||
ELSE
|
||||
-- Create the task using existing function
|
||||
SELECT (create_quick_task(v_task::TEXT)::JSONB)->>'id' INTO v_task_id;
|
||||
|
||||
IF v_task_id IS NOT NULL THEN
|
||||
INSERT INTO bulk_task_results (task_id, task_name, created, error_message)
|
||||
VALUES (v_task_id::UUID, v_task->>'name', TRUE, NULL);
|
||||
ELSE
|
||||
INSERT INTO bulk_task_results (task_id, task_name, created, error_message)
|
||||
VALUES (NULL, v_task->>'name', FALSE, 'Failed to create task');
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
-- Capture any errors
|
||||
v_error_message := SQLERRM;
|
||||
INSERT INTO bulk_task_results (task_id, task_name, created, error_message)
|
||||
VALUES (NULL, v_task->>'name', FALSE, v_error_message);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
-- Return all results
|
||||
RETURN QUERY SELECT * FROM bulk_task_results;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Function to bulk assign team members to tasks
|
||||
CREATE OR REPLACE FUNCTION bulk_assign_team_members(
|
||||
p_assignments JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
task_id UUID,
|
||||
team_member_id UUID,
|
||||
assigned BOOLEAN,
|
||||
error_message TEXT
|
||||
) AS $$
|
||||
DECLARE
|
||||
v_assignment JSONB;
|
||||
v_result RECORD;
|
||||
BEGIN
|
||||
CREATE TEMP TABLE IF NOT EXISTS bulk_assignment_results (
|
||||
task_id UUID,
|
||||
team_member_id UUID,
|
||||
assigned BOOLEAN,
|
||||
error_message TEXT
|
||||
) ON COMMIT DROP;
|
||||
|
||||
FOR v_assignment IN SELECT * FROM jsonb_array_elements(p_assignments)
|
||||
LOOP
|
||||
BEGIN
|
||||
-- Check if assignment already exists
|
||||
IF EXISTS (
|
||||
SELECT 1 FROM tasks_assignees
|
||||
WHERE task_id = (v_assignment->>'task_id')::UUID
|
||||
AND team_member_id = (v_assignment->>'team_member_id')::UUID
|
||||
) THEN
|
||||
INSERT INTO bulk_assignment_results
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'team_member_id')::UUID,
|
||||
FALSE,
|
||||
'Assignment already exists'
|
||||
);
|
||||
ELSE
|
||||
-- Create the assignment
|
||||
INSERT INTO tasks_assignees (task_id, team_member_id, assigned_by)
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'team_member_id')::UUID,
|
||||
(v_assignment->>'assigned_by')::UUID
|
||||
);
|
||||
|
||||
INSERT INTO bulk_assignment_results
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'team_member_id')::UUID,
|
||||
TRUE,
|
||||
NULL
|
||||
);
|
||||
END IF;
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
INSERT INTO bulk_assignment_results
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'team_member_id')::UUID,
|
||||
FALSE,
|
||||
SQLERRM
|
||||
);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
RETURN QUERY SELECT * FROM bulk_assignment_results;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Function to bulk assign labels to tasks
|
||||
CREATE OR REPLACE FUNCTION bulk_assign_labels(
|
||||
p_label_assignments JSONB
|
||||
)
|
||||
RETURNS TABLE (
|
||||
task_id UUID,
|
||||
label_id UUID,
|
||||
assigned BOOLEAN,
|
||||
error_message TEXT
|
||||
) AS $$
|
||||
DECLARE
|
||||
v_assignment JSONB;
|
||||
v_labels JSONB;
|
||||
BEGIN
|
||||
CREATE TEMP TABLE IF NOT EXISTS bulk_label_results (
|
||||
task_id UUID,
|
||||
label_id UUID,
|
||||
assigned BOOLEAN,
|
||||
error_message TEXT
|
||||
) ON COMMIT DROP;
|
||||
|
||||
FOR v_assignment IN SELECT * FROM jsonb_array_elements(p_label_assignments)
|
||||
LOOP
|
||||
BEGIN
|
||||
-- Use existing function to add label
|
||||
SELECT add_or_remove_task_label(
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'label_id')::UUID
|
||||
) INTO v_labels;
|
||||
|
||||
INSERT INTO bulk_label_results
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'label_id')::UUID,
|
||||
TRUE,
|
||||
NULL
|
||||
);
|
||||
EXCEPTION WHEN OTHERS THEN
|
||||
INSERT INTO bulk_label_results
|
||||
VALUES (
|
||||
(v_assignment->>'task_id')::UUID,
|
||||
(v_assignment->>'label_id')::UUID,
|
||||
FALSE,
|
||||
SQLERRM
|
||||
);
|
||||
END;
|
||||
END LOOP;
|
||||
|
||||
RETURN QUERY SELECT * FROM bulk_label_results;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
@@ -0,0 +1,40 @@
|
||||
-- Create notifications table if it doesn't exist
|
||||
CREATE TABLE IF NOT EXISTS notifications (
|
||||
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
||||
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
message TEXT NOT NULL,
|
||||
data JSONB,
|
||||
read BOOLEAN DEFAULT FALSE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
read_at TIMESTAMP WITH TIME ZONE
|
||||
);
|
||||
|
||||
-- Create user_push_tokens table if it doesn't exist (for future push notifications)
|
||||
CREATE TABLE IF NOT EXISTS user_push_tokens (
|
||||
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
||||
user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE,
|
||||
push_token TEXT NOT NULL,
|
||||
device_type VARCHAR(20),
|
||||
active BOOLEAN DEFAULT TRUE,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(user_id, push_token)
|
||||
);
|
||||
|
||||
-- Add notification preferences to users table if they don't exist
|
||||
ALTER TABLE users
|
||||
ADD COLUMN IF NOT EXISTS email_notifications BOOLEAN DEFAULT TRUE,
|
||||
ADD COLUMN IF NOT EXISTS push_notifications BOOLEAN DEFAULT TRUE,
|
||||
ADD COLUMN IF NOT EXISTS in_app_notifications BOOLEAN DEFAULT TRUE;
|
||||
|
||||
-- Create indexes for better performance
|
||||
CREATE INDEX IF NOT EXISTS idx_notifications_user_id ON notifications(user_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_notifications_created_at ON notifications(created_at);
|
||||
CREATE INDEX IF NOT EXISTS idx_notifications_unread ON notifications(user_id, read) WHERE read = FALSE;
|
||||
CREATE INDEX IF NOT EXISTS idx_user_push_tokens_user_id ON user_push_tokens(user_id);
|
||||
|
||||
-- Comments
|
||||
COMMENT ON TABLE notifications IS 'In-app notifications for users';
|
||||
COMMENT ON TABLE user_push_tokens IS 'Push notification tokens for mobile devices';
|
||||
COMMENT ON COLUMN notifications.data IS 'Additional notification data in JSON format';
|
||||
COMMENT ON COLUMN user_push_tokens.device_type IS 'Device type: ios, android, web';
|
||||
@@ -0,0 +1,94 @@
|
||||
-- Create audit log table for recurring task operations
|
||||
CREATE TABLE IF NOT EXISTS recurring_tasks_audit_log (
|
||||
id UUID DEFAULT uuid_generate_v4() PRIMARY KEY,
|
||||
operation_type VARCHAR(50) NOT NULL,
|
||||
template_id UUID,
|
||||
schedule_id UUID,
|
||||
task_id UUID,
|
||||
template_name TEXT,
|
||||
success BOOLEAN DEFAULT TRUE,
|
||||
error_message TEXT,
|
||||
details JSONB,
|
||||
created_tasks_count INTEGER DEFAULT 0,
|
||||
failed_tasks_count INTEGER DEFAULT 0,
|
||||
execution_time_ms INTEGER,
|
||||
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
|
||||
created_by UUID REFERENCES users(id)
|
||||
);
|
||||
|
||||
-- Create indexes for better query performance
|
||||
CREATE INDEX idx_recurring_tasks_audit_log_template_id ON recurring_tasks_audit_log(template_id);
|
||||
CREATE INDEX idx_recurring_tasks_audit_log_schedule_id ON recurring_tasks_audit_log(schedule_id);
|
||||
CREATE INDEX idx_recurring_tasks_audit_log_created_at ON recurring_tasks_audit_log(created_at);
|
||||
CREATE INDEX idx_recurring_tasks_audit_log_operation_type ON recurring_tasks_audit_log(operation_type);
|
||||
|
||||
-- Add comments
|
||||
COMMENT ON TABLE recurring_tasks_audit_log IS 'Audit log for all recurring task operations';
|
||||
COMMENT ON COLUMN recurring_tasks_audit_log.operation_type IS 'Type of operation: cron_job_run, manual_trigger, schedule_created, schedule_updated, schedule_deleted, etc.';
|
||||
COMMENT ON COLUMN recurring_tasks_audit_log.details IS 'Additional details about the operation in JSON format';
|
||||
|
||||
-- Create a function to log recurring task operations
|
||||
CREATE OR REPLACE FUNCTION log_recurring_task_operation(
|
||||
p_operation_type VARCHAR(50),
|
||||
p_template_id UUID DEFAULT NULL,
|
||||
p_schedule_id UUID DEFAULT NULL,
|
||||
p_task_id UUID DEFAULT NULL,
|
||||
p_template_name TEXT DEFAULT NULL,
|
||||
p_success BOOLEAN DEFAULT TRUE,
|
||||
p_error_message TEXT DEFAULT NULL,
|
||||
p_details JSONB DEFAULT NULL,
|
||||
p_created_tasks_count INTEGER DEFAULT 0,
|
||||
p_failed_tasks_count INTEGER DEFAULT 0,
|
||||
p_execution_time_ms INTEGER DEFAULT NULL,
|
||||
p_created_by UUID DEFAULT NULL
|
||||
)
|
||||
RETURNS UUID AS $$
|
||||
DECLARE
|
||||
v_log_id UUID;
|
||||
BEGIN
|
||||
INSERT INTO recurring_tasks_audit_log (
|
||||
operation_type,
|
||||
template_id,
|
||||
schedule_id,
|
||||
task_id,
|
||||
template_name,
|
||||
success,
|
||||
error_message,
|
||||
details,
|
||||
created_tasks_count,
|
||||
failed_tasks_count,
|
||||
execution_time_ms,
|
||||
created_by
|
||||
) VALUES (
|
||||
p_operation_type,
|
||||
p_template_id,
|
||||
p_schedule_id,
|
||||
p_task_id,
|
||||
p_template_name,
|
||||
p_success,
|
||||
p_error_message,
|
||||
p_details,
|
||||
p_created_tasks_count,
|
||||
p_failed_tasks_count,
|
||||
p_execution_time_ms,
|
||||
p_created_by
|
||||
) RETURNING id INTO v_log_id;
|
||||
|
||||
RETURN v_log_id;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
|
||||
-- Create a view for recent audit logs
|
||||
CREATE OR REPLACE VIEW v_recent_recurring_tasks_audit AS
|
||||
SELECT
|
||||
l.*,
|
||||
u.name as created_by_name,
|
||||
t.name as current_template_name,
|
||||
s.schedule_type,
|
||||
s.timezone
|
||||
FROM recurring_tasks_audit_log l
|
||||
LEFT JOIN users u ON l.created_by = u.id
|
||||
LEFT JOIN task_recurring_templates t ON l.template_id = t.id
|
||||
LEFT JOIN task_recurring_schedules s ON l.schedule_id = s.id
|
||||
WHERE l.created_at >= CURRENT_TIMESTAMP - INTERVAL '30 days'
|
||||
ORDER BY l.created_at DESC;
|
||||
@@ -0,0 +1,44 @@
|
||||
-- Add timezone support to recurring tasks
|
||||
|
||||
-- Add timezone column to task_recurring_schedules
|
||||
ALTER TABLE task_recurring_schedules
|
||||
ADD COLUMN IF NOT EXISTS timezone VARCHAR(50) DEFAULT 'UTC';
|
||||
|
||||
-- Add timezone column to task_recurring_templates
|
||||
ALTER TABLE task_recurring_templates
|
||||
ADD COLUMN IF NOT EXISTS reporter_timezone VARCHAR(50);
|
||||
|
||||
-- Add date_of_month column if not exists (for monthly schedules)
|
||||
ALTER TABLE task_recurring_schedules
|
||||
ADD COLUMN IF NOT EXISTS date_of_month INTEGER;
|
||||
|
||||
-- Add last_checked_at and last_created_task_end_date columns for tracking
|
||||
ALTER TABLE task_recurring_schedules
|
||||
ADD COLUMN IF NOT EXISTS last_checked_at TIMESTAMP WITH TIME ZONE,
|
||||
ADD COLUMN IF NOT EXISTS last_created_task_end_date TIMESTAMP WITH TIME ZONE;
|
||||
|
||||
-- Add end_date and excluded_dates columns for schedule control
|
||||
ALTER TABLE task_recurring_schedules
|
||||
ADD COLUMN IF NOT EXISTS end_date DATE,
|
||||
ADD COLUMN IF NOT EXISTS excluded_dates TEXT[];
|
||||
|
||||
-- Create index on timezone for better query performance
|
||||
CREATE INDEX IF NOT EXISTS idx_task_recurring_schedules_timezone
|
||||
ON task_recurring_schedules(timezone);
|
||||
|
||||
-- Update existing records to use user's timezone if available
|
||||
UPDATE task_recurring_schedules trs
|
||||
SET timezone = COALESCE(
|
||||
(SELECT u.timezone
|
||||
FROM task_recurring_templates trt
|
||||
JOIN tasks t ON trt.task_id = t.id
|
||||
JOIN users u ON t.reporter_id = u.id
|
||||
WHERE trt.schedule_id = trs.id
|
||||
LIMIT 1),
|
||||
'UTC'
|
||||
)
|
||||
WHERE trs.timezone IS NULL OR trs.timezone = 'UTC';
|
||||
|
||||
-- Add comment to explain timezone field
|
||||
COMMENT ON COLUMN task_recurring_schedules.timezone IS 'IANA timezone identifier for schedule calculations';
|
||||
COMMENT ON COLUMN task_recurring_templates.reporter_timezone IS 'Original reporter timezone for reference';
|
||||
Reference in New Issue
Block a user