mirror of
https://github.com/coder/coder.git
synced 2025-07-13 21:36:50 +00:00
Merge branch 'main' of github.com:/coder/coder into dk/prebuilds
Signed-off-by: Danny Kopping <dannykopping@gmail.com>
This commit is contained in:
59
coderd/database/queries/notificationsinbox.sql
Normal file
59
coderd/database/queries/notificationsinbox.sql
Normal file
@ -0,0 +1,59 @@
|
||||
-- name: GetInboxNotificationsByUserID :many
|
||||
-- Fetches inbox notifications for a user filtered by templates and targets
|
||||
-- param user_id: The user ID
|
||||
-- param read_status: The read status to filter by - can be any of 'ALL', 'UNREAD', 'READ'
|
||||
-- param created_at_opt: The created_at timestamp to filter by. This parameter is usd for pagination - it fetches notifications created before the specified timestamp if it is not the zero value
|
||||
-- param limit_opt: The limit of notifications to fetch. If the limit is not specified, it defaults to 25
|
||||
SELECT * FROM inbox_notifications WHERE
|
||||
user_id = @user_id AND
|
||||
(@read_status::inbox_notification_read_status = 'all' OR (@read_status::inbox_notification_read_status = 'unread' AND read_at IS NULL) OR (@read_status::inbox_notification_read_status = 'read' AND read_at IS NOT NULL)) AND
|
||||
(@created_at_opt::TIMESTAMPTZ = '0001-01-01 00:00:00Z' OR created_at < @created_at_opt::TIMESTAMPTZ)
|
||||
ORDER BY created_at DESC
|
||||
LIMIT (COALESCE(NULLIF(@limit_opt :: INT, 0), 25));
|
||||
|
||||
-- name: GetFilteredInboxNotificationsByUserID :many
|
||||
-- Fetches inbox notifications for a user filtered by templates and targets
|
||||
-- param user_id: The user ID
|
||||
-- param templates: The template IDs to filter by - the template_id = ANY(@templates::UUID[]) condition checks if the template_id is in the @templates array
|
||||
-- param targets: The target IDs to filter by - the targets @> COALESCE(@targets, ARRAY[]::UUID[]) condition checks if the targets array (from the DB) contains all the elements in the @targets array
|
||||
-- param read_status: The read status to filter by - can be any of 'ALL', 'UNREAD', 'READ'
|
||||
-- param created_at_opt: The created_at timestamp to filter by. This parameter is usd for pagination - it fetches notifications created before the specified timestamp if it is not the zero value
|
||||
-- param limit_opt: The limit of notifications to fetch. If the limit is not specified, it defaults to 25
|
||||
SELECT * FROM inbox_notifications WHERE
|
||||
user_id = @user_id AND
|
||||
template_id = ANY(@templates::UUID[]) AND
|
||||
targets @> COALESCE(@targets, ARRAY[]::UUID[]) AND
|
||||
(@read_status::inbox_notification_read_status = 'all' OR (@read_status::inbox_notification_read_status = 'unread' AND read_at IS NULL) OR (@read_status::inbox_notification_read_status = 'read' AND read_at IS NOT NULL)) AND
|
||||
(@created_at_opt::TIMESTAMPTZ = '0001-01-01 00:00:00Z' OR created_at < @created_at_opt::TIMESTAMPTZ)
|
||||
ORDER BY created_at DESC
|
||||
LIMIT (COALESCE(NULLIF(@limit_opt :: INT, 0), 25));
|
||||
|
||||
-- name: GetInboxNotificationByID :one
|
||||
SELECT * FROM inbox_notifications WHERE id = $1;
|
||||
|
||||
-- name: CountUnreadInboxNotificationsByUserID :one
|
||||
SELECT COUNT(*) FROM inbox_notifications WHERE user_id = $1 AND read_at IS NULL;
|
||||
|
||||
-- name: InsertInboxNotification :one
|
||||
INSERT INTO
|
||||
inbox_notifications (
|
||||
id,
|
||||
user_id,
|
||||
template_id,
|
||||
targets,
|
||||
title,
|
||||
content,
|
||||
icon,
|
||||
actions,
|
||||
created_at
|
||||
)
|
||||
VALUES
|
||||
($1, $2, $3, $4, $5, $6, $7, $8, $9) RETURNING *;
|
||||
|
||||
-- name: UpdateInboxNotificationReadStatus :exec
|
||||
UPDATE
|
||||
inbox_notifications
|
||||
SET
|
||||
read_at = $1
|
||||
WHERE
|
||||
id = $2;
|
@ -111,7 +111,7 @@ WHERE
|
||||
AND (COALESCE(array_length(@ids::uuid[], 1), 0) = 0 OR pd.id = ANY(@ids::uuid[]))
|
||||
AND (@tags::tagset = 'null'::tagset OR provisioner_tagset_contains(pd.tags::tagset, @tags::tagset))
|
||||
ORDER BY
|
||||
pd.created_at ASC
|
||||
pd.created_at DESC
|
||||
LIMIT
|
||||
sqlc.narg('limit')::int;
|
||||
|
||||
|
@ -50,42 +50,64 @@ WHERE
|
||||
id = ANY(@ids :: uuid [ ]);
|
||||
|
||||
-- name: GetProvisionerJobsByIDsWithQueuePosition :many
|
||||
WITH pending_jobs AS (
|
||||
SELECT
|
||||
id, created_at
|
||||
FROM
|
||||
provisioner_jobs
|
||||
WHERE
|
||||
started_at IS NULL
|
||||
AND
|
||||
canceled_at IS NULL
|
||||
AND
|
||||
completed_at IS NULL
|
||||
AND
|
||||
error IS NULL
|
||||
WITH filtered_provisioner_jobs AS (
|
||||
-- Step 1: Filter provisioner_jobs
|
||||
SELECT
|
||||
id, created_at
|
||||
FROM
|
||||
provisioner_jobs
|
||||
WHERE
|
||||
id = ANY(@ids :: uuid [ ]) -- Apply filter early to reduce dataset size before expensive JOIN
|
||||
),
|
||||
queue_position AS (
|
||||
SELECT
|
||||
id,
|
||||
ROW_NUMBER() OVER (ORDER BY created_at ASC) AS queue_position
|
||||
FROM
|
||||
pending_jobs
|
||||
pending_jobs AS (
|
||||
-- Step 2: Extract only pending jobs
|
||||
SELECT
|
||||
id, created_at, tags
|
||||
FROM
|
||||
provisioner_jobs
|
||||
WHERE
|
||||
job_status = 'pending'
|
||||
),
|
||||
queue_size AS (
|
||||
SELECT COUNT(*) AS count FROM pending_jobs
|
||||
ranked_jobs AS (
|
||||
-- Step 3: Rank only pending jobs based on provisioner availability
|
||||
SELECT
|
||||
pj.id,
|
||||
pj.created_at,
|
||||
ROW_NUMBER() OVER (PARTITION BY pd.id ORDER BY pj.created_at ASC) AS queue_position,
|
||||
COUNT(*) OVER (PARTITION BY pd.id) AS queue_size
|
||||
FROM
|
||||
pending_jobs pj
|
||||
INNER JOIN provisioner_daemons pd
|
||||
ON provisioner_tagset_contains(pd.tags, pj.tags) -- Join only on the small pending set
|
||||
),
|
||||
final_jobs AS (
|
||||
-- Step 4: Compute best queue position and max queue size per job
|
||||
SELECT
|
||||
fpj.id,
|
||||
fpj.created_at,
|
||||
COALESCE(MIN(rj.queue_position), 0) :: BIGINT AS queue_position, -- Best queue position across provisioners
|
||||
COALESCE(MAX(rj.queue_size), 0) :: BIGINT AS queue_size -- Max queue size across provisioners
|
||||
FROM
|
||||
filtered_provisioner_jobs fpj -- Use the pre-filtered dataset instead of full provisioner_jobs
|
||||
LEFT JOIN ranked_jobs rj
|
||||
ON fpj.id = rj.id -- Join with the ranking jobs CTE to assign a rank to each specified provisioner job.
|
||||
GROUP BY
|
||||
fpj.id, fpj.created_at
|
||||
)
|
||||
SELECT
|
||||
-- Step 5: Final SELECT with INNER JOIN provisioner_jobs
|
||||
fj.id,
|
||||
fj.created_at,
|
||||
sqlc.embed(pj),
|
||||
COALESCE(qp.queue_position, 0) AS queue_position,
|
||||
COALESCE(qs.count, 0) AS queue_size
|
||||
fj.queue_position,
|
||||
fj.queue_size
|
||||
FROM
|
||||
provisioner_jobs pj
|
||||
LEFT JOIN
|
||||
queue_position qp ON qp.id = pj.id
|
||||
LEFT JOIN
|
||||
queue_size qs ON TRUE
|
||||
WHERE
|
||||
pj.id = ANY(@ids :: uuid [ ]);
|
||||
final_jobs fj
|
||||
INNER JOIN provisioner_jobs pj
|
||||
ON fj.id = pj.id -- Ensure we retrieve full details from `provisioner_jobs`.
|
||||
-- JOIN with pj is required for sqlc.embed(pj) to compile successfully.
|
||||
ORDER BY
|
||||
fj.created_at;
|
||||
|
||||
-- name: GetProvisionerJobsByOrganizationAndStatusWithQueuePositionAndProvisioner :many
|
||||
WITH pending_jobs AS (
|
||||
|
@ -4,25 +4,25 @@ SELECT
|
||||
FROM
|
||||
custom_roles
|
||||
WHERE
|
||||
true
|
||||
-- @lookup_roles will filter for exact (role_name, org_id) pairs
|
||||
-- To do this manually in SQL, you can construct an array and cast it:
|
||||
-- cast(ARRAY[('customrole','ece79dac-926e-44ca-9790-2ff7c5eb6e0c')] AS name_organization_pair[])
|
||||
AND CASE WHEN array_length(@lookup_roles :: name_organization_pair[], 1) > 0 THEN
|
||||
-- Using 'coalesce' to avoid troubles with null literals being an empty string.
|
||||
(name, coalesce(organization_id, '00000000-0000-0000-0000-000000000000' ::uuid)) = ANY (@lookup_roles::name_organization_pair[])
|
||||
ELSE true
|
||||
END
|
||||
-- This allows fetching all roles, or just site wide roles
|
||||
AND CASE WHEN @exclude_org_roles :: boolean THEN
|
||||
organization_id IS null
|
||||
true
|
||||
-- @lookup_roles will filter for exact (role_name, org_id) pairs
|
||||
-- To do this manually in SQL, you can construct an array and cast it:
|
||||
-- cast(ARRAY[('customrole','ece79dac-926e-44ca-9790-2ff7c5eb6e0c')] AS name_organization_pair[])
|
||||
AND CASE WHEN array_length(@lookup_roles :: name_organization_pair[], 1) > 0 THEN
|
||||
-- Using 'coalesce' to avoid troubles with null literals being an empty string.
|
||||
(name, coalesce(organization_id, '00000000-0000-0000-0000-000000000000' ::uuid)) = ANY (@lookup_roles::name_organization_pair[])
|
||||
ELSE true
|
||||
END
|
||||
-- Allows fetching all roles to a particular organization
|
||||
AND CASE WHEN @organization_id :: uuid != '00000000-0000-0000-0000-000000000000'::uuid THEN
|
||||
organization_id = @organization_id
|
||||
ELSE true
|
||||
END
|
||||
END
|
||||
-- This allows fetching all roles, or just site wide roles
|
||||
AND CASE WHEN @exclude_org_roles :: boolean THEN
|
||||
organization_id IS null
|
||||
ELSE true
|
||||
END
|
||||
-- Allows fetching all roles to a particular organization
|
||||
AND CASE WHEN @organization_id :: uuid != '00000000-0000-0000-0000-000000000000'::uuid THEN
|
||||
organization_id = @organization_id
|
||||
ELSE true
|
||||
END
|
||||
;
|
||||
|
||||
-- name: DeleteCustomRole :exec
|
||||
@ -46,16 +46,16 @@ INSERT INTO
|
||||
updated_at
|
||||
)
|
||||
VALUES (
|
||||
-- Always force lowercase names
|
||||
lower(@name),
|
||||
@display_name,
|
||||
@organization_id,
|
||||
@site_permissions,
|
||||
@org_permissions,
|
||||
@user_permissions,
|
||||
now(),
|
||||
now()
|
||||
)
|
||||
-- Always force lowercase names
|
||||
lower(@name),
|
||||
@display_name,
|
||||
@organization_id,
|
||||
@site_permissions,
|
||||
@org_permissions,
|
||||
@user_permissions,
|
||||
now(),
|
||||
now()
|
||||
)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateCustomRole :one
|
||||
|
@ -1,3 +1,19 @@
|
||||
-- name: FetchVolumesResourceMonitorsUpdatedAfter :many
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
workspace_agent_volume_resource_monitors
|
||||
WHERE
|
||||
updated_at > $1;
|
||||
|
||||
-- name: FetchMemoryResourceMonitorsUpdatedAfter :many
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
workspace_agent_memory_resource_monitors
|
||||
WHERE
|
||||
updated_at > $1;
|
||||
|
||||
-- name: FetchMemoryResourceMonitorsByAgentID :one
|
||||
SELECT
|
||||
*
|
||||
|
@ -415,13 +415,11 @@ WHERE
|
||||
ORDER BY created_at DESC;
|
||||
|
||||
-- name: GetWorkspaceUniqueOwnerCountByTemplateIDs :many
|
||||
SELECT
|
||||
template_id, COUNT(DISTINCT owner_id) AS unique_owners_sum
|
||||
FROM
|
||||
workspaces
|
||||
WHERE
|
||||
template_id = ANY(@template_ids :: uuid[]) AND deleted = false
|
||||
GROUP BY template_id;
|
||||
SELECT templates.id AS template_id, COUNT(DISTINCT workspaces.owner_id) AS unique_owners_sum
|
||||
FROM templates
|
||||
LEFT JOIN workspaces ON workspaces.template_id = templates.id AND workspaces.deleted = false
|
||||
WHERE templates.id = ANY(@template_ids :: uuid[])
|
||||
GROUP BY templates.id;
|
||||
|
||||
-- name: InsertWorkspace :one
|
||||
INSERT INTO
|
||||
|
Reference in New Issue
Block a user