datasquirel/package-shared/functions/dsql/triggers-and-stored-proceedures/table-replication.md
Benjamin Toby 7e8bb37c09 Updates
2025-07-05 14:59:30 +01:00

2.9 KiB

DELIMITER //

CREATE PROCEDURE dsql_replicate_two_tables(
    IN source_db VARCHAR(64),
    IN target_db VARCHAR(64),
    IN source_table VARCHAR(64),
    IN target_table VARCHAR(64)
)
BEGIN
    -- Declare variables
    DECLARE column_list TEXT;
    DECLARE set_clause TEXT;
    DECLARE trigger_sql TEXT;

    -- Start transaction to ensure consistency
    START TRANSACTION;

    -- Dynamically get column names for the source table
    SELECT GROUP_CONCAT(CONCAT('NEW.', COLUMN_NAME))
    INTO column_list
    FROM INFORMATION_SCHEMA.COLUMNS
    WHERE TABLE_SCHEMA = source_db
    AND TABLE_NAME = source_table;

    SELECT GROUP_CONCAT(CONCAT(COLUMN_NAME, '=NEW.', COLUMN_NAME))
    INTO set_clause
    FROM INFORMATION_SCHEMA.COLUMNS
    WHERE TABLE_SCHEMA = source_db
    AND TABLE_NAME = source_table;

    -- Drop existing triggers if they exist
    SET @drop_trigger_insert = CONCAT('DROP TRIGGER IF EXISTS after_insert_', source_table);
    SET @drop_trigger_update = CONCAT('DROP TRIGGER IF EXISTS after_update_', source_table);
    SET @drop_trigger_delete = CONCAT('DROP TRIGGER IF EXISTS after_delete_', source_table);
    PREPARE stmt_drop_insert FROM @drop_trigger_insert;
    EXECUTE stmt_drop_insert;
    DEALLOCATE PREPARE stmt_drop_insert;
    PREPARE stmt_drop_update FROM @drop_trigger_update;
    EXECUTE stmt_drop_update;
    DEALLOCATE PREPARE stmt_drop_update;
    PREPARE stmt_drop_delete FROM @drop_trigger_delete;
    EXECUTE stmt_drop_delete;
    DEALLOCATE PREPARE stmt_drop_delete;

    -- Create INSERT trigger
    SET @trigger_sql = CONCAT(
        'CREATE TRIGGER after_insert_', source_table,
        ' AFTER INSERT ON ', source_db, '.', source_table, ' FOR EACH ROW ',
        'BEGIN ',
        'INSERT INTO ', target_db, '.', target_table, ' (',
        (SELECT GROUP_CONCAT(COLUMN_NAME) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = source_db AND TABLE_NAME = source_table), ') ',
        'VALUES (', column_list, '); ',
        'END;'
    );
    PREPARE stmt FROM @trigger_sql;
    EXECUTE stmt;
    DEALLOCATE PREPARE stmt;

    -- Create UPDATE trigger
    -- Assume 'id' as the primary key; adjust if different
    SET @trigger_sql = CONCAT(
        'CREATE TRIGGER after_update_', source_table,
        ' AFTER UPDATE ON ', source_db, '.', source_table, ' FOR EACH ROW ',
        'BEGIN ',
        'UPDATE ', target_db, '.', target_table, ' SET ',
        set_clause,
        ' WHERE id = NEW.id; ',
        'END;'
    );
    PREPARE stmt FROM @trigger_sql;
    EXECUTE stmt;
    DEALLOCATE PREPARE stmt;

    -- Create DELETE trigger
    SET @trigger_sql = CONCAT(
        'CREATE TRIGGER after_delete_', source_table,
        ' AFTER DELETE ON ', source_db, '.', source_table, ' FOR EACH ROW ',
        'BEGIN ',
        'DELETE FROM ', target_db, '.', target_table, ' WHERE id = OLD.id; ',
        'END;'
    );
    PREPARE stmt FROM @trigger_sql;
    EXECUTE stmt;
    DEALLOCATE PREPARE stmt;

    COMMIT;

END //

DELIMITER ;