CalejoControl/database/migration_simplified_schema...

221 lines
8.3 KiB
MySQL
Raw Normal View History

-- Calejo Control Simplified Schema Migration
-- Migration from complex ID system to simple signal names + tags
-- Date: November 8, 2025
-- =============================================
-- STEP 1: Create new simplified tables
-- =============================================
-- New simplified protocol_signals table
CREATE TABLE IF NOT EXISTS protocol_signals (
signal_id VARCHAR(100) PRIMARY KEY,
signal_name VARCHAR(200) NOT NULL,
tags TEXT[] NOT NULL DEFAULT '{}',
protocol_type VARCHAR(20) NOT NULL,
protocol_address VARCHAR(500) NOT NULL,
db_source VARCHAR(100) NOT NULL,
-- Signal preprocessing configuration
preprocessing_enabled BOOLEAN DEFAULT FALSE,
preprocessing_rules JSONB,
min_output_value DECIMAL(10, 4),
max_output_value DECIMAL(10, 4),
default_output_value DECIMAL(10, 4),
-- Protocol-specific configurations
modbus_config JSONB,
opcua_config JSONB,
-- Metadata
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW(),
created_by VARCHAR(100),
enabled BOOLEAN DEFAULT TRUE,
-- Constraints
CONSTRAINT valid_protocol_type CHECK (protocol_type IN ('opcua', 'modbus_tcp', 'modbus_rtu', 'rest_api')),
CONSTRAINT signal_name_not_empty CHECK (signal_name <> ''),
CONSTRAINT valid_signal_id CHECK (signal_id ~ '^[a-zA-Z0-9_-]+$')
);
COMMENT ON TABLE protocol_signals IS 'Simplified protocol signals with human-readable names and tags';
COMMENT ON COLUMN protocol_signals.signal_id IS 'Unique identifier for the signal';
COMMENT ON COLUMN protocol_signals.signal_name IS 'Human-readable signal name';
COMMENT ON COLUMN protocol_signals.tags IS 'Array of tags for categorization and filtering';
COMMENT ON COLUMN protocol_signals.protocol_type IS 'Protocol type: opcua, modbus_tcp, modbus_rtu, rest_api';
COMMENT ON COLUMN protocol_signals.protocol_address IS 'Protocol-specific address (OPC UA node ID, Modbus register, REST endpoint)';
COMMENT ON COLUMN protocol_signals.db_source IS 'Database field name that this signal represents';
-- Create indexes for efficient querying
CREATE INDEX idx_protocol_signals_tags ON protocol_signals USING GIN(tags);
CREATE INDEX idx_protocol_signals_protocol_type ON protocol_signals(protocol_type, enabled);
CREATE INDEX idx_protocol_signals_signal_name ON protocol_signals(signal_name);
CREATE INDEX idx_protocol_signals_created_at ON protocol_signals(created_at DESC);
-- =============================================
-- STEP 2: Migration function to convert existing data
-- =============================================
CREATE OR REPLACE FUNCTION migrate_protocol_mappings_to_signals()
RETURNS INTEGER AS $$
DECLARE
migrated_count INTEGER := 0;
mapping_record RECORD;
station_name_text TEXT;
pump_name_text TEXT;
signal_name_text TEXT;
tags_array TEXT[];
signal_id_text TEXT;
BEGIN
-- Loop through existing protocol mappings
FOR mapping_record IN
SELECT
pm.mapping_id,
pm.station_id,
pm.pump_id,
pm.protocol_type,
pm.protocol_address,
pm.data_type,
pm.db_source,
ps.station_name,
p.pump_name
FROM protocol_mappings pm
LEFT JOIN pump_stations ps ON pm.station_id = ps.station_id
LEFT JOIN pumps p ON pm.station_id = p.station_id AND pm.pump_id = p.pump_id
WHERE pm.enabled = TRUE
LOOP
-- Generate human-readable signal name
station_name_text := COALESCE(mapping_record.station_name, 'Unknown Station');
pump_name_text := COALESCE(mapping_record.pump_name, 'Unknown Pump');
signal_name_text := CONCAT(
station_name_text, ' ',
pump_name_text, ' ',
CASE mapping_record.data_type
WHEN 'setpoint' THEN 'Setpoint'
WHEN 'status' THEN 'Status'
WHEN 'control' THEN 'Control'
WHEN 'safety' THEN 'Safety'
WHEN 'alarm' THEN 'Alarm'
WHEN 'configuration' THEN 'Configuration'
ELSE INITCAP(mapping_record.data_type)
END
);
-- Generate tags array
tags_array := ARRAY[
-- Station tags
CASE
WHEN mapping_record.station_id LIKE '%main%' THEN 'station:main'
WHEN mapping_record.station_id LIKE '%backup%' THEN 'station:backup'
WHEN mapping_record.station_id LIKE '%control%' THEN 'station:control'
ELSE 'station:unknown'
END,
-- Equipment tags
CASE
WHEN mapping_record.pump_id LIKE '%primary%' THEN 'equipment:primary_pump'
WHEN mapping_record.pump_id LIKE '%backup%' THEN 'equipment:backup_pump'
WHEN mapping_record.pump_id LIKE '%sensor%' THEN 'equipment:sensor'
WHEN mapping_record.pump_id LIKE '%valve%' THEN 'equipment:valve'
WHEN mapping_record.pump_id LIKE '%controller%' THEN 'equipment:controller'
ELSE 'equipment:unknown'
END,
-- Data type tags
'data_type:' || mapping_record.data_type,
-- Protocol tags
'protocol:' || mapping_record.protocol_type
];
-- Generate signal ID (use existing mapping_id if it follows new pattern, otherwise create new)
IF mapping_record.mapping_id ~ '^[a-zA-Z0-9_-]+$' THEN
signal_id_text := mapping_record.mapping_id;
ELSE
signal_id_text := CONCAT(
REPLACE(LOWER(station_name_text), ' ', '_'), '_',
REPLACE(LOWER(pump_name_text), ' ', '_'), '_',
mapping_record.data_type, '_',
SUBSTRING(mapping_record.mapping_id, 1, 8)
);
END IF;
-- Insert into new table
INSERT INTO protocol_signals (
signal_id, signal_name, tags, protocol_type, protocol_address, db_source
) VALUES (
signal_id_text,
signal_name_text,
tags_array,
mapping_record.protocol_type,
mapping_record.protocol_address,
mapping_record.db_source
);
migrated_count := migrated_count + 1;
END LOOP;
RETURN migrated_count;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- STEP 3: Migration validation function
-- =============================================
CREATE OR REPLACE FUNCTION validate_migration()
RETURNS TABLE(
original_count INTEGER,
migrated_count INTEGER,
validation_status TEXT
) AS $$
BEGIN
-- Count original mappings
SELECT COUNT(*) INTO original_count FROM protocol_mappings WHERE enabled = TRUE;
-- Count migrated signals
SELECT COUNT(*) INTO migrated_count FROM protocol_signals;
-- Determine validation status
IF original_count = migrated_count THEN
validation_status := 'SUCCESS';
ELSIF migrated_count > 0 THEN
validation_status := 'PARTIAL_SUCCESS';
ELSE
validation_status := 'FAILED';
END IF;
RETURN NEXT;
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- STEP 4: Rollback function (for safety)
-- =============================================
CREATE OR REPLACE FUNCTION rollback_migration()
RETURNS VOID AS $$
BEGIN
-- Drop the new table if migration needs to be rolled back
DROP TABLE IF EXISTS protocol_signals;
-- Drop migration functions
DROP FUNCTION IF EXISTS migrate_protocol_mappings_to_signals();
DROP FUNCTION IF EXISTS validate_migration();
DROP FUNCTION IF EXISTS rollback_migration();
END;
$$ LANGUAGE plpgsql;
-- =============================================
-- STEP 5: Usage instructions
-- =============================================
COMMENT ON FUNCTION migrate_protocol_mappings_to_signals() IS 'Migrate existing protocol mappings to new simplified signals format';
COMMENT ON FUNCTION validate_migration() IS 'Validate that migration completed successfully';
COMMENT ON FUNCTION rollback_migration() IS 'Rollback migration by removing new tables and functions';
-- Example usage:
-- SELECT migrate_protocol_mappings_to_signals(); -- Run migration
-- SELECT * FROM validate_migration(); -- Validate results
-- SELECT rollback_migration(); -- Rollback if needed