-- Migration script to add referral points system to existing database -- Run this script on your existing database to add referral points functionality -- Date: 2025-12-28 SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; START TRANSACTION; SET time_zone = "+00:00"; -- Add referral_points column to buyers table ALTER TABLE `buyers` ADD COLUMN `referral_points` decimal(10,2) NOT NULL DEFAULT 0.00 AFTER `email`; -- Add points_used column to pending_orders table ALTER TABLE `pending_orders` ADD COLUMN `points_used` decimal(10,2) NOT NULL DEFAULT 0.00 AFTER `price_currency`; -- Add points_used and price_amount columns to sales table ALTER TABLE `sales` ADD COLUMN `price_amount` decimal(10,2) DEFAULT NULL AFTER `payment_id`, ADD COLUMN `price_currency` varchar(10) NOT NULL DEFAULT 'chf' AFTER `price_amount`, ADD COLUMN `points_used` decimal(10,2) NOT NULL DEFAULT 0.00 AFTER `price_currency`; -- Create referral_point_transactions table CREATE TABLE `referral_point_transactions` ( `id` int(11) NOT NULL AUTO_INCREMENT, `buyer_id` int(11) NOT NULL, `points` decimal(10,2) NOT NULL, `type` enum('earned','spent') NOT NULL, `sale_id` int(11) DEFAULT NULL, `pending_order_id` int(11) DEFAULT NULL, `description` text DEFAULT NULL, `created_at` datetime NOT NULL DEFAULT current_timestamp(), PRIMARY KEY (`id`), KEY `buyer_id` (`buyer_id`), KEY `sale_id` (`sale_id`), KEY `pending_order_id` (`pending_order_id`), CONSTRAINT `referral_point_transactions_ibfk_1` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, CONSTRAINT `referral_point_transactions_ibfk_2` FOREIGN KEY (`sale_id`) REFERENCES `sales` (`id`) ON DELETE SET NULL ON UPDATE CASCADE, CONSTRAINT `referral_point_transactions_ibfk_3` FOREIGN KEY (`pending_order_id`) REFERENCES `pending_orders` (`id`) ON DELETE SET NULL ON UPDATE CASCADE ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- Create referral_settings table CREATE TABLE `referral_settings` ( `id` int(11) NOT NULL AUTO_INCREMENT, `setting_key` varchar(100) NOT NULL, `setting_value` varchar(255) NOT NULL, `description` text DEFAULT NULL, `updated_at` datetime NOT NULL DEFAULT current_timestamp() ON UPDATE current_timestamp(), PRIMARY KEY (`id`), UNIQUE KEY `setting_key` (`setting_key`) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- Insert default referral settings INSERT INTO `referral_settings` (`setting_key`, `setting_value`, `description`) VALUES ('points_per_chf', '10', 'Number of referral points earned per 1 CHF purchase by referred user'), ('points_to_chf', '100', 'Number of referral points required to redeem 1 CHF discount'); -- Create stored procedure to award referral points DELIMITER $$ CREATE PROCEDURE `award_referral_points`(IN p_sale_id INT) BEGIN DECLARE v_buyer_id INT; DECLARE v_referrer_id INT; DECLARE v_price_amount DECIMAL(10,2); DECLARE v_points_per_chf DECIMAL(10,2); DECLARE v_points_earned DECIMAL(10,2); DECLARE v_drop_id INT; DECLARE v_size INT; DECLARE v_ppu DECIMAL(10,2); DECLARE v_currency VARCHAR(10); -- Get sale details SELECT buyer_id, drop_id, size, COALESCE(price_amount, 0), price_currency INTO v_buyer_id, v_drop_id, v_size, v_price_amount, v_currency FROM sales WHERE id = p_sale_id; -- If price_amount is not set, calculate it from drop's ppu IF v_price_amount = 0 OR v_price_amount IS NULL THEN SELECT ppu INTO v_ppu FROM drops WHERE id = v_drop_id; SET v_price_amount = v_ppu * v_size; END IF; -- Get the referrer for this buyer (if any) SELECT referrer INTO v_referrer_id FROM referrals WHERE referree = v_buyer_id LIMIT 1; -- If there's a referrer, award points IF v_referrer_id IS NOT NULL THEN -- Get points_per_chf setting SELECT CAST(setting_value AS DECIMAL(10,2)) INTO v_points_per_chf FROM referral_settings WHERE setting_key = 'points_per_chf' LIMIT 1; -- Default to 10 if setting not found IF v_points_per_chf IS NULL THEN SET v_points_per_chf = 10; END IF; -- Calculate points earned (based on actual purchase amount in CHF) SET v_points_earned = v_price_amount * v_points_per_chf; -- Update referrer's points balance UPDATE buyers SET referral_points = referral_points + v_points_earned WHERE id = v_referrer_id; -- Record the transaction INSERT INTO referral_point_transactions ( buyer_id, points, type, sale_id, description ) VALUES ( v_referrer_id, v_points_earned, 'earned', p_sale_id, CONCAT('Points earned from referral purchase (Sale #', p_sale_id, ', Amount: ', v_price_amount, ' ', v_currency, ')') ); END IF; END$$ -- Create stored procedure to spend referral points CREATE PROCEDURE `spend_referral_points`( IN p_buyer_id INT, IN p_points_to_spend DECIMAL(10,2), IN p_pending_order_id INT, IN p_sale_id INT, OUT p_success INT ) BEGIN DECLARE v_current_points DECIMAL(10,2); DECLARE v_new_balance DECIMAL(10,2); -- Get current points balance SELECT referral_points INTO v_current_points FROM buyers WHERE id = p_buyer_id; -- Check if buyer has enough points IF v_current_points IS NULL OR v_current_points < p_points_to_spend THEN SET p_success = 0; ELSE -- Deduct points SET v_new_balance = v_current_points - p_points_to_spend; UPDATE buyers SET referral_points = v_new_balance WHERE id = p_buyer_id; -- Record the transaction INSERT INTO referral_point_transactions ( buyer_id, points, type, sale_id, pending_order_id, description ) VALUES ( p_buyer_id, p_points_to_spend, 'spent', p_sale_id, p_pending_order_id, CONCAT('Points spent for purchase', IF(p_sale_id IS NOT NULL, CONCAT(' (Sale #', p_sale_id, ')'), ''), IF(p_pending_order_id IS NOT NULL, CONCAT(' (Pending Order #', p_pending_order_id, ')'), '') ) ); SET p_success = 1; END IF; END$$ DELIMITER ; COMMIT;