diff --git a/coderd/database/dump.sql b/coderd/database/dump.sql index 55872db31d..830f8a1825 100644 --- a/coderd/database/dump.sql +++ b/coderd/database/dump.sql @@ -1644,6 +1644,8 @@ COMMENT ON INDEX template_usage_stats_start_time_template_id_user_id_idx IS 'Ind CREATE UNIQUE INDEX templates_organization_id_name_idx ON templates USING btree (organization_id, lower((name)::text)) WHERE (deleted = false); +CREATE UNIQUE INDEX user_links_linked_id_login_type_idx ON user_links USING btree (linked_id, login_type) WHERE (linked_id <> ''::text); + CREATE UNIQUE INDEX users_email_lower_idx ON users USING btree (lower(email)) WHERE (deleted = false); CREATE UNIQUE INDEX users_username_lower_idx ON users USING btree (lower(username)) WHERE (deleted = false); diff --git a/coderd/database/migrations/000205_unique_linked_id.down.sql b/coderd/database/migrations/000205_unique_linked_id.down.sql new file mode 100644 index 0000000000..81e7d14fc1 --- /dev/null +++ b/coderd/database/migrations/000205_unique_linked_id.down.sql @@ -0,0 +1 @@ +DROP INDEX user_links_linked_id_login_type_idx; diff --git a/coderd/database/migrations/000205_unique_linked_id.up.sql b/coderd/database/migrations/000205_unique_linked_id.up.sql new file mode 100644 index 0000000000..da3ff6126a --- /dev/null +++ b/coderd/database/migrations/000205_unique_linked_id.up.sql @@ -0,0 +1,21 @@ +-- Remove the linked_id if two user_links share the same value. +-- This will affect the user if they attempt to change their settings on +-- the oauth/oidc provider. However, if two users exist with the same +-- linked_value, there is no way to determine correctly which user should +-- be updated. Since the linked_id is empty, this value will be linked +-- by email. +UPDATE ONLY user_links AS out +SET + linked_id = + CASE WHEN ( + -- When the count of linked_id is greater than 1, set the linked_id to empty + SELECT + COUNT(*) + FROM + user_links inn + WHERE + out.linked_id = inn.linked_id AND out.login_type = inn.login_type + ) > 1 THEN '' ELSE out.linked_id END; + +-- Enforce unique linked_id constraint on non-empty linked_id +CREATE UNIQUE INDEX user_links_linked_id_login_type_idx ON user_links USING btree (linked_id, login_type) WHERE (linked_id != ''); diff --git a/coderd/database/migrations/testdata/fixtures/000048_userdelete.up.sql b/coderd/database/migrations/testdata/fixtures/000048_userdelete.up.sql index 0fb1d0efd4..c4f8b2e909 100644 --- a/coderd/database/migrations/testdata/fixtures/000048_userdelete.up.sql +++ b/coderd/database/migrations/testdata/fixtures/000048_userdelete.up.sql @@ -17,3 +17,18 @@ INSERT INTO public.user_links(user_id, login_type, linked_id, oauth_access_token -- This has happened on a production database. INSERT INTO public.user_links(user_id, login_type, linked_id, oauth_access_token) VALUES('fc1511ef-4fcf-4a3b-98a1-8df64160e35a', 'oidc', 'foo', ''); + + +-- Lastly, make 2 other users who have the same user link. +INSERT INTO public.users(id, email, username, hashed_password, created_at, updated_at, status, rbac_roles, deleted) +VALUES ('580ed397-727d-4aaf-950a-51f89f556c24', 'dup_link_a@coder.com', 'dupe_a', '\x', '2022-11-02 13:05:21.445455+02', '2022-11-02 13:05:21.445455+02', 'active', '{}', false) ON CONFLICT DO NOTHING; +INSERT INTO public.organization_members VALUES ('580ed397-727d-4aaf-950a-51f89f556c24', 'bb640d07-ca8a-4869-b6bc-ae61ebb2fda1', '2022-11-02 13:05:21.447595+02', '2022-11-02 13:05:21.447595+02', '{}') ON CONFLICT DO NOTHING; +INSERT INTO public.user_links(user_id, login_type, linked_id, oauth_access_token) +VALUES('580ed397-727d-4aaf-950a-51f89f556c24', 'github', '500', ''); + + +INSERT INTO public.users(id, email, username, hashed_password, created_at, updated_at, status, rbac_roles, deleted) +VALUES ('c813366b-2fde-45ae-920c-101c3ad6a1e1', 'dup_link_b@coder.com', 'dupe_b', '\x', '2022-11-02 13:05:21.445455+02', '2022-11-02 13:05:21.445455+02', 'active', '{}', false) ON CONFLICT DO NOTHING; +INSERT INTO public.organization_members VALUES ('c813366b-2fde-45ae-920c-101c3ad6a1e1', 'bb640d07-ca8a-4869-b6bc-ae61ebb2fda1', '2022-11-02 13:05:21.447595+02', '2022-11-02 13:05:21.447595+02', '{}') ON CONFLICT DO NOTHING; +INSERT INTO public.user_links(user_id, login_type, linked_id, oauth_access_token) +VALUES('c813366b-2fde-45ae-920c-101c3ad6a1e1', 'github', '500', ''); diff --git a/coderd/database/unique_constraint.go b/coderd/database/unique_constraint.go index 52de0a50f6..9db8af72c8 100644 --- a/coderd/database/unique_constraint.go +++ b/coderd/database/unique_constraint.go @@ -82,6 +82,7 @@ const ( UniqueOrganizationsSingleDefaultOrg UniqueConstraint = "organizations_single_default_org" // CREATE UNIQUE INDEX organizations_single_default_org ON organizations USING btree (is_default) WHERE (is_default = true); UniqueTemplateUsageStatsStartTimeTemplateIDUserIDIndex UniqueConstraint = "template_usage_stats_start_time_template_id_user_id_idx" // CREATE UNIQUE INDEX template_usage_stats_start_time_template_id_user_id_idx ON template_usage_stats USING btree (start_time, template_id, user_id); UniqueTemplatesOrganizationIDNameIndex UniqueConstraint = "templates_organization_id_name_idx" // CREATE UNIQUE INDEX templates_organization_id_name_idx ON templates USING btree (organization_id, lower((name)::text)) WHERE (deleted = false); + UniqueUserLinksLinkedIDLoginTypeIndex UniqueConstraint = "user_links_linked_id_login_type_idx" // CREATE UNIQUE INDEX user_links_linked_id_login_type_idx ON user_links USING btree (linked_id, login_type) WHERE (linked_id <> ''::text); UniqueUsersEmailLowerIndex UniqueConstraint = "users_email_lower_idx" // CREATE UNIQUE INDEX users_email_lower_idx ON users USING btree (lower(email)) WHERE (deleted = false); UniqueUsersUsernameLowerIndex UniqueConstraint = "users_username_lower_idx" // CREATE UNIQUE INDEX users_username_lower_idx ON users USING btree (lower(username)) WHERE (deleted = false); UniqueWorkspaceProxiesLowerNameIndex UniqueConstraint = "workspace_proxies_lower_name_idx" // CREATE UNIQUE INDEX workspace_proxies_lower_name_idx ON workspace_proxies USING btree (lower(name)) WHERE (deleted = false);