mirror of
https://github.com/coder/coder.git
synced 2025-07-06 15:41:45 +00:00
feat: add support for optional external auth providers (#12021)
This commit is contained in:
committed by
GitHub
parent
78c9f82719
commit
475c3650ca
@ -0,0 +1,61 @@
|
||||
-- We cannot alter the column type while a view depends on it, so we drop it and recreate it.
|
||||
DROP VIEW template_version_with_user;
|
||||
|
||||
|
||||
-- Does the opposite of `migrate_external_auth_providers_to_jsonb`
|
||||
-- eg. `'[{"id": "github"}, {"id": "gitlab"}]'::jsonb` would become `'{github,gitlab}'::text[]`
|
||||
CREATE OR REPLACE FUNCTION revert_migrate_external_auth_providers_to_jsonb(jsonb)
|
||||
RETURNS text[]
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
result text[];
|
||||
BEGIN
|
||||
SELECT
|
||||
array_agg(id::text) INTO result
|
||||
FROM (
|
||||
SELECT
|
||||
jsonb_array_elements($1) ->> 'id' AS id) AS external_auth_provider_ids;
|
||||
RETURN result;
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
||||
-- Remove the non-null constraint and default
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers DROP DEFAULT;
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers DROP NOT NULL;
|
||||
|
||||
|
||||
-- Update the column type and migrate the values
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers TYPE text[]
|
||||
USING revert_migrate_external_auth_providers_to_jsonb(external_auth_providers);
|
||||
|
||||
|
||||
-- Recreate `template_version_with_user` as described in dump.sql
|
||||
CREATE VIEW template_version_with_user AS
|
||||
SELECT
|
||||
template_versions.id,
|
||||
template_versions.template_id,
|
||||
template_versions.organization_id,
|
||||
template_versions.created_at,
|
||||
template_versions.updated_at,
|
||||
template_versions.name,
|
||||
template_versions.readme,
|
||||
template_versions.job_id,
|
||||
template_versions.created_by,
|
||||
template_versions.external_auth_providers,
|
||||
template_versions.message,
|
||||
template_versions.archived,
|
||||
COALESCE(visible_users.avatar_url, ''::text) AS created_by_avatar_url,
|
||||
COALESCE(visible_users.username, ''::text) AS created_by_username
|
||||
FROM (public.template_versions
|
||||
LEFT JOIN visible_users ON (template_versions.created_by = visible_users.id));
|
||||
|
||||
COMMENT ON VIEW template_version_with_user IS 'Joins in the username + avatar url of the created by user.';
|
||||
|
||||
|
||||
-- Cleanup
|
||||
DROP FUNCTION revert_migrate_external_auth_providers_to_jsonb;
|
@ -0,0 +1,63 @@
|
||||
-- We cannot alter the column type while a view depends on it, so we drop it and recreate it.
|
||||
DROP VIEW template_version_with_user;
|
||||
|
||||
|
||||
-- Turns the list of provider names into JSONB with the type `Array<{ id: string; optional?: boolean }>`
|
||||
-- eg. `'{github,gitlab}'::text[]` would become `'[{"id": "github"}, {"id": "gitlab"}]'::jsonb`
|
||||
CREATE OR REPLACE FUNCTION migrate_external_auth_providers_to_jsonb(text[])
|
||||
RETURNS jsonb
|
||||
LANGUAGE plpgsql
|
||||
AS $$
|
||||
DECLARE
|
||||
result jsonb;
|
||||
BEGIN
|
||||
SELECT
|
||||
jsonb_agg(jsonb_build_object('id', value::text)) INTO result
|
||||
FROM
|
||||
unnest($1) AS value;
|
||||
RETURN result;
|
||||
END;
|
||||
$$;
|
||||
|
||||
|
||||
-- Update the column type and migrate the values
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers TYPE jsonb
|
||||
USING migrate_external_auth_providers_to_jsonb(external_auth_providers);
|
||||
|
||||
|
||||
-- Make the column non-nullable to make the types nicer on the Go side
|
||||
UPDATE template_versions
|
||||
SET external_auth_providers = '[]'::jsonb
|
||||
WHERE external_auth_providers IS NULL;
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers SET DEFAULT '[]'::jsonb;
|
||||
ALTER TABLE template_versions
|
||||
ALTER COLUMN external_auth_providers SET NOT NULL;
|
||||
|
||||
|
||||
-- Recreate `template_version_with_user` as described in dump.sql
|
||||
CREATE VIEW template_version_with_user AS
|
||||
SELECT
|
||||
template_versions.id,
|
||||
template_versions.template_id,
|
||||
template_versions.organization_id,
|
||||
template_versions.created_at,
|
||||
template_versions.updated_at,
|
||||
template_versions.name,
|
||||
template_versions.readme,
|
||||
template_versions.job_id,
|
||||
template_versions.created_by,
|
||||
template_versions.external_auth_providers,
|
||||
template_versions.message,
|
||||
template_versions.archived,
|
||||
COALESCE(visible_users.avatar_url, ''::text) AS created_by_avatar_url,
|
||||
COALESCE(visible_users.username, ''::text) AS created_by_username
|
||||
FROM (public.template_versions
|
||||
LEFT JOIN visible_users ON (template_versions.created_by = visible_users.id));
|
||||
|
||||
COMMENT ON VIEW template_version_with_user IS 'Joins in the username + avatar url of the created by user.';
|
||||
|
||||
|
||||
-- Cleanup
|
||||
DROP FUNCTION migrate_external_auth_providers_to_jsonb;
|
Reference in New Issue
Block a user