Merge branch 'feature/project-finance' of https://github.com/Worklenz/worklenz into feature/project-finance

This commit is contained in:
shancds
2025-05-23 06:22:00 +05:30
56 changed files with 2989 additions and 1172 deletions

View File

@@ -0,0 +1,160 @@
-- Migration: Fix progress_mode_type ENUM and casting issues
-- Date: 2025-04-27
-- Version: 1.0.0
BEGIN;
-- First, let's ensure the ENUM type exists with the correct values
DO $$
BEGIN
-- Check if the type exists
IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'progress_mode_type') THEN
CREATE TYPE progress_mode_type AS ENUM ('manual', 'weighted', 'time', 'default');
ELSE
-- Add any missing values to the existing ENUM
BEGIN
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'manual';
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'weighted';
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'time';
ALTER TYPE progress_mode_type ADD VALUE IF NOT EXISTS 'default';
EXCEPTION
WHEN duplicate_object THEN
-- Ignore if values already exist
NULL;
END;
END IF;
END $$;
-- Update functions to use proper type casting
CREATE OR REPLACE FUNCTION on_update_task_progress(_body json) RETURNS json
LANGUAGE plpgsql
AS
$$
DECLARE
_task_id UUID;
_progress_value INTEGER;
_parent_task_id UUID;
_project_id UUID;
_current_mode progress_mode_type;
BEGIN
_task_id = (_body ->> 'task_id')::UUID;
_progress_value = (_body ->> 'progress_value')::INTEGER;
_parent_task_id = (_body ->> 'parent_task_id')::UUID;
-- Get the project ID and determine the current progress mode
SELECT project_id INTO _project_id FROM tasks WHERE id = _task_id;
IF _project_id IS NOT NULL THEN
SELECT
CASE
WHEN use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
WHEN use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
WHEN use_time_progress IS TRUE THEN 'time'::progress_mode_type
ELSE 'default'::progress_mode_type
END
INTO _current_mode
FROM projects
WHERE id = _project_id;
ELSE
_current_mode := 'default'::progress_mode_type;
END IF;
-- Update the task with progress value and set the progress mode
UPDATE tasks
SET progress_value = _progress_value,
manual_progress = TRUE,
progress_mode = _current_mode,
updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id;
-- Return the updated task info
RETURN JSON_BUILD_OBJECT(
'task_id', _task_id,
'progress_value', _progress_value,
'progress_mode', _current_mode
);
END;
$$;
-- Update the on_update_task_weight function to use proper type casting
CREATE OR REPLACE FUNCTION on_update_task_weight(_body json) RETURNS json
LANGUAGE plpgsql
AS
$$
DECLARE
_task_id UUID;
_weight INTEGER;
_parent_task_id UUID;
_project_id UUID;
BEGIN
_task_id = (_body ->> 'task_id')::UUID;
_weight = (_body ->> 'weight')::INTEGER;
_parent_task_id = (_body ->> 'parent_task_id')::UUID;
-- Get the project ID
SELECT project_id INTO _project_id FROM tasks WHERE id = _task_id;
-- Update the task with weight value and set progress_mode to 'weighted'
UPDATE tasks
SET weight = _weight,
progress_mode = 'weighted'::progress_mode_type,
updated_at = CURRENT_TIMESTAMP
WHERE id = _task_id;
-- Return the updated task info
RETURN JSON_BUILD_OBJECT(
'task_id', _task_id,
'weight', _weight
);
END;
$$;
-- Update the reset_project_progress_values function to use proper type casting
CREATE OR REPLACE FUNCTION reset_project_progress_values() RETURNS TRIGGER
LANGUAGE plpgsql
AS
$$
DECLARE
_old_mode progress_mode_type;
_new_mode progress_mode_type;
_project_id UUID;
BEGIN
_project_id := NEW.id;
-- Determine old and new modes with proper type casting
_old_mode :=
CASE
WHEN OLD.use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
WHEN OLD.use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
WHEN OLD.use_time_progress IS TRUE THEN 'time'::progress_mode_type
ELSE 'default'::progress_mode_type
END;
_new_mode :=
CASE
WHEN NEW.use_manual_progress IS TRUE THEN 'manual'::progress_mode_type
WHEN NEW.use_weighted_progress IS TRUE THEN 'weighted'::progress_mode_type
WHEN NEW.use_time_progress IS TRUE THEN 'time'::progress_mode_type
ELSE 'default'::progress_mode_type
END;
-- If mode has changed, reset progress values for tasks with the old mode
IF _old_mode <> _new_mode THEN
-- Reset progress values for tasks that were set in the old mode
UPDATE tasks
SET progress_value = NULL,
progress_mode = NULL
WHERE project_id = _project_id
AND progress_mode = _old_mode;
END IF;
RETURN NEW;
END;
$$;
-- Update the tasks table to ensure proper type casting for existing values
UPDATE tasks
SET progress_mode = progress_mode::text::progress_mode_type
WHERE progress_mode IS NOT NULL;
COMMIT;

View File

@@ -23,33 +23,40 @@ ALTER TABLE projects
ADD COLUMN IF NOT EXISTS use_time_progress BOOLEAN DEFAULT FALSE;
-- Update function to consider manual progress
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id UUID) RETURNS JSON
CREATE OR REPLACE FUNCTION get_task_complete_ratio(_task_id uuid) RETURNS json
LANGUAGE plpgsql
AS
$$
DECLARE
_parent_task_done FLOAT = 0;
_sub_tasks_done FLOAT = 0;
_sub_tasks_count FLOAT = 0;
_total_completed FLOAT = 0;
_total_tasks FLOAT = 0;
_ratio FLOAT = 0;
_is_manual BOOLEAN = FALSE;
_manual_value INTEGER = NULL;
_project_id UUID;
_use_manual_progress BOOLEAN = FALSE;
_parent_task_done FLOAT = 0;
_sub_tasks_done FLOAT = 0;
_sub_tasks_count FLOAT = 0;
_total_completed FLOAT = 0;
_total_tasks FLOAT = 0;
_ratio FLOAT = 0;
_is_manual BOOLEAN = FALSE;
_manual_value INTEGER = NULL;
_project_id UUID;
_use_manual_progress BOOLEAN = FALSE;
_use_weighted_progress BOOLEAN = FALSE;
_use_time_progress BOOLEAN = FALSE;
_use_time_progress BOOLEAN = FALSE;
_task_complete BOOLEAN = FALSE;
_progress_mode VARCHAR(20) = NULL;
BEGIN
-- Check if manual progress is set
SELECT manual_progress, progress_value, project_id
-- Check if manual progress is set for this task
SELECT manual_progress, progress_value, project_id, progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = tasks.id
AND is_done IS TRUE
) AS is_complete
FROM tasks
WHERE id = _task_id
INTO _is_manual, _manual_value, _project_id;
INTO _is_manual, _manual_value, _project_id, _progress_mode, _task_complete;
-- Check if the project uses manual progress
IF _project_id IS NOT NULL
THEN
IF _project_id IS NOT NULL THEN
SELECT COALESCE(use_manual_progress, FALSE),
COALESCE(use_weighted_progress, FALSE),
COALESCE(use_time_progress, FALSE)
@@ -58,49 +65,212 @@ BEGIN
INTO _use_manual_progress, _use_weighted_progress, _use_time_progress;
END IF;
-- If manual progress is enabled and has a value, use it directly
IF _is_manual IS TRUE AND _manual_value IS NOT NULL
THEN
-- Get all subtasks
SELECT COUNT(*)
FROM tasks
WHERE parent_task_id = _task_id AND archived IS FALSE
INTO _sub_tasks_count;
-- If task is complete, always return 100%
IF _task_complete IS TRUE THEN
RETURN JSON_BUILD_OBJECT(
'ratio', 100,
'total_completed', 1,
'total_tasks', 1,
'is_manual', FALSE
);
END IF;
-- Determine current active mode
DECLARE
_current_mode VARCHAR(20) = CASE
WHEN _use_manual_progress IS TRUE THEN 'manual'
WHEN _use_weighted_progress IS TRUE THEN 'weighted'
WHEN _use_time_progress IS TRUE THEN 'time'
ELSE 'default'
END;
BEGIN
-- Only use manual progress value if it was set in the current active mode
-- and time progress is not enabled
IF _use_time_progress IS FALSE AND
((_is_manual IS TRUE AND _manual_value IS NOT NULL AND
(_progress_mode IS NULL OR _progress_mode = _current_mode)) OR
(_use_manual_progress IS TRUE AND _manual_value IS NOT NULL AND
(_progress_mode IS NULL OR _progress_mode = 'manual'))) THEN
RETURN JSON_BUILD_OBJECT(
'ratio', _manual_value,
'total_completed', 0,
'total_tasks', 0,
'is_manual', TRUE
);
);
END IF;
END;
-- If there are no subtasks, calculate based on the task itself
IF _sub_tasks_count = 0 THEN
-- Use time-based estimation if enabled
IF _use_time_progress IS TRUE THEN
-- Calculate progress based on logged time vs estimated time
WITH task_time_info AS (
SELECT
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes
FROM tasks t
WHERE t.id = _task_id
)
SELECT
CASE
WHEN _task_complete IS TRUE THEN 100
WHEN estimated_minutes > 0 THEN
LEAST((logged_minutes / estimated_minutes) * 100, 100)
ELSE 0
END
INTO _ratio
FROM task_time_info;
ELSE
-- Traditional calculation for non-time-based tasks
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
INTO _parent_task_done;
_ratio = _parent_task_done * 100;
END IF;
ELSE
-- If project uses manual progress, calculate based on subtask manual progress values
IF _use_manual_progress IS TRUE AND _use_time_progress IS FALSE THEN
WITH subtask_progress AS (
SELECT
t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
),
subtask_with_values AS (
SELECT
CASE
WHEN is_complete IS TRUE THEN 100
WHEN progress_value IS NOT NULL AND (progress_mode = 'manual' OR progress_mode IS NULL) THEN progress_value
ELSE 0
END AS progress_value
FROM subtask_progress
)
SELECT COALESCE(AVG(progress_value), 0)
FROM subtask_with_values
INTO _ratio;
-- If project uses weighted progress, calculate based on subtask weights
ELSIF _use_weighted_progress IS TRUE AND _use_time_progress IS FALSE THEN
WITH subtask_progress AS (
SELECT
t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete,
COALESCE(t.weight, 100) AS weight
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
),
subtask_with_values AS (
SELECT
CASE
WHEN is_complete IS TRUE THEN 100
WHEN progress_value IS NOT NULL AND (progress_mode = 'weighted' OR progress_mode IS NULL) THEN progress_value
ELSE 0
END AS progress_value,
weight
FROM subtask_progress
)
SELECT COALESCE(
SUM(progress_value * weight) / NULLIF(SUM(weight), 0),
0
)
FROM subtask_with_values
INTO _ratio;
-- If project uses time-based progress, calculate based on actual logged time
ELSIF _use_time_progress IS TRUE THEN
WITH task_time_info AS (
SELECT
t.id,
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
)
SELECT COALESCE(
SUM(
CASE
WHEN is_complete IS TRUE THEN estimated_minutes
ELSE LEAST(logged_minutes, estimated_minutes)
END
) / NULLIF(SUM(estimated_minutes), 0) * 100,
0
)
FROM task_time_info
INTO _ratio;
ELSE
-- Traditional calculation based on completion status
SELECT (CASE WHEN _task_complete IS TRUE THEN 1 ELSE 0 END)
INTO _parent_task_done;
SELECT COUNT(*)
FROM tasks_with_status_view
WHERE parent_task_id = _task_id
AND is_done IS TRUE
INTO _sub_tasks_done;
_total_completed = _parent_task_done + _sub_tasks_done;
_total_tasks = _sub_tasks_count + 1; -- +1 for the parent task
IF _total_tasks = 0 THEN
_ratio = 0;
ELSE
_ratio = (_total_completed / _total_tasks) * 100;
END IF;
END IF;
END IF;
-- Otherwise calculate automatically as before
SELECT (CASE
WHEN EXISTS(SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = _task_id
AND is_done IS TRUE) THEN 1
ELSE 0 END)
INTO _parent_task_done;
SELECT COUNT(*) FROM tasks WHERE parent_task_id = _task_id AND archived IS FALSE INTO _sub_tasks_count;
SELECT COUNT(*)
FROM tasks_with_status_view
WHERE parent_task_id = _task_id
AND is_done IS TRUE
INTO _sub_tasks_done;
_total_completed = _parent_task_done + _sub_tasks_done;
_total_tasks = _sub_tasks_count; -- +1 for the parent task
IF _total_tasks > 0
THEN
_ratio = (_total_completed / _total_tasks) * 100;
ELSE
_ratio = _parent_task_done * 100;
-- Ensure ratio is between 0 and 100
IF _ratio < 0 THEN
_ratio = 0;
ELSIF _ratio > 100 THEN
_ratio = 100;
END IF;
RETURN JSON_BUILD_OBJECT(
'ratio', _ratio,
'total_completed', _total_completed,
'total_tasks', _total_tasks,
'is_manual', FALSE
);
'ratio', _ratio,
'total_completed', _total_completed,
'total_tasks', _total_tasks,
'is_manual', _is_manual
);
END
$$;
@@ -615,38 +785,38 @@ BEGIN
)
FROM subtask_with_values
INTO _ratio;
-- If project uses time-based progress, calculate based on estimated time
-- If project uses time-based progress, calculate based on actual logged time
ELSIF _use_time_progress IS TRUE
THEN
WITH subtask_progress AS (SELECT t.id,
t.manual_progress,
t.progress_value,
t.progress_mode,
EXISTS(SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE) AS is_complete,
COALESCE(t.total_minutes, 0) AS estimated_minutes
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE),
subtask_with_values AS (SELECT CASE
-- For completed tasks, always use 100%
WHEN is_complete IS TRUE THEN 100
-- For tasks with progress value set in the correct mode, use it
WHEN progress_value IS NOT NULL AND
(progress_mode = 'time' OR progress_mode IS NULL)
THEN progress_value
-- Default to 0 for incomplete tasks with no progress value or wrong mode
ELSE 0
END AS progress_value,
estimated_minutes
FROM subtask_progress)
WITH task_time_info AS (
SELECT
t.id,
COALESCE(t.total_minutes, 0) as estimated_minutes,
COALESCE((
SELECT SUM(time_spent)
FROM task_work_log
WHERE task_id = t.id
), 0) as logged_minutes,
EXISTS(
SELECT 1
FROM tasks_with_status_view
WHERE tasks_with_status_view.task_id = t.id
AND is_done IS TRUE
) AS is_complete
FROM tasks t
WHERE t.parent_task_id = _task_id
AND t.archived IS FALSE
)
SELECT COALESCE(
SUM(progress_value * estimated_minutes) / NULLIF(SUM(estimated_minutes), 0),
0
)
FROM subtask_with_values
SUM(
CASE
WHEN is_complete IS TRUE THEN estimated_minutes
ELSE LEAST(logged_minutes, estimated_minutes)
END
) / NULLIF(SUM(estimated_minutes), 0) * 100,
0
)
FROM task_time_info
INTO _ratio;
ELSE
-- Traditional calculation based on completion status

View File

@@ -3351,15 +3351,15 @@ BEGIN
SELECT COALESCE(ARRAY_TO_JSON(ARRAY_AGG(ROW_TO_JSON(rec))), '[]'::JSON)
FROM (SELECT team_member_id,
project_member_id,
(SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id),
(SELECT email_notifications_enabled
COALESCE((SELECT name FROM team_member_info_view WHERE team_member_info_view.team_member_id = tm.id), '') as name,
COALESCE((SELECT email_notifications_enabled
FROM notification_settings
WHERE team_id = tm.team_id
AND notification_settings.user_id = u.id) AS email_notifications_enabled,
u.avatar_url,
AND notification_settings.user_id = u.id), false) AS email_notifications_enabled,
COALESCE(u.avatar_url, '') as avatar_url,
u.id AS user_id,
u.email,
u.socket_id AS socket_id,
COALESCE(u.email, '') as email,
COALESCE(u.socket_id, '') as socket_id,
tm.team_id AS team_id
FROM tasks_assignees
INNER JOIN team_members tm ON tm.id = tasks_assignees.team_member_id
@@ -4066,14 +4066,14 @@ DECLARE
_schedule_id JSON;
_task_completed_at TIMESTAMPTZ;
BEGIN
SELECT name FROM tasks WHERE id = _task_id INTO _task_name;
SELECT COALESCE(name, '') FROM tasks WHERE id = _task_id INTO _task_name;
SELECT name
SELECT COALESCE(name, '')
FROM task_statuses
WHERE id = (SELECT status_id FROM tasks WHERE id = _task_id)
INTO _previous_status_name;
SELECT name FROM task_statuses WHERE id = _status_id INTO _new_status_name;
SELECT COALESCE(name, '') FROM task_statuses WHERE id = _status_id INTO _new_status_name;
IF (_previous_status_name != _new_status_name)
THEN
@@ -4081,14 +4081,22 @@ BEGIN
SELECT get_task_complete_info(_task_id, _status_id) INTO _task_info;
SELECT name FROM users WHERE id = _user_id INTO _updater_name;
SELECT COALESCE(name, '') FROM users WHERE id = _user_id INTO _updater_name;
_message = CONCAT(_updater_name, ' transitioned "', _task_name, '" from ', _previous_status_name, '',
_new_status_name);
END IF;
SELECT completed_at FROM tasks WHERE id = _task_id INTO _task_completed_at;
SELECT schedule_id FROM tasks WHERE id = _task_id INTO _schedule_id;
-- Handle schedule_id properly for recurring tasks
SELECT CASE
WHEN schedule_id IS NULL THEN 'null'::json
ELSE json_build_object('id', schedule_id)
END
FROM tasks
WHERE id = _task_id
INTO _schedule_id;
SELECT COALESCE(ROW_TO_JSON(r), '{}'::JSON)
FROM (SELECT is_done, is_doing, is_todo
@@ -4097,7 +4105,7 @@ BEGIN
INTO _status_category;
RETURN JSON_BUILD_OBJECT(
'message', _message,
'message', COALESCE(_message, ''),
'project_id', (SELECT project_id FROM tasks WHERE id = _task_id),
'parent_done', (CASE
WHEN EXISTS(SELECT 1
@@ -4105,14 +4113,14 @@ BEGIN
WHERE tasks_with_status_view.task_id = _task_id
AND is_done IS TRUE) THEN 1
ELSE 0 END),
'color_code', (_task_info ->> 'color_code')::TEXT,
'color_code_dark', (_task_info ->> 'color_code_dark')::TEXT,
'total_tasks', (_task_info ->> 'total_tasks')::INT,
'total_completed', (_task_info ->> 'total_completed')::INT,
'members', (_task_info ->> 'members')::JSON,
'color_code', COALESCE((_task_info ->> 'color_code')::TEXT, ''),
'color_code_dark', COALESCE((_task_info ->> 'color_code_dark')::TEXT, ''),
'total_tasks', COALESCE((_task_info ->> 'total_tasks')::INT, 0),
'total_completed', COALESCE((_task_info ->> 'total_completed')::INT, 0),
'members', COALESCE((_task_info ->> 'members')::JSON, '[]'::JSON),
'completed_at', _task_completed_at,
'status_category', _status_category,
'schedule_id', _schedule_id
'status_category', COALESCE(_status_category, '{}'::JSON),
'schedule_id', COALESCE(_schedule_id, 'null'::JSON)
);
END
$$;
@@ -6148,3 +6156,219 @@ BEGIN
RETURN v_new_id;
END;
$$;
CREATE OR REPLACE FUNCTION transfer_team_ownership(_team_id UUID, _new_owner_id UUID) RETURNS json
LANGUAGE plpgsql
AS
$$
DECLARE
_old_owner_id UUID;
_owner_role_id UUID;
_admin_role_id UUID;
_old_org_id UUID;
_new_org_id UUID;
_has_license BOOLEAN;
_old_owner_role_id UUID;
_new_owner_role_id UUID;
_has_active_coupon BOOLEAN;
_other_teams_count INTEGER;
_new_owner_org_id UUID;
_license_type_id UUID;
_has_valid_license BOOLEAN;
BEGIN
-- Get the current owner's ID and organization
SELECT t.user_id, t.organization_id
INTO _old_owner_id, _old_org_id
FROM teams t
WHERE t.id = _team_id;
IF _old_owner_id IS NULL THEN
RAISE EXCEPTION 'Team not found';
END IF;
-- Get the new owner's organization
SELECT organization_id INTO _new_owner_org_id
FROM organizations
WHERE user_id = _new_owner_id;
-- Get the old organization
SELECT id INTO _old_org_id
FROM organizations
WHERE id = _old_org_id;
IF _old_org_id IS NULL THEN
RAISE EXCEPTION 'Organization not found';
END IF;
-- Check if new owner has any valid license type
SELECT EXISTS (
SELECT 1
FROM (
-- Check regular subscriptions
SELECT lus.user_id, lus.status, lus.active
FROM licensing_user_subscriptions lus
WHERE lus.user_id = _new_owner_id
AND lus.active = TRUE
AND lus.status IN ('active', 'trialing')
UNION ALL
-- Check custom subscriptions
SELECT lcs.user_id, lcs.subscription_status as status, TRUE as active
FROM licensing_custom_subs lcs
WHERE lcs.user_id = _new_owner_id
AND lcs.end_date > CURRENT_DATE
UNION ALL
-- Check trial status in organizations
SELECT o.user_id, o.subscription_status as status, TRUE as active
FROM organizations o
WHERE o.user_id = _new_owner_id
AND o.trial_in_progress = TRUE
AND o.trial_expire_date > CURRENT_DATE
) valid_licenses
) INTO _has_valid_license;
IF NOT _has_valid_license THEN
RAISE EXCEPTION 'New owner does not have a valid license (subscription, custom subscription, or trial)';
END IF;
-- Check if new owner has any active coupon codes
SELECT EXISTS (
SELECT 1
FROM licensing_coupon_codes lcc
WHERE lcc.redeemed_by = _new_owner_id
AND lcc.is_redeemed = TRUE
AND lcc.is_refunded = FALSE
) INTO _has_active_coupon;
IF _has_active_coupon THEN
RAISE EXCEPTION 'New owner has active coupon codes that need to be handled before transfer';
END IF;
-- Count other teams in the organization for information purposes
SELECT COUNT(*) INTO _other_teams_count
FROM teams
WHERE organization_id = _old_org_id
AND id != _team_id;
-- If new owner has their own organization, move the team to their organization
IF _new_owner_org_id IS NOT NULL THEN
-- Update the team to use the new owner's organization
UPDATE teams
SET user_id = _new_owner_id,
organization_id = _new_owner_org_id
WHERE id = _team_id;
-- Create notification about organization change
PERFORM create_notification(
_old_owner_id,
_team_id,
NULL,
NULL,
CONCAT('Team <b>', (SELECT name FROM teams WHERE id = _team_id), '</b> has been moved to a different organization')
);
PERFORM create_notification(
_new_owner_id,
_team_id,
NULL,
NULL,
CONCAT('Team <b>', (SELECT name FROM teams WHERE id = _team_id), '</b> has been moved to your organization')
);
ELSE
-- If new owner doesn't have an organization, transfer the old organization to them
UPDATE organizations
SET user_id = _new_owner_id
WHERE id = _old_org_id;
-- Update the team to use the same organization
UPDATE teams
SET user_id = _new_owner_id,
organization_id = _old_org_id
WHERE id = _team_id;
-- Notify both users about organization ownership transfer
PERFORM create_notification(
_old_owner_id,
NULL,
NULL,
NULL,
CONCAT('You are no longer the owner of organization <b>', (SELECT organization_name FROM organizations WHERE id = _old_org_id), '</b>')
);
PERFORM create_notification(
_new_owner_id,
NULL,
NULL,
NULL,
CONCAT('You are now the owner of organization <b>', (SELECT organization_name FROM organizations WHERE id = _old_org_id), '</b>')
);
END IF;
-- Get the owner and admin role IDs
SELECT id INTO _owner_role_id FROM roles WHERE team_id = _team_id AND owner = TRUE;
SELECT id INTO _admin_role_id FROM roles WHERE team_id = _team_id AND admin_role = TRUE;
-- Get current role IDs for both users
SELECT role_id INTO _old_owner_role_id
FROM team_members
WHERE team_id = _team_id AND user_id = _old_owner_id;
SELECT role_id INTO _new_owner_role_id
FROM team_members
WHERE team_id = _team_id AND user_id = _new_owner_id;
-- Update the old owner's role to admin if they want to stay in the team
IF _old_owner_role_id IS NOT NULL THEN
UPDATE team_members
SET role_id = _admin_role_id
WHERE team_id = _team_id AND user_id = _old_owner_id;
END IF;
-- Update the new owner's role to owner
IF _new_owner_role_id IS NOT NULL THEN
UPDATE team_members
SET role_id = _owner_role_id
WHERE team_id = _team_id AND user_id = _new_owner_id;
ELSE
-- If new owner is not a team member yet, add them
INSERT INTO team_members (user_id, team_id, role_id)
VALUES (_new_owner_id, _team_id, _owner_role_id);
END IF;
-- Create notification for both users about team ownership
PERFORM create_notification(
_old_owner_id,
_team_id,
NULL,
NULL,
CONCAT('You are no longer the owner of team <b>', (SELECT name FROM teams WHERE id = _team_id), '</b>')
);
PERFORM create_notification(
_new_owner_id,
_team_id,
NULL,
NULL,
CONCAT('You are now the owner of team <b>', (SELECT name FROM teams WHERE id = _team_id), '</b>')
);
RETURN json_build_object(
'success', TRUE,
'old_owner_id', _old_owner_id,
'new_owner_id', _new_owner_id,
'team_id', _team_id,
'old_org_id', _old_org_id,
'new_org_id', COALESCE(_new_owner_org_id, _old_org_id),
'old_role_id', _old_owner_role_id,
'new_role_id', _new_owner_role_id,
'has_valid_license', _has_valid_license,
'has_active_coupon', _has_active_coupon,
'other_teams_count', _other_teams_count,
'org_ownership_transferred', _new_owner_org_id IS NULL,
'team_moved_to_new_org', _new_owner_org_id IS NOT NULL
);
END;
$$;