├── README.md ├── LICENSE └── dump.sql /README.md: -------------------------------------------------------------------------------- 1 | # A list of trick and tips for MySQL 2 | 3 | In this repo I show the use of triggers, stored procedures, functions and views through the classic example with products and sales, in a version deliberately revisited to facilitate teaching. 4 | 5 | - only two tables, one for products, one for sales; 6 | - each **product** has a field that indicates the **stock**; 7 | - with each **sale**, the product inventory decreases; 8 | - with each edit or delete of a row in the **sale** table, the product inventory is recalculated; 9 | - a view takes care of displaying the revenues for each **product**; 10 | - a custom function applies the discount based on the quantities ordered. 11 | 12 | You can test the code by importing it on a database and playing on the **sale** table, try to add or remove somethings and product stocks will be automatically modified. 13 | 14 | Tested and working on MySQL 8. 15 | 16 | :star: **If you liked what I did, if it was useful to you or if it served as a starting point for something more magical let me know with a star** :green_heart: 17 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | MIT License 2 | 3 | Copyright (c) 2022 JaxonRailey 4 | 5 | Permission is hereby granted, free of charge, to any person obtaining a copy 6 | of this software and associated documentation files (the "Software"), to deal 7 | in the Software without restriction, including without limitation the rights 8 | to use, copy, modify, merge, publish, distribute, sublicense, and/or sell 9 | copies of the Software, and to permit persons to whom the Software is 10 | furnished to do so, subject to the following conditions: 11 | 12 | The above copyright notice and this permission notice shall be included in all 13 | copies or substantial portions of the Software. 14 | 15 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR 16 | IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY, 17 | FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE 18 | AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER 19 | LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM, 20 | OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN THE 21 | SOFTWARE. 22 | -------------------------------------------------------------------------------- /dump.sql: -------------------------------------------------------------------------------- 1 | SET FOREIGN_KEY_CHECKS = 0; 2 | 3 | 4 | /* 5 | * Type: Table 6 | * Name: Product 7 | * Primary key: id_product 8 | * -------------------------------- 9 | */ 10 | 11 | DROP TABLE IF EXISTS `product`; 12 | CREATE TABLE `product` ( 13 | `id_product` INT(11) PRIMARY KEY AUTO_INCREMENT, 14 | `name` VARCHAR(255), 15 | `price` DECIMAL(8, 2) DEFAULT 0.00, 16 | `quantity` INT(6) DEFAULT 0, 17 | `date_add` DATETIME DEFAULT CURRENT_TIMESTAMP, 18 | `date_edit` DATETIME ON UPDATE CURRENT_TIMESTAMP DEFAULT NULL 19 | ) ENGINE = InnoDB DEFAULT CHARSET = utf8; 20 | 21 | INSERT INTO `product` (`name`, `price`, `quantity`) VALUES ('Milk', 1.45, 360); 22 | INSERT INTO `product` (`name`, `price`, `quantity`) VALUES ('Bread', 2.20, 72); 23 | INSERT INTO `product` (`name`, `price`, `quantity`) VALUES ('Yogurt', 0.99, 152); 24 | INSERT INTO `product` (`name`, `price`, `quantity`) VALUES ('Fruit', 2.99, 274); 25 | INSERT INTO `product` (`name`, `price`, `quantity`) VALUES ('Biscuits', 1.49, 95); 26 | 27 | 28 | /* 29 | * Type: Table 30 | * Name: Sale 31 | * Primary key: id_sale 32 | * Foreign key: id_product 33 | * -------------------------------- 34 | */ 35 | 36 | DROP TABLE IF EXISTS `sale`; 37 | CREATE TABLE `sale` ( 38 | `id_sale` INT(11) PRIMARY KEY AUTO_INCREMENT, 39 | `id_product` INT(11) NOT NULL, 40 | `quantity` INT(6), 41 | `date_add` DATETIME DEFAULT CURRENT_TIMESTAMP, 42 | `date_edit` DATETIME ON UPDATE CURRENT_TIMESTAMP DEFAULT NULL, 43 | FOREIGN KEY (`id_product`) REFERENCES `product`(`id_product`) 44 | ON DELETE CASCADE 45 | ON UPDATE CASCADE 46 | ) ENGINE = InnoDB DEFAULT CHARSET = utf8; 47 | 48 | 49 | /* 50 | * Type: Function 51 | * Name: total 52 | * Purpose: calculate the total considering the quantity discount 53 | * Params: 54 | * price 55 | * quantity 56 | * -------------------------------- 57 | */ 58 | 59 | DROP FUNCTION IF EXISTS `total`; 60 | DELIMITER $$ 61 | CREATE FUNCTION `total`(`price` DECIMAL(8, 2), `quantity` INT(6)) 62 | RETURNS DECIMAL(8, 2) DETERMINISTIC 63 | BEGIN 64 | DECLARE `calc` DECIMAL(8, 2); 65 | SET `calc` = `price` * `quantity`; 66 | 67 | -- apply 10% discount if the purchased quantity is between 10 and 49 units 68 | IF quantity > 9 AND quantity < 50 THEN 69 | SET `calc` = `calc` - (`calc` * 10 / 100); 70 | END IF; 71 | 72 | -- apply 20% discount if the purchased quantity is between 50 and 99 units 73 | IF quantity >= 50 AND quantity < 100 THEN 74 | SET `calc` = `calc` - (`calc` * 20 / 100); 75 | END IF; 76 | 77 | -- apply 25% discount if the purchased quantity is greater than 100 units 78 | IF quantity >= 100 THEN 79 | SET `calc` = `calc` - (`calc` * 25 / 100); 80 | END IF; 81 | 82 | RETURN `calc`; 83 | END $$ 84 | DELIMITER ; 85 | 86 | 87 | /* 88 | * Type: View 89 | * Name: amount 90 | * Purpose: list of products sold and revenue produced 91 | * -------------------------------- 92 | */ 93 | 94 | DROP VIEW IF EXISTS `amount`; 95 | CREATE VIEW `amount` AS 96 | SELECT 97 | `product`.`name`, 98 | sum(`sale`.`quantity`) as quantity, 99 | sum(total(`product`.`price`, `sale`.`quantity`)) AS total 100 | FROM `product` 101 | JOIN `sale` USING (`id_product`) 102 | GROUP BY `product`.`id_product`; 103 | 104 | 105 | /* 106 | * Type: Trigger 107 | * Name: saleNewProduct 108 | * Purpose: subtract the quantity sold to the product 109 | * -------------------------------- 110 | */ 111 | 112 | DROP TRIGGER IF EXISTS `saleNewProduct`; 113 | CREATE TRIGGER `saleNewProduct` 114 | BEFORE INSERT ON `sale` 115 | FOR EACH ROW 116 | CALL setProductQuantity(NEW.quantity, NEW.id_product, 'minus'); 117 | 118 | 119 | /* 120 | * Type: Trigger 121 | * Name: deleteSale 122 | * Purpose: restore quantity to the product 123 | * -------------------------------- 124 | */ 125 | 126 | DROP TRIGGER IF EXISTS `deleteSale`; 127 | CREATE TRIGGER `deleteSale` 128 | BEFORE DELETE ON `sale` 129 | FOR EACH ROW 130 | CALL setProductQuantity(OLD.quantity, OLD.id_product, 'add'); 131 | 132 | 133 | /* 134 | * Type: Trigger 135 | * Name: editSale 136 | * Purpose: recalculates the quantity of the product that has been changed in 'sale' table 137 | * -------------------------------- 138 | */ 139 | 140 | DROP TRIGGER IF EXISTS `editSale`; 141 | DELIMITER $$ 142 | CREATE TRIGGER `editSale` 143 | BEFORE UPDATE ON `sale` 144 | FOR EACH ROW 145 | BEGIN 146 | DECLARE operator VARCHAR(5); 147 | DECLARE diff INT; 148 | SET operator = 'add'; 149 | SET diff = OLD.quantity - NEW.quantity; 150 | IF NEW.quantity > OLD.quantity THEN 151 | SET operator = 'minus'; 152 | SET diff = NEW.quantity - OLD.quantity; 153 | END IF; 154 | CALL setProductQuantity(diff, OLD.id_product, operator); 155 | END $$ 156 | DELIMITER ; 157 | 158 | 159 | /* 160 | * Type: Procedure 161 | * Name: setProductQuantity 162 | * Purpose: set the quantity to the product 163 | * -------------------------------- 164 | */ 165 | 166 | DROP PROCEDURE IF EXISTS `setProductQuantity`; 167 | DELIMITER $$ 168 | CREATE PROCEDURE `setProductQuantity` (IN newQuantity INT, IN productId INT, IN operator VARCHAR(5)) 169 | BEGIN 170 | DECLARE qta INT(2); 171 | SET qta = (SELECT `quantity` FROM `product` WHERE `product`.`id_product` = productId); 172 | IF operator = 'minus' THEN 173 | IF qta - newQuantity >= 0 THEN 174 | UPDATE `product` SET `quantity` = `quantity` - newQuantity WHERE `product`.`id_product` = productId; 175 | ELSE 176 | SIGNAL SQLSTATE '02000' SET MESSAGE_TEXT = 'The product does not have the desired available quantity'; 177 | END IF; 178 | ELSE 179 | UPDATE `product` SET `quantity` = `quantity` + newQuantity WHERE `product`.`id_product` = productId; 180 | END IF; 181 | END $$ 182 | DELIMITER ; 183 | 184 | 185 | SET FOREIGN_KEY_CHECKS = 1; 186 | --------------------------------------------------------------------------------