Files
4WDCSA.co.za/scripts/ikhokha_migrations/001_add_payment_columns.sql
2025-12-15 00:36:34 +02:00

62 lines
2.8 KiB
SQL

-- Migration: add iKhokha / provider metadata to payments table
-- Migration: add iKhokha / provider metadata to payments table
-- Compatible with MySQL versions that do not support `ADD COLUMN IF NOT EXISTS`.
-- Run on staging first. Make a DB backup before running on production.
DELIMITER $$
CREATE PROCEDURE add_payment_columns_if_missing()
BEGIN
-- provider
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'provider') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `provider` VARCHAR(50) NULL AFTER `status`;
END IF;
-- provider_payment_id
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'provider_payment_id') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `provider_payment_id` VARCHAR(128) NULL AFTER `provider`;
END IF;
-- payment_link
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'payment_link') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `payment_link` VARCHAR(512) NULL AFTER `provider_payment_id`;
END IF;
-- provider_status
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'provider_status') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `provider_status` VARCHAR(50) NULL AFTER `payment_link`;
END IF;
-- provider_response (JSON)
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'provider_response') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `provider_response` JSON NULL AFTER `provider_status`;
END IF;
-- booking_id
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.COLUMNS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND COLUMN_NAME = 'booking_id') = 0 THEN
ALTER TABLE `payments` ADD COLUMN `booking_id` INT NULL AFTER `user_id`;
END IF;
-- index idx_provider_payment_id
IF (SELECT COUNT(*) FROM INFORMATION_SCHEMA.STATISTICS
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME = 'payments' AND INDEX_NAME = 'idx_provider_payment_id') = 0 THEN
ALTER TABLE `payments` ADD INDEX `idx_provider_payment_id` (`provider_payment_id`(128));
END IF;
END$$
DELIMITER ;
CALL add_payment_columns_if_missing();
DROP PROCEDURE IF EXISTS add_payment_columns_if_missing;
-- Notes:
-- 1) This script creates a short stored procedure which performs existence checks
-- against INFORMATION_SCHEMA before applying each ALTER TABLE. Run in the
-- MySQL client or via your migration tool. It avoids syntax not supported on
-- older MySQL versions.
-- 2) Test on staging and make a DB dump before running on production.