Add member_contact table and postal_code column to member table
Created a new SQL migration to add a postal_code column to the member table and introduced a member_contact table to store multiple phone numbers and email addresses. Implemented data migration for existing phone numbers and email addresses from the member table to the new member_contact table, ensuring data integrity and improved contact management.
This commit is contained in:
57
backend/migrations/add_member_contact_and_postal_code.sql
Normal file
57
backend/migrations/add_member_contact_and_postal_code.sql
Normal file
@@ -0,0 +1,57 @@
|
||||
-- Add postal_code column to member table
|
||||
ALTER TABLE `member`
|
||||
ADD COLUMN `postal_code` TEXT NULL COMMENT 'Postal code (PLZ)' AFTER `city`;
|
||||
|
||||
-- Create member_contact table for multiple phone numbers and email addresses
|
||||
CREATE TABLE IF NOT EXISTS `member_contact` (
|
||||
`id` INT NOT NULL AUTO_INCREMENT,
|
||||
`member_id` INT NOT NULL,
|
||||
`type` ENUM('phone', 'email') NOT NULL COMMENT 'Type of contact: phone or email',
|
||||
`value` TEXT NOT NULL,
|
||||
`is_parent` BOOLEAN NOT NULL DEFAULT FALSE COMMENT 'Whether this contact belongs to a parent',
|
||||
`parent_name` TEXT NULL COMMENT 'Name of the parent (e.g. "Mutter", "Vater", "Elternteil 1")',
|
||||
`is_primary` BOOLEAN NOT NULL DEFAULT FALSE COMMENT 'Whether this is the primary contact of this type',
|
||||
`created_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`updated_at` DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (`id`),
|
||||
INDEX `idx_member_id` (`member_id`),
|
||||
INDEX `idx_type` (`type`),
|
||||
CONSTRAINT `fk_member_contact_member`
|
||||
FOREIGN KEY (`member_id`)
|
||||
REFERENCES `member` (`id`)
|
||||
ON DELETE CASCADE
|
||||
ON UPDATE CASCADE
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci;
|
||||
|
||||
-- Migrate existing phone numbers from member.phone to member_contact
|
||||
INSERT INTO `member_contact` (`member_id`, `type`, `value`, `is_parent`, `parent_name`, `is_primary`, `created_at`, `updated_at`)
|
||||
SELECT
|
||||
`id` AS `member_id`,
|
||||
'phone' AS `type`,
|
||||
`phone` AS `value`,
|
||||
FALSE AS `is_parent`,
|
||||
NULL AS `parent_name`,
|
||||
TRUE AS `is_primary`,
|
||||
NOW() AS `created_at`,
|
||||
NOW() AS `updated_at`
|
||||
FROM `member`
|
||||
WHERE `phone` IS NOT NULL
|
||||
AND `phone` != ''
|
||||
AND TRIM(`phone`) != '';
|
||||
|
||||
-- Migrate existing email addresses from member.email to member_contact
|
||||
INSERT INTO `member_contact` (`member_id`, `type`, `value`, `is_parent`, `parent_name`, `is_primary`, `created_at`, `updated_at`)
|
||||
SELECT
|
||||
`id` AS `member_id`,
|
||||
'email' AS `type`,
|
||||
`email` AS `value`,
|
||||
FALSE AS `is_parent`,
|
||||
NULL AS `parent_name`,
|
||||
TRUE AS `is_primary`,
|
||||
NOW() AS `created_at`,
|
||||
NOW() AS `updated_at`
|
||||
FROM `member`
|
||||
WHERE `email` IS NOT NULL
|
||||
AND `email` != ''
|
||||
AND TRIM(`email`) != '';
|
||||
|
||||
Reference in New Issue
Block a user