mirror of
https://github.com/abhinavxd/libredesk.git
synced 2025-11-03 05:23:48 +00:00
fix: Chat initialization failing due to the JWT authenticated user doesn't exist in the DB yet. fix: Always upsert custom attribues instead of replacing.
328 lines
8.7 KiB
SQL
328 lines
8.7 KiB
SQL
-- name: get-users
|
|
SELECT COUNT(*) OVER() as total, users.id, users.avatar_url, users.type, users.created_at, users.updated_at, users.first_name, users.last_name, users.email, users.enabled
|
|
FROM users
|
|
WHERE users.email != 'System' AND users.deleted_at IS NULL AND type = $1
|
|
|
|
-- name: soft-delete-agent
|
|
WITH soft_delete AS (
|
|
UPDATE users
|
|
SET deleted_at = now(), updated_at = now()
|
|
WHERE id = $1 AND type = 'agent'
|
|
RETURNING id
|
|
),
|
|
-- Delete from user_roles and teams
|
|
delete_team_members AS (
|
|
DELETE FROM team_members
|
|
WHERE user_id IN (SELECT id FROM soft_delete)
|
|
RETURNING 1
|
|
),
|
|
delete_user_roles AS (
|
|
DELETE FROM user_roles
|
|
WHERE user_id IN (SELECT id FROM soft_delete)
|
|
RETURNING 1
|
|
)
|
|
SELECT 1;
|
|
|
|
-- name: get-agents-compact
|
|
SELECT u.id, u.type, u.first_name, u.last_name, u.enabled, u.avatar_url
|
|
FROM users u
|
|
WHERE u.email != 'System' AND u.deleted_at IS NULL AND u.type = 'agent'
|
|
ORDER BY u.updated_at DESC;
|
|
|
|
-- name: get-user
|
|
SELECT
|
|
u.id,
|
|
u.created_at,
|
|
u.updated_at,
|
|
u.email,
|
|
u.password,
|
|
u.type,
|
|
u.created_at,
|
|
u.updated_at,
|
|
u.enabled,
|
|
u.avatar_url,
|
|
u.first_name,
|
|
u.last_name,
|
|
u.availability_status,
|
|
u.last_active_at,
|
|
u.last_login_at,
|
|
u.phone_number_calling_code,
|
|
u.phone_number,
|
|
u.api_key,
|
|
u.api_key_last_used_at,
|
|
u.external_user_id,
|
|
array_agg(DISTINCT r.name) FILTER (WHERE r.name IS NOT NULL) AS roles,
|
|
COALESCE(
|
|
(SELECT json_agg(json_build_object('id', t.id, 'name', t.name, 'emoji', t.emoji))
|
|
FROM team_members tm
|
|
JOIN teams t ON tm.team_id = t.id
|
|
WHERE tm.user_id = u.id),
|
|
'[]'
|
|
) AS teams,
|
|
array_agg(DISTINCT p ORDER BY p) FILTER (WHERE p IS NOT NULL) AS permissions
|
|
FROM users u
|
|
LEFT JOIN user_roles ur ON ur.user_id = u.id
|
|
LEFT JOIN roles r ON r.id = ur.role_id
|
|
LEFT JOIN LATERAL unnest(r.permissions) AS p ON true
|
|
WHERE u.deleted_at IS NULL
|
|
AND ($1 = 0 OR u.id = $1)
|
|
AND ($2 = '' OR u.email = $2)
|
|
AND ($3 = '' OR u.type::text = $3)
|
|
GROUP BY u.id;
|
|
|
|
-- name: set-user-password
|
|
UPDATE users
|
|
SET password = $1, updated_at = now()
|
|
WHERE id = $2;
|
|
|
|
-- name: update-agent
|
|
WITH not_removed_roles AS (
|
|
SELECT r.id FROM unnest($5::text[]) role_name
|
|
JOIN roles r ON r.name = role_name
|
|
),
|
|
old_roles AS (
|
|
DELETE FROM user_roles
|
|
WHERE user_id = $1
|
|
AND role_id NOT IN (SELECT id FROM not_removed_roles)
|
|
),
|
|
new_roles AS (
|
|
INSERT INTO user_roles (user_id, role_id)
|
|
SELECT $1, r.id FROM not_removed_roles r
|
|
ON CONFLICT (user_id, role_id) DO NOTHING
|
|
)
|
|
UPDATE users
|
|
SET first_name = COALESCE($2, first_name),
|
|
last_name = COALESCE($3, last_name),
|
|
email = COALESCE($4, email),
|
|
avatar_url = COALESCE($6, avatar_url),
|
|
password = COALESCE($7, password),
|
|
enabled = COALESCE($8, enabled),
|
|
availability_status = COALESCE($9, availability_status),
|
|
updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: update-custom-attributes
|
|
UPDATE users
|
|
SET custom_attributes = $2,
|
|
updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: upsert-custom-attributes
|
|
UPDATE users
|
|
SET custom_attributes = COALESCE(custom_attributes, '{}'::jsonb) || $2,
|
|
updated_at = now()
|
|
WHERE id = $1
|
|
|
|
-- name: update-avatar
|
|
UPDATE users
|
|
SET avatar_url = $2, updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: update-availability
|
|
UPDATE users
|
|
SET availability_status = $2
|
|
WHERE id = $1;
|
|
|
|
-- name: update-last-active-at
|
|
UPDATE users
|
|
SET last_active_at = now(),
|
|
availability_status = CASE WHEN availability_status = 'offline' THEN 'online' ELSE availability_status END
|
|
WHERE id = $1;
|
|
|
|
-- name: update-inactive-offline
|
|
UPDATE users
|
|
SET availability_status = 'offline'
|
|
WHERE
|
|
type = 'agent'
|
|
AND (last_active_at IS NULL OR last_active_at < NOW() - INTERVAL '5 minutes')
|
|
AND availability_status NOT IN ('offline', 'away_and_reassigning', 'away_manual');
|
|
|
|
-- name: set-reset-password-token
|
|
UPDATE users
|
|
SET reset_password_token = $2, reset_password_token_expiry = now() + interval '1 day'
|
|
WHERE id = $1 AND type = 'agent';
|
|
|
|
-- name: set-password
|
|
UPDATE users
|
|
SET password = $1, reset_password_token = NULL, reset_password_token_expiry = NULL
|
|
WHERE reset_password_token = $2 AND reset_password_token_expiry > now() AND type = 'agent';
|
|
|
|
-- name: insert-agent
|
|
WITH inserted_user AS (
|
|
INSERT INTO users (email, type, first_name, last_name, "password", avatar_url)
|
|
VALUES ($1, 'agent', $2, $3, $4, $5)
|
|
RETURNING id AS user_id
|
|
)
|
|
INSERT INTO user_roles (user_id, role_id)
|
|
SELECT inserted_user.user_id, r.id
|
|
FROM inserted_user, unnest($6::text[]) role_name
|
|
JOIN roles r ON r.name = role_name
|
|
RETURNING user_id;
|
|
|
|
-- name: insert-contact-with-external-id
|
|
INSERT INTO users (email, type, first_name, last_name, "password", avatar_url, external_user_id, custom_attributes)
|
|
VALUES ($1, 'contact', $2, $3, $4, $5, $6, $7)
|
|
ON CONFLICT (external_user_id) WHERE type = 'contact' AND deleted_at IS NULL AND external_user_id IS NOT NULL
|
|
DO UPDATE SET updated_at = now()
|
|
RETURNING id;
|
|
|
|
-- name: insert-contact-without-external-id
|
|
INSERT INTO users (email, type, first_name, last_name, "password", avatar_url, external_user_id)
|
|
VALUES ($1, 'contact', $2, $3, $4, $5, NULL)
|
|
ON CONFLICT (email) WHERE type = 'contact' AND deleted_at IS NULL AND external_user_id IS NULL
|
|
DO UPDATE SET updated_at = now()
|
|
RETURNING id;
|
|
|
|
-- name: insert-visitor
|
|
INSERT INTO users (email, type, first_name, last_name)
|
|
VALUES ($1, 'visitor', $2, $3)
|
|
RETURNING *;
|
|
|
|
-- name: update-last-login-at
|
|
UPDATE users
|
|
SET last_login_at = now(),
|
|
updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: toggle-enable
|
|
UPDATE users
|
|
SET enabled = $3, updated_at = NOW()
|
|
WHERE id = $1 AND type = $2;
|
|
|
|
-- name: update-contact
|
|
UPDATE users
|
|
SET first_name = COALESCE($2, first_name),
|
|
last_name = COALESCE($3, last_name),
|
|
email = COALESCE($4, email),
|
|
avatar_url = $5,
|
|
phone_number = $6,
|
|
phone_number_calling_code = $7,
|
|
updated_at = now()
|
|
WHERE id = $1 and type = 'contact';
|
|
|
|
-- name: get-notes
|
|
SELECT
|
|
cn.id,
|
|
cn.created_at,
|
|
cn.updated_at,
|
|
cn.contact_id,
|
|
cn.note,
|
|
cn.user_id,
|
|
u.first_name,
|
|
u.last_name,
|
|
u.avatar_url
|
|
FROM contact_notes cn
|
|
INNER JOIN users u ON u.id = cn.user_id
|
|
WHERE cn.contact_id = $1
|
|
ORDER BY cn.created_at DESC;
|
|
|
|
-- name: insert-note
|
|
INSERT INTO contact_notes (contact_id, user_id, note)
|
|
VALUES ($1, $2, $3);
|
|
|
|
-- name: delete-note
|
|
DELETE FROM contact_notes
|
|
WHERE id = $1 AND contact_id = $2;
|
|
|
|
-- name: get-note
|
|
SELECT
|
|
cn.id,
|
|
cn.created_at,
|
|
cn.updated_at,
|
|
cn.contact_id,
|
|
cn.note,
|
|
cn.user_id,
|
|
u.first_name,
|
|
u.last_name,
|
|
u.avatar_url
|
|
FROM contact_notes cn
|
|
INNER JOIN users u ON u.id = cn.user_id
|
|
WHERE cn.id = $1;
|
|
|
|
-- name: get-user-by-api-key
|
|
SELECT
|
|
u.id,
|
|
u.created_at,
|
|
u.updated_at,
|
|
u.email,
|
|
u.type,
|
|
u.enabled,
|
|
u.avatar_url,
|
|
u.first_name,
|
|
u.last_name,
|
|
u.availability_status,
|
|
u.last_active_at,
|
|
u.last_login_at,
|
|
u.phone_number_calling_code,
|
|
u.phone_number,
|
|
u.api_secret,
|
|
u.external_user_id,
|
|
array_agg(DISTINCT r.name) FILTER (WHERE r.name IS NOT NULL) AS roles,
|
|
COALESCE(
|
|
(SELECT json_agg(json_build_object('id', t.id, 'name', t.name, 'emoji', t.emoji))
|
|
FROM team_members tm
|
|
JOIN teams t ON tm.team_id = t.id
|
|
WHERE tm.user_id = u.id),
|
|
'[]'
|
|
) AS teams,
|
|
array_agg(DISTINCT p ORDER BY p) FILTER (WHERE p IS NOT NULL) AS permissions
|
|
FROM users u
|
|
LEFT JOIN user_roles ur ON ur.user_id = u.id
|
|
LEFT JOIN roles r ON r.id = ur.role_id
|
|
LEFT JOIN LATERAL unnest(r.permissions) AS p ON true
|
|
WHERE u.api_key = $1 AND u.enabled = true AND u.deleted_at IS NULL
|
|
GROUP BY u.id;
|
|
|
|
-- name: generate-api-key
|
|
UPDATE users
|
|
SET api_key = $2, api_secret = $3, api_key_last_used_at = NULL, updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: revoke-api-key
|
|
UPDATE users
|
|
SET api_key = NULL, api_secret = NULL, api_key_last_used_at = NULL, updated_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: update-api-key-last-used
|
|
UPDATE users
|
|
SET api_key_last_used_at = now()
|
|
WHERE id = $1;
|
|
|
|
-- name: get-user-by-external-id
|
|
SELECT
|
|
u.id,
|
|
u.created_at,
|
|
u.updated_at,
|
|
u.email,
|
|
u.password,
|
|
u.type,
|
|
u.enabled,
|
|
u.avatar_url,
|
|
u.first_name,
|
|
u.last_name,
|
|
u.availability_status,
|
|
u.last_active_at,
|
|
u.last_login_at,
|
|
u.phone_number_calling_code,
|
|
u.phone_number,
|
|
u.external_user_id,
|
|
u.custom_attributes,
|
|
u.api_key,
|
|
u.api_key_last_used_at,
|
|
array_agg(DISTINCT r.name) FILTER (WHERE r.name IS NOT NULL) AS roles,
|
|
COALESCE(
|
|
(SELECT json_agg(json_build_object('id', t.id, 'name', t.name, 'emoji', t.emoji))
|
|
FROM team_members tm
|
|
JOIN teams t ON tm.team_id = t.id
|
|
WHERE tm.user_id = u.id),
|
|
'[]'
|
|
) AS teams,
|
|
array_agg(DISTINCT p ORDER BY p) FILTER (WHERE p IS NOT NULL) AS permissions
|
|
FROM users u
|
|
LEFT JOIN user_roles ur ON ur.user_id = u.id
|
|
LEFT JOIN roles r ON r.id = ur.role_id
|
|
LEFT JOIN LATERAL unnest(r.permissions) AS p ON true
|
|
WHERE u.deleted_at IS NULL
|
|
AND u.external_user_id = $1
|
|
GROUP BY u.id;
|