Files
coder/coderd/database/queries/workspaces.sql
Presley Pizzo 7c238f13e5 feat: paginate workspaces page (#4647)
* Start - still needs api call changes

* Some xservice changes

* Finish adding count to xservice

* Mock out api call on frontend

* Handle errors

* Doctor getWorkspaces

* Add types, start writing count function

* Hook up route

* Use empty page struct

* Write interface and database fake

* SQL query

* Fix params type

* Missed a spot

* Space after alert banner

* Fix model queries

* Unpack query correctly

* Fix filter-page interaction

* Make mobile friendly

* Format

* Test backend

* Fix key

* Delete unnecessary conditional

* Add test helpers

* Use limit constant

* Show widget with no count

* Add test

* Format

* make gen from garretts workspace idk why

* fix authorize test'

* Hide widget with 0 records

* Fix tests

* Format

* Fix types generated

* Fix story

* Add alert banner story

* Format

* Fix import

* Format

* Try removing story

* Revert "Fix story"

This reverts commit c06765b7fb.

* Add counts to page view story

* Revert "Try removing story"

This reverts commit 476019b041.

Co-authored-by: Garrett <garrett@coder.com>
2022-10-20 13:23:14 -04:00

368 lines
9.0 KiB
SQL

-- name: GetWorkspaceByID :one
SELECT
*
FROM
workspaces
WHERE
id = $1
LIMIT
1;
-- name: GetWorkspaces :many
SELECT
workspaces.*
FROM
workspaces
LEFT JOIN LATERAL (
SELECT
workspace_builds.transition,
provisioner_jobs.started_at,
provisioner_jobs.updated_at,
provisioner_jobs.canceled_at,
provisioner_jobs.completed_at,
provisioner_jobs.error
FROM
workspace_builds
LEFT JOIN
provisioner_jobs
ON
provisioner_jobs.id = workspace_builds.job_id
WHERE
workspace_builds.workspace_id = workspaces.id
ORDER BY
build_number DESC
LIMIT
1
) latest_build ON TRUE
WHERE
-- Optionally include deleted workspaces
workspaces.deleted = @deleted
AND CASE
WHEN @status :: text != '' THEN
CASE
WHEN @status = 'pending' THEN
latest_build.started_at IS NULL
WHEN @status = 'starting' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'start'::workspace_transition
WHEN @status = 'running' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'start'::workspace_transition
WHEN @status = 'stopping' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'stop'::workspace_transition
WHEN @status = 'stopped' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'stop'::workspace_transition
WHEN @status = 'failed' THEN
(latest_build.canceled_at IS NOT NULL AND
latest_build.error IS NOT NULL) OR
(latest_build.completed_at IS NOT NULL AND
latest_build.error IS NOT NULL)
WHEN @status = 'canceling' THEN
latest_build.canceled_at IS NOT NULL AND
latest_build.completed_at IS NULL
WHEN @status = 'canceled' THEN
latest_build.canceled_at IS NOT NULL AND
latest_build.completed_at IS NOT NULL
WHEN @status = 'deleted' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NOT NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'delete'::workspace_transition
WHEN @status = 'deleting' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'delete'::workspace_transition
ELSE
true
END
ELSE true
END
-- Filter by owner_id
AND CASE
WHEN @owner_id :: uuid != '00000000-00000000-00000000-00000000' THEN
owner_id = @owner_id
ELSE true
END
-- Filter by owner_name
AND CASE
WHEN @owner_username :: text != '' THEN
owner_id = (SELECT id FROM users WHERE lower(username) = lower(@owner_username) AND deleted = false)
ELSE true
END
-- Filter by template_name
-- There can be more than 1 template with the same name across organizations.
-- Use the organization filter to restrict to 1 org if needed.
AND CASE
WHEN @template_name :: text != '' THEN
template_id = ANY(SELECT id FROM templates WHERE lower(name) = lower(@template_name) AND deleted = false)
ELSE true
END
-- Filter by template_ids
AND CASE
WHEN array_length(@template_ids :: uuid[], 1) > 0 THEN
template_id = ANY(@template_ids)
ELSE true
END
-- Filter by name, matching on substring
AND CASE
WHEN @name :: text != '' THEN
name ILIKE '%' || @name || '%'
ELSE true
END
-- Authorize Filter clause will be injected below in GetAuthorizedWorkspaces
-- @authorize_filter
ORDER BY
last_used_at DESC
LIMIT
CASE
WHEN @limit_ :: integer > 0 THEN
@limit_
END
OFFSET
@offset_
;
-- this duplicates the filtering in GetWorkspaces
-- name: GetWorkspaceCount :one
SELECT
COUNT(*) as count
FROM
workspaces
LEFT JOIN LATERAL (
SELECT
workspace_builds.transition,
provisioner_jobs.started_at,
provisioner_jobs.updated_at,
provisioner_jobs.canceled_at,
provisioner_jobs.completed_at,
provisioner_jobs.error
FROM
workspace_builds
LEFT JOIN
provisioner_jobs
ON
provisioner_jobs.id = workspace_builds.job_id
WHERE
workspace_builds.workspace_id = workspaces.id
ORDER BY
build_number DESC
LIMIT
1
) latest_build ON TRUE
WHERE
-- Optionally include deleted workspaces
workspaces.deleted = @deleted
AND CASE
WHEN @status :: text != '' THEN
CASE
WHEN @status = 'pending' THEN
latest_build.started_at IS NULL
WHEN @status = 'starting' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'start'::workspace_transition
WHEN @status = 'running' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'start'::workspace_transition
WHEN @status = 'stopping' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'stop'::workspace_transition
WHEN @status = 'stopped' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'stop'::workspace_transition
WHEN @status = 'failed' THEN
(latest_build.canceled_at IS NOT NULL AND
latest_build.error IS NOT NULL) OR
(latest_build.completed_at IS NOT NULL AND
latest_build.error IS NOT NULL)
WHEN @status = 'canceling' THEN
latest_build.canceled_at IS NOT NULL AND
latest_build.completed_at IS NULL
WHEN @status = 'canceled' THEN
latest_build.canceled_at IS NOT NULL AND
latest_build.completed_at IS NOT NULL
WHEN @status = 'deleted' THEN
latest_build.started_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.completed_at IS NOT NULL AND
latest_build.updated_at - INTERVAL '30 seconds' < NOW() AND
latest_build.transition = 'delete'::workspace_transition
WHEN @status = 'deleting' THEN
latest_build.completed_at IS NOT NULL AND
latest_build.canceled_at IS NULL AND
latest_build.error IS NULL AND
latest_build.transition = 'delete'::workspace_transition
ELSE
true
END
ELSE true
END
-- Filter by owner_id
AND CASE
WHEN @owner_id :: uuid != '00000000-00000000-00000000-00000000' THEN
owner_id = @owner_id
ELSE true
END
-- Filter by owner_name
AND CASE
WHEN @owner_username :: text != '' THEN
owner_id = (SELECT id FROM users WHERE lower(username) = lower(@owner_username) AND deleted = false)
ELSE true
END
-- Filter by template_name
-- There can be more than 1 template with the same name across organizations.
-- Use the organization filter to restrict to 1 org if needed.
AND CASE
WHEN @template_name :: text != '' THEN
template_id = ANY(SELECT id FROM templates WHERE lower(name) = lower(@template_name) AND deleted = false)
ELSE true
END
-- Filter by template_ids
AND CASE
WHEN array_length(@template_ids :: uuid[], 1) > 0 THEN
template_id = ANY(@template_ids)
ELSE true
END
-- Filter by name, matching on substring
AND CASE
WHEN @name :: text != '' THEN
name ILIKE '%' || @name || '%'
ELSE true
END
-- Authorize Filter clause will be injected below in GetAuthorizedWorkspaceCount
-- @authorize_filter
;
-- name: GetWorkspaceByOwnerIDAndName :one
SELECT
*
FROM
workspaces
WHERE
owner_id = @owner_id
AND deleted = @deleted
AND LOWER("name") = LOWER(@name)
ORDER BY created_at DESC;
-- name: GetWorkspaceOwnerCountsByTemplateIDs :many
SELECT
template_id,
COUNT(DISTINCT owner_id)
FROM
workspaces
WHERE
template_id = ANY(@ids :: uuid [ ])
-- Ignore deleted workspaces
AND deleted != true
GROUP BY
template_id;
-- name: GetWorkspaceCountByUserID :one
SELECT
COUNT(id)
FROM
workspaces
WHERE
owner_id = @owner_id
-- Ignore deleted workspaces
AND deleted != true;
-- name: InsertWorkspace :one
INSERT INTO
workspaces (
id,
created_at,
updated_at,
owner_id,
organization_id,
template_id,
name,
autostart_schedule,
ttl
)
VALUES
($1, $2, $3, $4, $5, $6, $7, $8, $9) RETURNING *;
-- name: UpdateWorkspaceDeletedByID :exec
UPDATE
workspaces
SET
deleted = $2
WHERE
id = $1;
-- name: UpdateWorkspace :one
UPDATE
workspaces
SET
name = $2
WHERE
id = $1
AND deleted = false
RETURNING *;
-- name: UpdateWorkspaceAutostart :exec
UPDATE
workspaces
SET
autostart_schedule = $2
WHERE
id = $1;
-- name: UpdateWorkspaceTTL :exec
UPDATE
workspaces
SET
ttl = $2
WHERE
id = $1;
-- name: UpdateWorkspaceLastUsedAt :exec
UPDATE
workspaces
SET
last_used_at = $2
WHERE
id = $1;