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:
Torsten Schulz (local)
2025-11-06 16:03:42 +01:00
parent 98637eec00
commit 5a4553a8a0
2 changed files with 146 additions and 0 deletions

View 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`) != '';

View File

@@ -0,0 +1,89 @@
import { DataTypes } from 'sequelize';
import sequelize from '../database.js';
import Member from './Member.js';
import { encryptData, decryptData } from '../utils/encrypt.js';
const MemberContact = sequelize.define('MemberContact', {
id: {
type: DataTypes.INTEGER,
primaryKey: true,
autoIncrement: true,
allowNull: false
},
memberId: {
type: DataTypes.INTEGER,
allowNull: false,
references: {
model: 'member',
key: 'id'
},
onDelete: 'CASCADE',
field: 'member_id'
},
type: {
type: DataTypes.ENUM('phone', 'email'),
allowNull: false,
comment: 'Type of contact: phone or email'
},
value: {
type: DataTypes.STRING,
allowNull: false,
set(value) {
const encryptedValue = encryptData(value);
this.setDataValue('value', encryptedValue);
},
get() {
const encryptedValue = this.getDataValue('value');
if (!encryptedValue) return null;
try {
return decryptData(encryptedValue);
} catch (error) {
console.error('[MemberContact] Error decrypting value:', error);
return encryptedValue; // Fallback: return encrypted value if decryption fails
}
}
},
isParent: {
type: DataTypes.BOOLEAN,
allowNull: false,
defaultValue: false,
field: 'is_parent',
comment: 'Whether this contact belongs to a parent'
},
parentName: {
type: DataTypes.STRING,
allowNull: true,
set(value) {
if (value) {
const encryptedValue = encryptData(value);
this.setDataValue('parentName', encryptedValue);
} else {
this.setDataValue('parentName', null);
}
},
get() {
const encryptedValue = this.getDataValue('parentName');
return encryptedValue ? decryptData(encryptedValue) : null;
},
field: 'parent_name',
comment: 'Name of the parent (e.g. "Mutter", "Vater", "Elternteil 1")'
},
isPrimary: {
type: DataTypes.BOOLEAN,
allowNull: false,
defaultValue: false,
field: 'is_primary',
comment: 'Whether this is the primary contact of this type'
}
}, {
underscored: true,
sequelize,
modelName: 'MemberContact',
tableName: 'member_contact',
timestamps: true
});
// Associations are defined in models/index.js to avoid duplicate alias errors
export default MemberContact;