Files
coder/coderd/database/queries/organizationmembers.sql
Danny Kopping 4c33846f6d chore: add prebuilds system user (#16916)
Pre-requisite for https://github.com/coder/coder/pull/16891

Closes https://github.com/coder/internal/issues/515

This PR introduces a new concept of a "system" user.

Our data model requires that all workspaces have an owner (a `users`
relation), and prebuilds is a feature that will spin up workspaces to be
claimed later by actual users - and thus needs to own the workspaces in
the interim.

Naturally, introducing a change like this touches a few aspects around
the codebase and we've taken the approach _default hidden_ here; in
other words, queries for users will by default _exclude_ all system
users, but there is a flag to ensure they can be displayed. This keeps
the changeset relatively small.

This user has minimal permissions (it's equivalent to a `member` since
it has no roles). It will be associated with the default org in the
initial migration, and thereafter we'll need to somehow ensure its
membership aligns with templates (which are org-scoped) for which it'll
need to provision prebuilds; that's a solution we'll have in a
subsequent PR.

---------

Signed-off-by: Danny Kopping <dannykopping@gmail.com>
Co-authored-by: Sas Swart <sas.swart.cdk@gmail.com>
2025-03-25 12:18:06 +00:00

98 lines
2.4 KiB
SQL

-- name: OrganizationMembers :many
-- Arguments are optional with uuid.Nil to ignore.
-- - Use just 'organization_id' to get all members of an org
-- - Use just 'user_id' to get all orgs a user is a member of
-- - Use both to get a specific org member row
SELECT
sqlc.embed(organization_members),
users.username, users.avatar_url, users.name, users.email, users.rbac_roles as "global_roles"
FROM
organization_members
INNER JOIN
users ON organization_members.user_id = users.id AND users.deleted = false
WHERE
-- Filter by organization id
CASE
WHEN @organization_id :: uuid != '00000000-0000-0000-0000-000000000000'::uuid THEN
organization_id = @organization_id
ELSE true
END
-- Filter by user id
AND CASE
WHEN @user_id :: uuid != '00000000-0000-0000-0000-000000000000'::uuid THEN
user_id = @user_id
ELSE true
END
-- Filter by system type
AND CASE
WHEN @include_system::bool THEN TRUE
ELSE
is_system = false
END;
-- name: InsertOrganizationMember :one
INSERT INTO
organization_members (
organization_id,
user_id,
created_at,
updated_at,
roles
)
VALUES
($1, $2, $3, $4, $5) RETURNING *;
-- name: DeleteOrganizationMember :exec
DELETE
FROM
organization_members
WHERE
organization_id = @organization_id AND
user_id = @user_id
;
-- name: GetOrganizationIDsByMemberIDs :many
SELECT
user_id, array_agg(organization_id) :: uuid [ ] AS "organization_IDs"
FROM
organization_members
WHERE
user_id = ANY(@ids :: uuid [ ])
GROUP BY
user_id;
-- name: UpdateMemberRoles :one
UPDATE
organization_members
SET
-- Remove all duplicates from the roles.
roles = ARRAY(SELECT DISTINCT UNNEST(@granted_roles :: text[]))
WHERE
user_id = @user_id
AND organization_id = @org_id
RETURNING *;
-- name: PaginatedOrganizationMembers :many
SELECT
sqlc.embed(organization_members),
users.username, users.avatar_url, users.name, users.email, users.rbac_roles as "global_roles",
COUNT(*) OVER() AS count
FROM
organization_members
INNER JOIN
users ON organization_members.user_id = users.id AND users.deleted = false
WHERE
-- Filter by organization id
CASE
WHEN @organization_id :: uuid != '00000000-0000-0000-0000-000000000000'::uuid THEN
organization_id = @organization_id
ELSE true
END
ORDER BY
-- Deterministic and consistent ordering of all users. This is to ensure consistent pagination.
LOWER(username) ASC OFFSET @offset_opt
LIMIT
-- A null limit means "no limit", so 0 means return all
NULLIF(@limit_opt :: int, 0);