-- phpMyAdmin SQL Dump -- version 5.2.1deb1+deb12u1 -- https://www.phpmyadmin.net/ -- -- Host: localhost:3306 -- Generation Time: Dec 28, 2025 at 01:36 AM -- Server version: 10.11.14-MariaDB-0+deb12u2 -- PHP Version: 8.2.29 SET SQL_MODE = "NO_AUTO_VALUE_ON_ZERO"; START TRANSACTION; SET time_zone = "+00:00"; /*!40101 SET @OLD_CHARACTER_SET_CLIENT=@@CHARACTER_SET_CLIENT */; /*!40101 SET @OLD_CHARACTER_SET_RESULTS=@@CHARACTER_SET_RESULTS */; /*!40101 SET @OLD_COLLATION_CONNECTION=@@COLLATION_CONNECTION */; /*!40101 SET NAMES utf8mb4 */; -- -- Database: `cbd420` -- -- -------------------------------------------------------- -- -- Table structure for table `buyers` -- CREATE TABLE `buyers` ( `id` int(11) NOT NULL, `username` varchar(255) NOT NULL, `password` varchar(255) NOT NULL, `email` varchar(255) NOT NULL, `referral_points` decimal(10,2) NOT NULL DEFAULT 0.00, `created_at` datetime NOT NULL DEFAULT current_timestamp() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `buyer_data` -- CREATE TABLE `buyer_data` ( `id` int(11) NOT NULL, `buyer_id` int(11) NOT NULL, `fullname` text NOT NULL, `address` text NOT NULL, `phone` varchar(15) NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `deliveries` -- CREATE TABLE `deliveries` ( `id` int(11) NOT NULL, `sale_id` int(11) NOT NULL, `created_at` datetime NOT NULL DEFAULT current_timestamp(), `status` text NOT NULL DEFAULT 'Pending' ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `drops` -- CREATE TABLE `drops` ( `id` int(11) NOT NULL, `item` text NOT NULL, `size` int(11) NOT NULL DEFAULT 100, `fill` int(11) NOT NULL DEFAULT 0, `unit` varchar(12) NOT NULL DEFAULT 'g', `image_url` varchar(255) DEFAULT NULL, `ppu` int(11) NOT NULL DEFAULT 1, `created_at` datetime NOT NULL DEFAULT current_timestamp(), `start_time` datetime DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `drop_images` -- CREATE TABLE `drop_images` ( `id` int(11) NOT NULL, `drop_id` int(11) NOT NULL, `image_url` varchar(255) NOT NULL, `display_order` int(11) NOT NULL DEFAULT 0, `created_at` datetime NOT NULL DEFAULT current_timestamp() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `notification_subscribers` -- CREATE TABLE `notification_subscribers` ( `address` varchar(100) NOT NULL, `type` text NOT NULL DEFAULT '\'email\'', `buyer_id` int(11) DEFAULT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `pending_orders` -- CREATE TABLE `pending_orders` ( `id` int(11) NOT NULL, `payment_id` varchar(255) NOT NULL, `order_id` varchar(255) NOT NULL, `drop_id` int(11) NOT NULL, `buyer_id` int(11) NOT NULL, `buyer_data_id` int(11) NOT NULL, `size` int(11) NOT NULL, `price_amount` decimal(10,2) NOT NULL, `price_currency` varchar(10) NOT NULL DEFAULT 'chf', `points_used` decimal(10,2) NOT NULL DEFAULT 0.00, `created_at` datetime NOT NULL DEFAULT current_timestamp(), `expires_at` datetime NOT NULL DEFAULT (current_timestamp() + interval 10 minute) ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `referral_point_transactions` -- CREATE TABLE `referral_point_transactions` ( `id` int(11) NOT NULL, `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() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `referral_settings` -- CREATE TABLE `referral_settings` ( `id` int(11) NOT NULL, `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() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `referrals` -- CREATE TABLE `referrals` ( `id` int(11) NOT NULL, `referrer` int(11) NOT NULL, `referree` int(11) NOT NULL ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -------------------------------------------------------- -- -- Table structure for table `sales` -- CREATE TABLE `sales` ( `id` int(11) NOT NULL, `drop_id` int(11) NOT NULL, `buyer_id` int(11) NOT NULL, `buyer_data_id` int(11) NOT NULL, `size` int(11) NOT NULL DEFAULT 1, `payment_id` text NOT NULL DEFAULT '', `price_amount` decimal(10,2) DEFAULT NULL, `price_currency` varchar(10) NOT NULL DEFAULT 'chf', `points_used` decimal(10,2) NOT NULL DEFAULT 0.00, `created_at` datetime NOT NULL DEFAULT current_timestamp() ) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_general_ci; -- -- Indexes for dumped tables -- -- -- Indexes for table `buyers` -- ALTER TABLE `buyers` ADD PRIMARY KEY (`id`); -- -- Indexes for table `buyer_data` -- ALTER TABLE `buyer_data` ADD PRIMARY KEY (`id`), ADD KEY `buyer_id` (`buyer_id`); -- -- Indexes for table `deliveries` -- ALTER TABLE `deliveries` ADD PRIMARY KEY (`id`), ADD KEY `sale_id` (`sale_id`); -- -- Indexes for table `drops` -- ALTER TABLE `drops` ADD PRIMARY KEY (`id`); -- -- Indexes for table `drop_images` -- ALTER TABLE `drop_images` ADD PRIMARY KEY (`id`), ADD KEY `drop_id` (`drop_id`), ADD KEY `idx_drop_images_drop_order` (`drop_id`,`display_order`); -- -- Indexes for table `notification_subscribers` -- ALTER TABLE `notification_subscribers` ADD PRIMARY KEY (`address`), ADD KEY `buyer_id` (`buyer_id`); -- -- Indexes for table `pending_orders` -- ALTER TABLE `pending_orders` ADD PRIMARY KEY (`id`), ADD UNIQUE KEY `payment_id` (`payment_id`), ADD UNIQUE KEY `order_id` (`order_id`), ADD KEY `drop_id` (`drop_id`), ADD KEY `buyer_id` (`buyer_id`), ADD KEY `idx_expires_at` (`expires_at`), ADD KEY `buyer_data_id` (`buyer_data_id`); -- -- Indexes for table `referral_point_transactions` -- ALTER TABLE `referral_point_transactions` ADD PRIMARY KEY (`id`), ADD KEY `buyer_id` (`buyer_id`), ADD KEY `sale_id` (`sale_id`), ADD KEY `pending_order_id` (`pending_order_id`); -- -- Indexes for table `referral_settings` -- ALTER TABLE `referral_settings` ADD PRIMARY KEY (`id`), ADD UNIQUE KEY `setting_key` (`setting_key`); -- -- Indexes for table `referrals` -- ALTER TABLE `referrals` ADD PRIMARY KEY (`id`), ADD KEY `referree` (`referree`), ADD KEY `referrer` (`referrer`); -- -- Indexes for table `sales` -- ALTER TABLE `sales` ADD PRIMARY KEY (`id`), ADD KEY `drop_id` (`drop_id`), ADD KEY `buyer_id` (`buyer_id`), ADD KEY `buyer_data_id` (`buyer_data_id`); -- -- AUTO_INCREMENT for dumped tables -- -- -- AUTO_INCREMENT for table `buyers` -- ALTER TABLE `buyers` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `buyer_data` -- ALTER TABLE `buyer_data` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `deliveries` -- ALTER TABLE `deliveries` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `drops` -- ALTER TABLE `drops` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `drop_images` -- ALTER TABLE `drop_images` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `pending_orders` -- ALTER TABLE `pending_orders` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `referral_point_transactions` -- ALTER TABLE `referral_point_transactions` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `referral_settings` -- ALTER TABLE `referral_settings` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `referrals` -- ALTER TABLE `referrals` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- AUTO_INCREMENT for table `sales` -- ALTER TABLE `sales` MODIFY `id` int(11) NOT NULL AUTO_INCREMENT; -- -- Constraints for dumped tables -- -- -- Constraints for table `buyer_data` -- ALTER TABLE `buyer_data` ADD CONSTRAINT `buyer_data_ibfk_1` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`); -- -- Constraints for table `deliveries` -- ALTER TABLE `deliveries` ADD CONSTRAINT `deliveries_ibfk_1` FOREIGN KEY (`sale_id`) REFERENCES `sales` (`id`) ON DELETE CASCADE ON UPDATE CASCADE; -- -- Constraints for table `drop_images` -- ALTER TABLE `drop_images` ADD CONSTRAINT `drop_images_ibfk_1` FOREIGN KEY (`drop_id`) REFERENCES `drops` (`id`) ON DELETE CASCADE ON UPDATE CASCADE; -- -- Constraints for table `notification_subscribers` -- ALTER TABLE `notification_subscribers` ADD CONSTRAINT `notification_subscribers_ibfk_1` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`); -- -- Constraints for table `pending_orders` -- ALTER TABLE `pending_orders` ADD CONSTRAINT `pending_orders_ibfk_1` FOREIGN KEY (`drop_id`) REFERENCES `drops` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT `pending_orders_ibfk_2` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT `pending_orders_ibfk_3` FOREIGN KEY (`buyer_data_id`) REFERENCES `buyer_data` (`id`); -- -- Constraints for table `referral_point_transactions` -- ALTER TABLE `referral_point_transactions` ADD CONSTRAINT `referral_point_transactions_ibfk_1` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT `referral_point_transactions_ibfk_2` FOREIGN KEY (`sale_id`) REFERENCES `sales` (`id`) ON DELETE SET NULL ON UPDATE CASCADE, ADD CONSTRAINT `referral_point_transactions_ibfk_3` FOREIGN KEY (`pending_order_id`) REFERENCES `pending_orders` (`id`) ON DELETE SET NULL ON UPDATE CASCADE; -- -- Constraints for table `referrals` -- ALTER TABLE `referrals` ADD CONSTRAINT `referrals_ibfk_1` FOREIGN KEY (`referree`) REFERENCES `buyers` (`id`), ADD CONSTRAINT `referrals_ibfk_2` FOREIGN KEY (`referrer`) REFERENCES `buyers` (`id`); -- -- Constraints for table `sales` -- ALTER TABLE `sales` ADD CONSTRAINT `sales_ibfk_1` FOREIGN KEY (`drop_id`) REFERENCES `drops` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT `sales_ibfk_2` FOREIGN KEY (`buyer_id`) REFERENCES `buyers` (`id`) ON DELETE CASCADE ON UPDATE CASCADE, ADD CONSTRAINT `sales_ibfk_3` FOREIGN KEY (`buyer_data_id`) REFERENCES `buyer_data` (`id`); -- -- 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'); -- -- Stored procedure to award referral points when a sale is completed -- This procedure should be called after a sale is created -- Parameters: sale_id - The ID of the sale that was just created -- 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) -- Note: This assumes price_amount is already in CHF, or convert if needed 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$$ -- -- Stored procedure to spend referral points for a purchase -- This procedure deducts points from buyer's balance and records the transaction -- Parameters: -- p_buyer_id - The ID of the buyer spending points -- p_points_to_spend - Amount of points to spend -- p_pending_order_id - Optional: ID of pending order if spending for pending order -- p_sale_id - Optional: ID of sale if spending for completed sale -- Returns: 1 if successful, 0 if insufficient points -- DELIMITER $$ 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; /*!40101 SET CHARACTER_SET_CLIENT=@OLD_CHARACTER_SET_CLIENT */; /*!40101 SET CHARACTER_SET_RESULTS=@OLD_CHARACTER_SET_RESULTS */; /*!40101 SET COLLATION_CONNECTION=@OLD_COLLATION_CONNECTION */;