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

3.6 KiB

DELIMITER //

CREATE PROCEDURE dsql_replicate_databases(IN source_db VARCHAR(64), IN target_db VARCHAR(64))
BEGIN
    -- Declare variables
    DECLARE done INT DEFAULT FALSE;
    DECLARE table_name VARCHAR(64);
    DECLARE column_list TEXT;
    DECLARE trigger_sql TEXT;

    -- Cursor to iterate over tables in source_db
    DECLARE cur CURSOR FOR
        SELECT TABLE_NAME
        FROM INFORMATION_SCHEMA.TABLES
        WHERE TABLE_SCHEMA = source_db;

    -- Handler for end of cursor
    DECLARE CONTINUE HANDLER FOR NOT FOUND SET done = TRUE;

    -- Start transaction to ensure consistency
    START TRANSACTION;

    -- Open cursor
    OPEN cur;

    read_loop: LOOP
        FETCH cur INTO table_name;
        IF done THEN
            LEAVE read_loop;
        END IF;

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

        -- Drop existing triggers if they exist
        SET @drop_trigger_insert = CONCAT('DROP TRIGGER IF EXISTS after_insert_', table_name);
        SET @drop_trigger_update = CONCAT('DROP TRIGGER IF EXISTS after_update_', table_name);
        SET @drop_trigger_delete = CONCAT('DROP TRIGGER IF EXISTS after_delete_', table_name);
        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_', table_name,
            ' AFTER INSERT ON ', source_db, '.', table_name, ' FOR EACH ROW ',
            'BEGIN ',
            'INSERT INTO ', target_db, '.', table_name, ' (',
            (SELECT GROUP_CONCAT(COLUMN_NAME) FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = source_db AND TABLE_NAME = table_name), ') ',
            'VALUES (', column_list, '); ',
            'END;'
        );
        PREPARE stmt FROM @trigger_sql;
        EXECUTE stmt;
        DEALLOCATE PREPARE stmt;

        -- Create UPDATE trigger
        SET @trigger_sql = CONCAT(
            'CREATE TRIGGER after_update_', table_name,
            ' AFTER UPDATE ON ', source_db, '.', table_name, ' FOR EACH ROW ',
            'BEGIN ',
            'UPDATE ', target_db, '.', table_name, ' SET ',
            (SELECT GROUP_CONCAT(CONCAT(COLUMN_NAME, '=NEW.', COLUMN_NAME))
             FROM INFORMATION_SCHEMA.COLUMNS WHERE TABLE_SCHEMA = source_db AND TABLE_NAME = table_name),
            ' WHERE ',
            (SELECT CONCAT('id=NEW.id')
             FROM INFORMATION_SCHEMA.COLUMNS
             WHERE TABLE_SCHEMA = source_db AND TABLE_NAME = table_name AND COLUMN_NAME = 'id' LIMIT 1), '; ',
            'END;'
        );
        PREPARE stmt FROM @trigger_sql;
        EXECUTE stmt;
        DEALLOCATE PREPARE stmt;

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

    END LOOP;

    CLOSE cur;
    COMMIT;

END //

DELIMITER ;