Re_Backend/src/migrations/2025110501-alter-tat-days-to-generated.ts

77 lines
2.3 KiB
TypeScript

import { QueryInterface } from 'sequelize';
/**
* Migration: Convert tat_days to GENERATED STORED column
*
* This ensures tat_days is auto-calculated from tat_hours across all environments.
* Production already has this as a generated column, this migration makes other environments consistent.
*/
export async function up(queryInterface: QueryInterface): Promise<void> {
// Check if tat_days is already a generated column
const result = await queryInterface.sequelize.query(`
SELECT
a.attname as column_name,
a.attgenerated as is_generated
FROM pg_attribute a
JOIN pg_class c ON a.attrelid = c.oid
WHERE c.relname = 'approval_levels'
AND a.attname = 'tat_days'
AND NOT a.attisdropped;
`, { type: 'SELECT' });
const column = result[0] as any;
if (column && column.is_generated === 's') {
// Already a GENERATED column, skipping
return;
}
// Converting tat_days to GENERATED column
// Step 1: Drop the existing regular column
await queryInterface.sequelize.query(`
ALTER TABLE approval_levels DROP COLUMN IF EXISTS tat_days;
`);
// Step 2: Add it back as a GENERATED STORED column
// Formula: CEIL(tat_hours / 24.0) - rounds up to nearest day
await queryInterface.sequelize.query(`
ALTER TABLE approval_levels
ADD COLUMN tat_days INTEGER
GENERATED ALWAYS AS (CAST(CEIL(tat_hours / 24.0) AS INTEGER)) STORED;
`);
// tat_days is now auto-calculated
}
export async function down(queryInterface: QueryInterface): Promise<void> {
// Rolling back to regular column
// Drop the generated column
await queryInterface.sequelize.query(`
ALTER TABLE approval_levels DROP COLUMN IF EXISTS tat_days;
`);
// Add it back as a regular column (with default calculation for existing rows)
await queryInterface.sequelize.query(`
ALTER TABLE approval_levels
ADD COLUMN tat_days INTEGER;
`);
// Populate existing rows with calculated values
await queryInterface.sequelize.query(`
UPDATE approval_levels
SET tat_days = CAST(CEIL(tat_hours / 24.0) AS INTEGER)
WHERE tat_days IS NULL;
`);
// Make it NOT NULL after populating
await queryInterface.sequelize.query(`
ALTER TABLE approval_levels
ALTER COLUMN tat_days SET NOT NULL;
`);
// Rolled back successfully
}