From 0aa51115780cc296d9ac2d0944cf9c5409786492 Mon Sep 17 00:00:00 2001 From: =?UTF-8?q?Claus-Peter=20H=C3=BCbner?= Date: Tue, 2 Aug 2022 02:34:16 +0200 Subject: [PATCH] switch 0044 to 0045 Migration --- .../User.ts | 0 .../UserContact.ts | 0 database/entity/User.ts | 2 +- database/entity/UserContact.ts | 2 +- .../0044-adapt_users_table_for_gradidoid.ts | 42 --------- .../0045-adapt_users_table_for_gradidoid.ts | 90 +++++++++++++++++++ .../UC_Introduction_of_Gradido-ID.md | 33 ++++--- 7 files changed, 115 insertions(+), 54 deletions(-) rename database/entity/{0044-adapt_users_table_for_gradidoid => 0045-adapt_users_table_for_gradidoid}/User.ts (100%) rename database/entity/{0044-adapt_users_table_for_gradidoid => 0045-adapt_users_table_for_gradidoid}/UserContact.ts (100%) delete mode 100644 database/migrations/0044-adapt_users_table_for_gradidoid.ts create mode 100644 database/migrations/0045-adapt_users_table_for_gradidoid.ts diff --git a/database/entity/0044-adapt_users_table_for_gradidoid/User.ts b/database/entity/0045-adapt_users_table_for_gradidoid/User.ts similarity index 100% rename from database/entity/0044-adapt_users_table_for_gradidoid/User.ts rename to database/entity/0045-adapt_users_table_for_gradidoid/User.ts diff --git a/database/entity/0044-adapt_users_table_for_gradidoid/UserContact.ts b/database/entity/0045-adapt_users_table_for_gradidoid/UserContact.ts similarity index 100% rename from database/entity/0044-adapt_users_table_for_gradidoid/UserContact.ts rename to database/entity/0045-adapt_users_table_for_gradidoid/UserContact.ts diff --git a/database/entity/User.ts b/database/entity/User.ts index a29e87cd7..89b5d3d7f 100644 --- a/database/entity/User.ts +++ b/database/entity/User.ts @@ -1 +1 @@ -export { User } from './0044-adapt_users_table_for_gradidoid/User' +export { User } from './0045-adapt_users_table_for_gradidoid/User' diff --git a/database/entity/UserContact.ts b/database/entity/UserContact.ts index dce775516..ac47fac24 100644 --- a/database/entity/UserContact.ts +++ b/database/entity/UserContact.ts @@ -1 +1 @@ -export { UserContact } from './0044-adapt_users_table_for_gradidoid/UserContact' +export { UserContact } from './0045-adapt_users_table_for_gradidoid/UserContact' diff --git a/database/migrations/0044-adapt_users_table_for_gradidoid.ts b/database/migrations/0044-adapt_users_table_for_gradidoid.ts deleted file mode 100644 index 7b9cdbc94..000000000 --- a/database/migrations/0044-adapt_users_table_for_gradidoid.ts +++ /dev/null @@ -1,42 +0,0 @@ -/* MIGRATION TO ADD GRADIDO_ID - * - * This migration adds new columns to the table `users` and creates the - * new table `user_contacts` - */ - -/* eslint-disable @typescript-eslint/explicit-module-boundary-types */ -/* eslint-disable @typescript-eslint/no-explicit-any */ - -export async function upgrade(queryFn: (query: string, values?: any[]) => Promise>) { - await queryFn(` - CREATE TABLE IF NOT EXISTS \`user_contacts\` ( - \`id\` int(10) unsigned NOT NULL AUTO_INCREMENT, - \`type\` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, - \`user_id\` int(10) unsigned NOT NULL, - \`email\` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL UNIQUE, - \`email_hash\` binary(32) NULL, - \`email_checked\` tinyint(4) NOT NULL DEFAULT 0, - \`phone\` varchar(255) COLLATE utf8mb4_unicode_ci NULL DEFAULT NULL, - \`created_at\` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP, - \`updated_at\` datetime NULL DEFAULT NULL, - \`deleted_at\` datetime NULL DEFAULT NULL, - PRIMARY KEY (\`id\`) - ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;`) - - await queryFn( - 'ALTER TABLE `users` ADD COLUMN `gradido_id` varchar(36) NOT NULL UNIQUE DEFAULT UUID() AFTER `id`;', - ) - await queryFn( - 'ALTER TABLE `users` ADD COLUMN `alias` varchar(20) NULL UNIQUE AFTER `gradido_id`;', - ) - await queryFn('ALTER TABLE `users` ADD COLUMN `email_id` int(10) NULL AFTER `email`;') -} - -export async function downgrade(queryFn: (query: string, values?: any[]) => Promise>) { - // write downgrade logic as parameter of queryFn - await queryFn(`DROP TABLE IF EXISTS \`user_contacts\`;`) - - await queryFn('ALTER TABLE `users` DROP COLUMN `gradido_id`;') - await queryFn('ALTER TABLE `users` DROP COLUMN `alias`;') - await queryFn('ALTER TABLE `users` DROP COLUMN `email_id`;') -} diff --git a/database/migrations/0045-adapt_users_table_for_gradidoid.ts b/database/migrations/0045-adapt_users_table_for_gradidoid.ts new file mode 100644 index 000000000..65c2d4b97 --- /dev/null +++ b/database/migrations/0045-adapt_users_table_for_gradidoid.ts @@ -0,0 +1,90 @@ +/* MIGRATION TO ADD GRADIDO_ID + * + * This migration adds new columns to the table `users` and creates the + * new table `user_contacts` + */ + +/* eslint-disable @typescript-eslint/explicit-module-boundary-types */ +/* eslint-disable @typescript-eslint/no-explicit-any */ + +export async function upgrade(queryFn: (query: string, values?: any[]) => Promise>) { + await queryFn(` + CREATE FUNCTION UuidToBin(_uuid BINARY(36)) + RETURNS BINARY(16) + LANGUAGE SQL DETERMINISTIC CONTAINS SQL SQL SECURITY INVOKER + RETURN + UNHEX(CONCAT( + SUBSTR(_uuid, 15, 4), + SUBSTR(_uuid, 10, 4), + SUBSTR(_uuid, 1, 8), + SUBSTR(_uuid, 20, 4), + SUBSTR(_uuid, 25) ));`) + + await queryFn(` + CREATE FUNCTION UuidFromBin(_bin BINARY(16)) + RETURNS BINARY(36) + LANGUAGE SQL DETERMINISTIC CONTAINS SQL SQL SECURITY INVOKER + RETURN + LCASE(CONCAT_WS('-', + HEX(SUBSTR(_bin, 5, 4)), + HEX(SUBSTR(_bin, 3, 2)), + HEX(SUBSTR(_bin, 1, 2)), + HEX(SUBSTR(_bin, 9, 2)), + HEX(SUBSTR(_bin, 11)) + ));`) + + await queryFn(` + CREATE TABLE IF NOT EXISTS \`user_contacts\` ( + \`id\` int(10) unsigned NOT NULL AUTO_INCREMENT, + \`type\` varchar(100) COLLATE utf8mb4_unicode_ci NOT NULL, + \`user_id\` int(10) unsigned NOT NULL, + \`email\` varchar(255) COLLATE utf8mb4_unicode_ci NOT NULL, + \`email_verification_code\` bigint(20) unsigned NOT NULL, + \`email_opt_in_type_id\` int NOT NULL, + \`email_resend_count\` int DEFAULT '0', + \`email_checked\` tinyint(4) NOT NULL DEFAULT 0, + \`phone\` varchar(255) COLLATE utf8mb4_unicode_ci NULL DEFAULT NULL, + \`created_at\` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP, + \`updated_at\` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, + \`deleted_at\` datetime NULL DEFAULT NULL, + PRIMARY KEY (\`id\`), + UNIQUE KEY \`email_verification_code\` (\`email_verification_code\`), + UNIQUE KEY \`email\` (\`email\`) + ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4;`) + + await queryFn( + 'ALTER TABLE `users` ADD COLUMN `gradido_id` BINARY(16) NOT NULL UNIQUE DEFAULT UuidToBin(UUID()) AFTER `id`;', + ) + await queryFn( + 'ALTER TABLE `users` ADD COLUMN `alias` varchar(20) NULL UNIQUE AFTER `gradido_id`;', + ) + await queryFn('ALTER TABLE `users` ADD COLUMN `email_id` int(10) NULL AFTER `email`;') + await queryFn(` + INSERT INTO gradido_community.user_contacts + (type, user_id, email, email_verification_code, email_opt_in_type_id, email_resent_count, email_checked, created_at, updated_at, deleted_at) + SELECT + 'EMAIL' as type, + u.id as user_id, + u.email, + e.verification_code, + e.email_opt_in_type_id, + e.resend_count, + u.email_checked, + e.created, + e.updated, + u.deletedAt + FROM + gradido_community.users as u, + gradido_community.login_email_opt_in as e + WHERE + u.id = e.user_id;`) +} + +export async function downgrade(queryFn: (query: string, values?: any[]) => Promise>) { + // write downgrade logic as parameter of queryFn + await queryFn(`DROP TABLE IF EXISTS \`user_contacts\`;`) + + await queryFn('ALTER TABLE `users` DROP COLUMN `gradido_id`;') + await queryFn('ALTER TABLE `users` DROP COLUMN `alias`;') + await queryFn('ALTER TABLE `users` DROP COLUMN `email_id`;') +} diff --git a/docu/Concepts/TechnicalRequirements/UC_Introduction_of_Gradido-ID.md b/docu/Concepts/TechnicalRequirements/UC_Introduction_of_Gradido-ID.md index 5da969eac..c8eb12524 100644 --- a/docu/Concepts/TechnicalRequirements/UC_Introduction_of_Gradido-ID.md +++ b/docu/Concepts/TechnicalRequirements/UC_Introduction_of_Gradido-ID.md @@ -39,14 +39,21 @@ The preferred and proper solution will be to add a new column `Users.emailId `as A new entity `UserContacts `is introduced to store several contacts of different types like email, telephone or other kinds of contact addresses. -| Column | Type | Description | -| --------------- | ------ | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------- | -| id | int | the technical key of a contact entity | -| type | int | Defines the type of contact entry as enum: Email, Phone, etc | -| usersID | int | Defines the foreign key to the `Users` table | -| email | String | defines the address of a contact entry of type Email | -| phone | String | defines the address of a contact entry of type Phone | -| contactChannels | String | define the contact channel as comma separated list for which this entry is confirmed by the user e.g. main contact (default), infomail, contracting, advertisings, ... | +| Column | Type | Description | +| --------------------- | ------------------- | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------- | +| id | int | the technical key of a contact entity | +| type | int | Defines the type of contact entry as enum: Email, Phone, etc | +| userID | int | Defines the foreign key to the `Users` table | +| email | String | defines the address of a contact entry of type Email | +| emailVerificationCode | unsinged bigint(20) | unique code to verify email or password reset | +| emailOptInType | int | REGISTER=1, RESET_PASSWORD=2 | +| emailResendCount | int | counter how often the email was resend | +| emailChecked | boolean | flag if email is verified and confirmed | +| createdAt | DateTime | point of time the Contact was created | +| updatedAt | DateTime | point of time the Contact was updated | +| deletedAt | DateTime | point of time the Contact was soft deleted | +| phone | String | defines the address of a contact entry of type Phone | +| contactChannels | String | define the contact channel as comma separated list for which this entry is confirmed by the user e.g. main contact (default), infomail, contracting, advertisings, ... | ### Database-Migration @@ -58,18 +65,24 @@ In a one-time migration create for each entry of the `Users `tabel an unique UUI #### Primary Email Contact -In a one-time migration read for each entry of the `Users `table the `Users.id` and `Users.email` and create for it a new entry in the `UsersContact `table, by initializing the contact-values with: +In a one-time migration read for each entry of the `Users `table the `Users.id` and `Users.email`, select from the table `login_email_opt_in` the entry with the `login_email_opt_in.user_id` = `Users.id` and create a new entry in the `UsersContact `table, by initializing the contact-values with: * id = new technical key * type = Enum-Email * userID = `Users.id` * email = `Users.email` +* emailVerifyCode = `login_email_opt_in.verification_code` +* emailOptInType = `login_email_opt_in.email_opt_in_type_id` +* emailResendCount = `login_email_opt_in.resent_count` +* emailChecked = `Users.emailChecked` +* createdAt = `login_email_opt_in.created_at` +* updatedAt = `login_email_opt_in.updated_at` * phone = null * usedChannel = Enum-"main contact" and update the `Users `entry with `Users.emailId = UsersContact.Id` and `Users.passphraseEncryptionType = 1` -After this one-time migration the column `Users.email` can be deleted. +After this one-time migration and a verification, which ensures that all data are migrated, then the columns `Users.email`, `Users.emailChecked`, `Users.emailHash` and the table `login_email_opt_in` can be deleted. ### Adaption of BusinessLogic