├── README.md ├── classes ├── class_01.md ├── class_02.md ├── class_03.md ├── class_04.md ├── class_05.md ├── class_06.md ├── class_07.md ├── class_08.md ├── class_09.md ├── class_10.md ├── class_11.md ├── class_12.md ├── class_13.md ├── class_14.md ├── class_14_1.md ├── class_14_2.md ├── class_14_3.md ├── class_15.md ├── class_16.md ├── class_16_1.md ├── class_16_2.md ├── class_17.md ├── class_17_1.md ├── class_17_2.md ├── class_18.md ├── class_18_1.md ├── class_18_2.md ├── class_18_3.md ├── class_18_4.md ├── class_18_5.md ├── class_19.md ├── class_20.md ├── class_21.md ├── class_22.md ├── exercises-results.md ├── monogdb-querys.md ├── multidimension.md ├── multidimensional-model.md ├── mysql_administration.md └── normalization.pptx ├── images ├── 1NF.png ├── 2NFTable1.png ├── 2NFTable2.png ├── 2NFTable3.png ├── CompositeKey.png ├── ForeignKeyRelationWithPrimary.png ├── MySQL-handler-precedence.jpg ├── NormalizationTable1.png ├── Table1.png ├── Table2.png ├── WhyDataBaseIsImportant.png ├── cartesian-product.png ├── cube-example.png ├── database.png ├── foreign_key_table.png ├── inner-join-more-tables-explanation-1.png ├── inner-join-more-tables-explanation-2.png ├── inner-join-more-tables-explanation-3.png ├── inner-join-more-tables.png ├── inner-join-using-clause.png ├── inner-join.png ├── left-outer-join.png ├── mysql-case-statement.png ├── mysql-cursor.png ├── mysql-error-handling-duplicate-keys.jpg ├── mysql-error-handling.jpg ├── mysql-if-statement-flow-chart.png ├── mysql-resignal.jpg ├── mysql-signal.jpg ├── mysql-stored-procedure1.jpg ├── natural-join.png ├── partial-cube-example.png ├── partial-rollup-example.png ├── right-outer-join.png ├── rollup-example.png ├── sakila-tables.png ├── star-schema.png ├── transitive_functional_dependencies.png └── what.jpeg └── tools.md /README.md: -------------------------------------------------------------------------------- 1 | 2 | ## Prerequisites / Tools 3 | 4 | Databases Engines and Tools to [install](tools.md) 5 | 6 | ## Introduction to SQL 7 | 8 | * [DDL Basics - Data Types - Table creation - Alter tables: Class 1](classes/class_01.md) 9 | 10 | * [DDL Exercises: Class 2](classes/class_02.md) 11 | 12 | * [Simple Queries - ER diagram: Class 3](classes/class_03.md) 13 | 14 | * [Table Variables and Set Operators - Exercises: Class 4](classes/class_04.md) 15 | 16 | * [Sub-queries in WHERE: Class 5](classes/class_05.md) 17 | 18 | * [Sub-queries Exercises: Class 6](classes/class_06.md) 19 | 20 | * [Sub-queries in FROM and SELECT - Exercises : Class 7](classes/class_07.md) 21 | 22 | * [Aggregations : Class 8](classes/class_08.md) 23 | 24 | * [Aggregations (Cont.md) : Class 9](classes/class_09.md) 25 | 26 | * [Join Operators : Class 10](classes/class_10.md) 27 | 28 | * [Aggregations - Join and Misc Exercises: Class 11](classes/class_11.md) 29 | 30 | ## Database Design 31 | * [Normalization Overview : Class 12](classes/class_12.md) 32 | 33 | ## Advanced SQL 34 | 35 | * [Data Modification Statements - Exercises: Class 13](classes/class_13.md) 36 | 37 | * [Functions - Exercises: Class 14](classes/class_14.md) 38 | 39 | * [Views - Exercises: Class 15](classes/class_15.md) 40 | 41 | * [Constraints and Triggers - Exercises: Class 16](classes/class_16.md) 42 | 43 | * [Indexes - Exercises: Class 17](classes/class_17.md) 44 | 45 | * [Stored Procedures: Class 18](classes/class_18.md) 46 | * [Multiple Returns & Conditional: Class 18_1](classes/class_18_1.md) 47 | * [Loop in Stored Procedures: Class 18_2](classes/class_18_2.md) 48 | * [Error Handling: Class 18_3](classes/class_18_3.md) 49 | * [MySQL Stored Function: Class 18_4](classes/class_18_4.md) 50 | * [Exercises: Class 18_5](classes/class_18_5.md) 51 | 52 | * [MySQL Administration: Class 19](classes/mysql_administration.md) 53 | 54 | ## Mongo DB 55 | 56 | * [How to install mongo in your pc (ubuntu or dockerized.md)](classes/class_19.md) 57 | * [Mongo Queryset](classes/monogdb-querys.md) 58 | * [Mongo Exercises](classes/class_20.md) 59 | 60 | ## Key Value DB 61 | 62 | * [Redis](classes/class_21.md) 63 | 64 | ## OLAP 65 | 66 | * [Dimensional Model](classes/multidimensional-model.md) 67 | 68 | * [Vertica DB](classes/class_22.md) 69 | -------------------------------------------------------------------------------- /classes/class_01.md: -------------------------------------------------------------------------------- 1 | ### DDL Review 2 | 3 | Data Definition Language consist of commands to create and drop database objects, like tables, indexes, views, etc. 4 | 5 | ### Data types 6 | 7 | https://dev.mysql.com/doc/refman/5.7/en/data-types.html 8 | 9 | #### String Datatypes 10 | 11 | | Syntax | Maximum Size | Explanation | 12 | |------------------|--------------------------------------------------|-------------------------------------------------------------------------------------------------------------------------------| 13 | | CHAR(size) | Maximum size of 255 characters. | Where size is the number of characters to store. Fixed-length strings. Space padded on right to equal size characters. | 14 | | VARCHAR(size) | Maximum size of 65,535 characters. | Where size is the number of characters to store. Variable-length string. | 15 | | TINYTEXT(size) | Maximum size of 255 characters. | Where size is the number of characters to store. | 16 | | TEXT(size) | Maximum size of 65,535 characters. | Where size is the number of characters to store. | 17 | | MEDIUMTEXT(size) | Maximum size of 16,777,215 characters. | Where size is the number of characters to store. | 18 | | LONGTEXT(size) | Maximum size of 4GB or 4,294,967,295 characters. | Where size is the number of characters to store. | 19 | | BINARY(size) | Maximum size of 255 characters. | Where size is the number of binary characters to store. Fixed-length strings. Space padded on right to equal size characters. | 20 | | VARBINARY(size) | Maximum size of 255 characters. | Where size is the number of characters to store. Variable-length string. | 21 | 22 | #### Numeric Datatypes 23 | 24 | | Syntax | Maximum Size | Explanation | 25 | |-----------------------|-----------------------------------------------------------------------------------------------------------------------------|-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------| 26 | | BIT(m) | Where m goes from 1 to 64. Default is 1. | Numbers represented in bits e.g. BIT(5) type with value b'00111' is the numeric value 7. | 27 | | TINYINT(m) | Signed values range from -128 to 127. Unsigned values range from 0 to 255. | Very small integer value. | 28 | | SMALLINT(m) | Signed values range from -32768 to 32767. Unsigned values range from 0 to 65535. | Small integer value. | 29 | | MEDIUMINT(m) | Signed values range from -8388608 to 8388607. Unsigned values range from 0 to 16777215. | Medium integer value. | 30 | | INT(m) | Signed values range from -2147483648 to 2147483647. Unsigned values range from 0 to 4294967295. | Standard integer value. | 31 | | INTEGER(m) | Signed values range from -2147483648 to 2147483647. Unsigned values range from 0 to 4294967295. | Standard integer value. This is a synonym for the INT datatype. | 32 | | BIGINT(m) | Signed values range from -9223372036854775808 to 9223372036854775807. Unsigned values range from 0 to 18446744073709551615. | Big integer value. | 33 | | DECIMAL(m,d) | | Unpacked fixed point number. m defaults to 10, if not specified. d defaults to 0, if not specified. Where m is the total digits and d is the number of digits after the decimal. | 34 | | DEC(m,d) | | This is a synonym for the DECIMAL datatype. | 35 | | NUMERIC(m,d) | | This is a synonym for the DECIMAL datatype. | 36 | | FIXED(m,d) | | Unpacked fixed-point number. Where m is the total digits and d is the number of digits after the decimal. (Introduced in MySQL 4.1). This is a synonym for the DECIMAL datatype. | 37 | | FLOAT(m,d) | | Single precision floating point number. Where m is the total digits and d is the number of digits after the decimal. | 38 | | DOUBLE(m,d) | | Double precision floating point number. Where m is the total digits and d is the number of digits after the decimal. | 39 | | DOUBLE PRECISION(m,d) | | This is a synonym for the DOUBLE datatype. | 40 | | REAL(m,d) | | This is a synonym for the DOUBLE datatype. | 41 | | FLOAT(p) | | Floating point number. Where p is the precision. | 42 | | BOOL | | Treated as a boolean data type where a value of 0 is considered to be FALSE and any other value is considered to be TRUE. Synonym for TINYINT(1) | 43 | | BOOLEAN | | This is a synonym for the BOOL datatype. | 44 | 45 | #### Date/Time Datatypes 46 | 47 | | Syntax | Maximum Size | Explanation | 48 | |------------------|-----------------------------------------------------------------------|-----------------------------------| 49 | | DATE | Values range from 1000-01-01 to 9999-12-31. | Displayed as YYYY-MM-DD. | 50 | | DATETIME | Values range from 1000-01-01 00:00:00 to 9999-12-31 23:59:59. | Displayed as YYYY-MM-DD HH:MM:SS. | 51 | | TIMESTAMP(m) | Values range from 1970-01-01 00:00:01 UTC to 2038-01-19 03:14:07 UTC. | Displayed as YYYY-MM-DD HH:MM:SS. | 52 | | TIME | Values range from -838:59:59 to 838:59:59. | Displayed as HH:MM:SS. | 53 | | YEAR[(2 or 4)] | Year value as 2 digits or 4 digits. | Default is 4 digits. | 54 | 55 | #### Large Object (LOB) Datatypes 56 | 57 | | Syntax | Maximum Size | Explanation | 58 | |------------------|--------------------------------------------------|----------------------------------------------------------------------------------------------------| 59 | | TINYBLOB | Maximum size of 255 bytes. | | 60 | | BLOB(size) | Maximum size of 65,535 bytes. | Where size is the number of characters to store (size is optional and was introduced in MySQL 4.1) | 61 | | MEDIUMBLOB | Maximum size of 16,777,215 bytes. | | 62 | | LONGTEXT | Maximum size of 4GB or 4,294,967,295 characters. | | 63 | 64 | #### Enum Type 65 | 66 | | Syntax | Maximum Size | Explanation | 67 | |------------------|--------------------------------------------------|----------------------------------------------------------------------------------------------------| 68 | | ENUM  | | An ENUM is a string object with a value chosen from a list of permitted values that are enumerated explicitly in the column specification at table creation time | 69 | 70 | ### Table creation 71 | 72 | ```sql 73 | CREATE [ TEMPORARY ] TABLE [IF NOT EXISTS] table_name 74 | ( 75 | column1 datatype [ NULL | NOT NULL ] 76 | [ DEFAULT default_value ] 77 | [ AUTO_INCREMENT ] 78 | [ UNIQUE KEY | PRIMARY KEY ] 79 | [ COMMENT 'string' ], 80 | ... 81 | | [CONSTRAINT [constraint_name]] PRIMARY KEY [ USING BTREE | HASH ] (index_col_name, ...) 82 | ... 83 | | [CONSTRAINT [constraint_name]] 84 | FOREIGN KEY index_name (index_col_name, ...) 85 | REFERENCES another_table_name (index_col_name, ...) 86 | [ MATCH FULL | MATCH PARTIAL | MATCH SIMPLE ] 87 | [ ON DELETE { RESTRICT | CASCADE | SET NULL | NO ACTION } ] 88 | [ ON UPDATE { RESTRICT | CASCADE | SET NULL | NO ACTION } ] 89 | ); 90 | ``` 91 | Example 92 | 93 | ```sql 94 | CREATE TABLE contacts 95 | ( contact_id INT(11) NOT NULL AUTO_INCREMENT, 96 | last_name VARCHAR(30) NOT NULL, 97 | first_name VARCHAR(25), 98 | birthday DATE, 99 | CONSTRAINT contacts_pk PRIMARY KEY (contact_id) 100 | ); 101 | ``` 102 | 103 | ### Altering Tables 104 | #### Add Primary Keys 105 | 106 | ```sql 107 | ALTER TABLE table_name 108 | ADD CONSTRAINT [ constraint_name ] 109 | PRIMARY KEY [ USING BTREE | HASH ] (column1, column2, ... column_n) 110 | ``` 111 | Example 112 | 113 | ```sql 114 | ALTER TABLE contacts 115 | ADD CONSTRAINT contacts_pk 116 | PRIMARY KEY (last_name, first_name); 117 | ``` 118 | 119 | #### Add column 120 | ```sql 121 | ALTER TABLE table_name 122 | ADD new_column_name column_definition 123 | [ FIRST | AFTER column_name ]; 124 | ``` 125 | 126 | Example 127 | 128 | ```sql 129 | ALTER TABLE contacts 130 | ADD last_name varchar(40) NOT NULL 131 | AFTER contact_id; 132 | ``` 133 | 134 | #### Modify column definition (datatype) 135 | 136 | ```sql 137 | ALTER TABLE table_name 138 | MODIFY column_name column_definition 139 | [ FIRST | AFTER column_name ]; 140 | ``` 141 | 142 | Example 143 | 144 | ```sql 145 | ALTER TABLE contacts 146 | MODIFY last_name varchar(50) NULL; 147 | ``` 148 | 149 | #### Drop column 150 | 151 | ```sql 152 | ALTER TABLE table_name 153 | DROP COLUMN column_name; 154 | ``` 155 | 156 | #### Rename column 157 | 158 | ```sql 159 | ALTER TABLE table_name 160 | CHANGE COLUMN old_name new_name 161 | column_definition 162 | [ FIRST | AFTER column_name ] 163 | ``` 164 | 165 | Example 166 | 167 | ```sql 168 | ALTER TABLE contacts 169 | CHANGE COLUMN contact_type ctype 170 | varchar(20) NOT NULL; 171 | ``` 172 | 173 | #### Rename table 174 | 175 | ```sql 176 | ALTER TABLE table_name 177 | RENAME TO new_table_name; 178 | ``` 179 | 180 | Example 181 | 182 | ```sql 183 | ALTER TABLE contacts 184 | RENAME TO people; 185 | ``` 186 | 187 | #### Add Foreign Key 188 | 189 | ```sql 190 | ALTER TABLE contacts 191 | ADD 192 | [CONSTRAINT [symbol]] FOREIGN KEY 193 | [index_name] (index_col_name, ...) 194 | REFERENCES tbl_name (index_col_name,...) 195 | [ON DELETE reference_option] 196 | [ON UPDATE reference_option] 197 | 198 | --reference_option: 199 | -- RESTRICT | CASCADE | SET NULL | NO ACTION | SET DEFAULT 200 | ``` 201 | 202 | Example 203 | 204 | ```sql 205 | CREATE TABLE products 206 | ( product_name VARCHAR(50) NOT NULL, 207 | location VARCHAR(50) NOT NULL, 208 | category VARCHAR(25), 209 | CONSTRAINT products_pk PRIMARY KEY (product_name, location) 210 | ); 211 | 212 | CREATE TABLE inventory 213 | ( inventory_id INT PRIMARY KEY, 214 | product_name VARCHAR(50) NOT NULL, 215 | location VARCHAR(50) NOT NULL, 216 | quantity INT, 217 | min_level INT, 218 | max_level INT 219 | ); 220 | 221 | ALTER TABLE inventory ADD 222 | CONSTRAINT fk_inventory_products 223 | FOREIGN KEY (product_name, location) 224 | REFERENCES products (product_name, location); 225 | ``` 226 | -------------------------------------------------------------------------------- /classes/class_02.md: -------------------------------------------------------------------------------- 1 | ## Exercises 2 | 3 | - Create a new database called imdb 4 | - Create tables: film (film_id, title, description, release_year); 5 | actor (actor_id, first_name, last_name) , film_actor (actor_id, film_id) 6 | - Use autoincrement id 7 | - Create PKs 8 | - Alter table add column last_update to film and actor 9 | - Alter table add foreign keys to film_actor table 10 | - Insert some actors, films and who acted in each film 11 | 12 | -------------------------------------------------------------------------------- /classes/class_03.md: -------------------------------------------------------------------------------- 1 | # Generate ER diagram 2 | 3 | Review the diagram. 4 | 5 | ![sakila-tables](../images/sakila-tables.png) 6 | 7 | # DML 8 | Data manipulation language operations are: 9 | 10 | - SELECT 11 | - INSERT 12 | - UPDATE 13 | 14 | ## SELECT 15 | 16 | ```sql 17 | SELECT A1, A2, A3..., An 18 | FROM T1, T2, T3,..., Tn 19 | WHERE condition 20 | ``` 21 | 22 | ### Operators in The WHERE Clause 23 | 24 | | Comparison Operator | Description | 25 | |---------------------|-------------------------------------------------------| 26 | | = | Equal | 27 | | <=> | Equal (MySql, safe to compare NULL values) | 28 | | <> | Not Equal | 29 | | != | Not Equal | 30 | | > | Greater Than | 31 | | >= | Greater Than or Equal | 32 | | < | Less Than | 33 | | <= | Less Than or Equal | 34 | | BETWEEN | Within a range (inclusive) | 35 | | NOT | Negates a condition | 36 | | IS NULL | NULL value | 37 | | IS NOT NULL | Non-NULL value | 38 | | LIKE | Pattern matching with % and _ | 39 | | IN ( ) | Matches a value in a list | 40 | | EXISTS | Condition is met if subquery returns at least one row | 41 | 42 | # Simple queries 43 | 44 | ## Conditions 45 | ```sql 46 | SELECT title, rating, length 47 | FROM film 48 | WHERE length > 100; 49 | ``` 50 | ```sql 51 | SELECT title, `length` FROM film 52 | WHERE `length` BETWEEN 100 AND 120; 53 | ``` 54 | 55 | ## Mutilple Tables 56 | ```sql 57 | SELECT city, district 58 | FROM address, city 59 | WHERE address.city_id = city.city_id; 60 | ``` 61 | 62 | ## Adding distinct 63 | ```sql 64 | SELECT [DISTINCT] country, city 65 | FROM address, city, country 66 | WHERE address.city_id = city.city_id 67 | AND city.country_id = country.country_id; 68 | ``` 69 | 70 | ## Conditions with columns in different tables 71 | ```sql 72 | SELECT title, name 73 | FROM film, `language` 74 | WHERE film.language_id = language.language_id 75 | AND film.`length` > 100 AND language.name = 'English' 76 | ``` 77 | 78 | ## Ambigous column names 79 | ```sql 80 | SELECT title, category_id 81 | FROM film, film_category, category 82 | WHERE film.film_id = film_category.film_id 83 | AND film_category.category_id = category.category_id 84 | ``` 85 | 86 | ## Adding Order BY 87 | ```sql 88 | SELECT title, special_features, rental_rate, name 89 | FROM film, film_category, category 90 | WHERE film.film_id = film_category.film_id 91 | AND film_category.category_id = category.category_id 92 | ORDER BY rental_rate DESC 93 | ``` 94 | ### More than one column 95 | ```sql 96 | SELECT title, special_features, rental_rate, name 97 | FROM film, film_category, category 98 | WHERE film.film_id = film_category.film_id 99 | AND film_category.category_id = category.category_id 100 | ORDER BY rental_rate DESC, special_features ASC 101 | ``` 102 | ## Using Limit 103 | ```sql 104 | SELECT * FROM actor 105 | LIMIT 10; 106 | ``` 107 | 108 | ## Like 109 | 110 | | Wildcard | Explanation | 111 | |----------|----------------------------------------------------------------------| 112 | | % | Allows you to match any string of any length (including zero length) | 113 | | _ | Allows you to match on a single character | 114 | 115 | ```sql 116 | SELECT * 117 | FROM film 118 | WHERE special_features LIKE '%Trailers%' 119 | ``` 120 | When searching for characters _ %, they have to be escaped with \ (default escape character) 121 | 122 | ```sql 123 | SELECT * FROM address 124 | WHERE address LIKE '%\_%'; 125 | ``` 126 | ## Arithmetics 127 | ```sql 128 | SELECT title, description, rental_rate * 150 AS "In Pesos" 129 | FROM film 130 | ``` 131 | -------------------------------------------------------------------------------- /classes/class_04.md: -------------------------------------------------------------------------------- 1 | ## Set Operators 2 | 3 | - UNION 4 | - INTERSECT (Not supported by Mysql) 5 | - EXCEPT (Not supported by Mysql) 6 | 7 | ### UNION 8 | ```sql 9 | SELECT name AS val FROM category 10 | WHERE name LIKE 'A%' OR name LIKE 'M%' 11 | UNION 12 | SELECT title FROM film 13 | WHERE title LIKE 'A%' OR title LIKE 'S%' 14 | ``` 15 | Union eliminates duplicates and sort the result, to see all the values UNION ALL has to be used. 16 | 17 | ## Table Variables 18 | 19 | ```sql 20 | SELECT f.title, f.special_features, f.rental_rate, c.name 21 | FROM film f, film_category fc, category c 22 | WHERE f.film_id = fc.film_id 23 | AND fc.category_id = c.category_id 24 | ORDER BY f.rental_rate DESC, f.special_features ASC 25 | ``` 26 | 27 | ```sql 28 | SELECT f1.title, f2.title, f1.`length` 29 | FROM film f1, film f2 30 | WHERE f1.`length` = f2.`length` 31 | ``` 32 | 33 | ```sql 34 | SELECT f1.title, f2.title, f1.`length` 35 | FROM film f1, film f2 36 | WHERE f1.`length` = f2.`length` AND f1.film_id <> f2.film_id; 37 | ``` 38 | 39 | ## Exercises 40 | 41 | 1. Show title and special_features of films that are PG-13 42 | 2. Get a list of all the different films duration. 43 | 3. Show title, rental_rate and replacement_cost of films that have replacement_cost from 20.00 up to 24.00 44 | 4. Show title, category and rating of films that have 'Behind the Scenes' as special_features 45 | 5. Show first name and last name of actors that acted in 'ZOOLANDER FICTION' 46 | 6. Show the address, city and country of the store with id 1 47 | 7. Show pair of film titles and rating of films that have the same rating. 48 | 8. Get all the films that are available in store id 2 and the manager first/last name of this store (the manager will appear in all the rows). 49 | -------------------------------------------------------------------------------- /classes/class_05.md: -------------------------------------------------------------------------------- 1 | ## Subqueries in WHERE 2 | 3 | ### IN Operator 4 | 5 | The IN operator allows you to specify multiple values in a WHERE clause. The IN operator is a shorthand for multiple OR conditions. 6 | 7 | Example 1: 8 | 9 | ```sql 10 | -- Find customers who paid between $3 and $4 11 | SELECT first_name,last_name 12 | FROM customer,payment 13 | WHERE customer.customer_id = payment.customer_id 14 | AND payment.amount BETWEEN 3 AND 4; 15 | ``` 16 | 17 | ```sql 18 | SELECT first_name,last_name 19 | FROM customer 20 | WHERE customer_id IN (SELECT customer_id 21 | FROM payment 22 | WHERE amount BETWEEN 3 AND 4); 23 | ``` 24 | 25 | Just adding DISTINCT to the first query gives us the same result. 26 | 27 | Example 2: 28 | 29 | ```sql 30 | SELECT first_name 31 | FROM customer,payment 32 | WHERE customer.customer_id = payment.customer_id 33 | AND payment.amount = 0.99 34 | AND first_name LIKE ( 'W%' ) 35 | ORDER BY first_name; 36 | ``` 37 | 38 | ```sql 39 | SELECT first_name 40 | FROM customer 41 | WHERE customer_id IN (SELECT customer_id 42 | FROM payment 43 | WHERE amount = 0.99) 44 | AND first_name LIKE ( 'W%' ) 45 | ORDER BY first_name; 46 | ``` 47 | 48 | In this case, adding DISTINCT gives us the wrong result. So we have to use a subquery. 49 | 50 | ### EXCEPT as subquery 51 | 52 | ```sql 53 | SELECT first_name, last_name 54 | FROM customer 55 | WHERE customer_id IN (SELECT customer_id 56 | FROM payment 57 | WHERE amount = 0.99) 58 | AND customer_id NOT IN (SELECT customer_id 59 | FROM payment 60 | WHERE amount = 1.99) 61 | AND first_name LIKE ( 'W%' ) 62 | ``` 63 | 64 | ### EXISTS Operator 65 | 66 | The EXISTS operator is used to test for the existence of any record in a subquery. The EXISTS operator returns true if the subquery returns one or more records. 67 | 68 | Example: find customers that share the first name. 69 | 70 | If you run this query it will give you the wrong result. 71 | 72 | ```sql 73 | SELECT first_name,last_name 74 | FROM customer c1 75 | WHERE EXISTS (SELECT * 76 | FROM customer c2 77 | WHERE c1.first_name = c2.first_name) 78 | ``` 79 | 80 | This one gives you the correct one instead (a customer should not be compared against itself): 81 | 82 | ```sql 83 | SELECT first_name,last_name 84 | FROM customer c1 85 | WHERE EXISTS (SELECT * 86 | FROM customer c2 87 | WHERE c1.first_name = c2.first_name 88 | AND c1.customer_id <> c2.customer_id) 89 | ``` 90 | 91 | #### Finding max 92 | 93 | ```sql 94 | -- Find films with the max duration 95 | SELECT title,`length` 96 | FROM film f1 97 | WHERE NOT EXISTS (SELECT * 98 | FROM film f2 99 | WHERE f2.`length` > f1.`length`); 100 | ``` 101 | 102 | -------------------------------------------------------------------------------- /classes/class_06.md: -------------------------------------------------------------------------------- 1 | ## Exercises 2 | 1. List all the actors that share the last name. Show them in order 3 | 2. Find actors that don't work in any film 4 | 3. Find customers that rented only one film 5 | 4. Find customers that rented more than one film 6 | 5. List the actors that acted in 'BETRAYED REAR' or in 'CATCH AMISTAD' 7 | 6. List the actors that acted in 'BETRAYED REAR' but not in 'CATCH AMISTAD' 8 | 7. List the actors that acted in both 'BETRAYED REAR' and 'CATCH AMISTAD' 9 | 8. List all the actors that didn't work in 'BETRAYED REAR' or 'CATCH AMISTAD' 10 | -------------------------------------------------------------------------------- /classes/class_07.md: -------------------------------------------------------------------------------- 1 | ## ALL / ANY 2 | 3 | **ALL** means “return TRUE if the comparison is TRUE for ALL of the values in the column that the subquery returns.” 4 | For example: 5 | 6 | ```sql 7 | SELECT s1 FROM t1 WHERE s1 > ALL (SELECT s1 FROM t2); 8 | ``` 9 | 10 | Suppose that there is a row in table t1 containing (10). The expression is TRUE if table t2 contains (-5,0,+5) 11 | because 10 is greater than all three values in t2. 12 | The expression is FALSE if table t2 contains (12,6,NULL,-100) because there is a single value 12 in table t2 13 | that is greater than 10. The expression is unknown (that is, NULL) if table t2 contains (0,NULL,1). 14 | 15 | Finally, the expression is TRUE if table t2 is empty. So, the following expression is TRUE when table t2 is empty: 16 | ```sql 17 | SELECT * FROM t1 WHERE 1 > ALL (SELECT s1 FROM t2); 18 | ``` 19 | 20 | ```sql 21 | SELECT title,length 22 | FROM film 23 | WHERE length >= ALL (SELECT length 24 | FROM film); 25 | ``` 26 | 27 | 28 | ```sql 29 | UPDATE film SET length = 200 WHERE film_id = 182; 30 | 31 | SELECT title,length 32 | FROM film f1 33 | WHERE length > ALL (SELECT length 34 | FROM film f2 35 | WHERE f2.film_id <> f1.film_id); 36 | ``` 37 | 38 | 39 | **ANY** means “return TRUE if the comparison is TRUE for ANY of the values in the column that the subquery returns.” 40 | For example: 41 | 42 | ```sql 43 | SELECT s1 FROM t1 WHERE s1 > ANY (SELECT s1 FROM t2); 44 | ``` 45 | 46 | Suppose that there is a row in table t1 containing (10). The expression is TRUE if table t2 contains (21,14,7) 47 | because there is a value 7 in t2 that is less than 10. 48 | The expression is FALSE if table t2 contains (20,10), or if table t2 is empty 49 | 50 | ```sql 51 | SELECT title,length 52 | FROM film f1 53 | WHERE NOT length <= ANY (SELECT length 54 | FROM film f2 55 | WHERE f2.film_id <> f1.film_id); 56 | 57 | UPDATE film SET length = 185 WHERE film_id = 182; 58 | ``` 59 | 60 | ```sql 61 | -- Films whose replacement cost is higher than the lowest replacement cost 62 | SELECT title,replacement_cost 63 | FROM film 64 | WHERE replacement_cost > ANY (SELECT replacement_cost 65 | FROM film) 66 | ORDER BY replacement_cost; 67 | 68 | -- Same query with exists 69 | SELECT title,replacement_cost 70 | FROM film f1 71 | WHERE EXISTS (SELECT * 72 | FROM film f2 73 | WHERE f1.replacement_cost > f2.replacement_cost) 74 | ORDER BY replacement_cost; 75 | ``` 76 | 77 | ## Subqueries in FROM 78 | 79 | ```sql 80 | SELECT title,description, 81 | rental_rate, 82 | rental_rate * 150 AS in_pesos 83 | FROM film 84 | WHERE rental_rate * 150 > 10.0 85 | AND rental_rate * 150 < 70.0; 86 | 87 | -- Can be written 88 | 89 | SELECT * 90 | FROM (SELECT title,description,rental_rate,rental_rate * 150 AS in_pesos 91 | FROM film) g 92 | WHERE in_pesos > 10.0 93 | AND in_pesos < 70.0; 94 | 95 | ``` 96 | 97 | ## Subqueries in SELECT 98 | 99 | This is an example to show that this can also be done, there are simpler ways of 100 | doing this: 101 | 102 | ```sql 103 | SELECT customer_id, 104 | first_name, 105 | last_name, 106 | (SELECT DISTINCT amount 107 | FROM payment 108 | WHERE customer.customer_id = payment.customer_id 109 | AND amount >= ALL (SELECT amount 110 | FROM payment 111 | WHERE customer.customer_id = payment.customer_id)) 112 | AS max_amount 113 | FROM customer 114 | ORDER BY max_amount DESC, 115 | customer_id DESC; 116 | ``` 117 | Is equivalent to 118 | 119 | ```sql 120 | SELECT customer_id, 121 | first_name, 122 | last_name, 123 | (SELECT MAX(amount) 124 | FROM payment 125 | WHERE payment.customer_id = customer.customer_id) AS max_amount 126 | FROM customer 127 | ORDER BY max_amount DESC, 128 | customer_id DESC; 129 | ``` 130 | 131 | ```sql 132 | SELECT customer.customer_id, 133 | first_name, 134 | last_name, 135 | MAX(amount) max_amount 136 | FROM customer, payment 137 | WHERE customer.customer_id = payment.customer_id 138 | GROUP BY customer_id, first_name, last_name 139 | ORDER BY max_amount DESC, customer_id DESC 140 | ``` 141 | 142 | ## Exercises 143 | 144 | 1. Find the films with less duration, show the title and rating. 145 | 2. Write a query that returns the tiltle of the film which duration is the lowest. If there are more than one film with the lowest durtation, the query returns an empty resultset. 146 | 3. Generate a report with list of customers showing the lowest payments done by each of them. Show customer information, the address and the lowest amount, provide both solution using ALL and/or ANY and MIN. 147 | 4. Generate a report that shows the customer's information with the highest payment and the lowest payment in the same row. 148 | -------------------------------------------------------------------------------- /classes/class_08.md: -------------------------------------------------------------------------------- 1 | ## Aggregations 2 | 3 | * The MIN() function returns the smallest value of the selected column. 4 | 5 | * The MAX() function returns the largest value of the selected column. 6 | 7 | * The COUNT() function returns the number of rows that matches a specified criteria. 8 | 9 | * The AVG() function returns the average value of a numeric column. 10 | 11 | * The SUM() function returns the total sum of a numeric column. 12 | 13 | #### Simple example 14 | 15 | ```sql 16 | -- Find the minimum payment of users whose last name starts with R 17 | SELECT MIN(amount) 18 | FROM customer, payment 19 | WHERE customer.customer_id = payment.customer_id 20 | AND customer.last_name LIKE 'R%' 21 | ``` 22 | 23 | #### Using Count 24 | ```sql 25 | -- 26 | SELECT COUNT(*) 27 | FROM inventory 28 | WHERE store_id = 1; 29 | 30 | SELECT COUNT(DISTINCT film_id) 31 | FROM inventory 32 | WHERE store_id = 1; 33 | ``` 34 | 35 | #### When to use subqueries 36 | 37 | ```sql 38 | -- wrong result 39 | SELECT AVG(length) 40 | FROM film, inventory 41 | WHERE film.film_id = inventory.film_id 42 | AND inventory.store_id = 1 43 | 44 | -- right result 45 | SELECT AVG (length) 46 | FROM film 47 | WHERE film_id IN (SELECT film_id 48 | FROM inventory 49 | WHERE store_id = 1) 50 | ``` 51 | 52 | ```sql 53 | -- same AS above 54 | SELECT str1.av 55 | FROM ( SELECT AVG(length) av 56 | FROM film 57 | WHERE film_id IN (SELECT film_id 58 | FROM inventory 59 | WHERE store_id = 1)) AS str1 60 | ``` 61 | 62 | 63 | ```sql 64 | SELECT other_stores.av 65 | FROM ( SELECT AVG(length) av 66 | FROM film 67 | WHERE film_id NOT IN (SELECT film_id 68 | FROM inventory 69 | WHERE store_id = 1)) AS other_stores 70 | ``` 71 | 72 | ```sql 73 | -- complex example: Calculate diff between average film length 74 | -- in store 1 vs other stores 75 | 76 | SELECT str1.av - other_stores.av 77 | FROM ( 78 | SELECT AVG(length) av 79 | FROM film 80 | WHERE film_id IN (SELECT film_id 81 | FROM inventory 82 | WHERE store_id = 1)) AS str1, 83 | (SELECT AVG(length) av 84 | FROM film 85 | WHERE film_id NOT IN (SELECT film_id 86 | FROM inventory 87 | WHERE store_id = 1)) AS other_stores 88 | ``` 89 | 90 | Similar but with subqueries in select 91 | 92 | ```sql 93 | SELECT 94 | (SELECT AVG(length) av 95 | FROM film 96 | WHERE film_id IN (SELECT film_id 97 | FROM inventory 98 | WHERE store_id = 1)) 99 | - 100 | (SELECT AVG(length) av 101 | FROM film 102 | WHERE film_id NOT IN (SELECT film_id 103 | FROM inventory 104 | WHERE store_id = 1)) AS diff_avg 105 | FROM film; 106 | ``` 107 | ## Group By 108 | 109 | The GROUP BY clause is used in a SELECT statement to collect data across multiple records and group the results by one or more columns. 110 | 111 | ### Syntax 112 | 113 | ```sql 114 | SELECT expression1, expression2, ... expression_n, 115 | aggregate_function (expression) 116 | FROM tables 117 | [WHERE conditions] 118 | GROUP BY expression1, expression2, ... expression_n; 119 | ``` 120 | 121 | ```sql 122 | SELECT rating, title 123 | FROM film 124 | ORDER BY rating 125 | 126 | -- Find films amounts per rating 127 | SELECT rating, COUNT(*) 128 | FROM film 129 | GROUP BY rating 130 | 131 | -- Find films durations per rating 132 | SELECT rating, AVG(length) 133 | FROM film 134 | GROUP BY rating 135 | ``` 136 | 137 | ```sql 138 | -- Find films durations per rating and special_features 139 | SELECT rating, special_features, `length` 140 | FROM film 141 | ORDER BY rating, special_features 142 | 143 | -- Using other aggretation functions 144 | SELECT rating, special_features, MIN(`length`), MAX(`length`) 145 | FROM film 146 | GROUP BY rating, special_features 147 | 148 | -- Working with aggregated columns on outer select. 149 | SELECT mx - mn AS diff 150 | FROM (SELECT rating, special_features, MIN(`length`) AS mn, MAX(`length`) AS mx 151 | FROM film 152 | GROUP BY rating, special_features) t1 153 | ``` -------------------------------------------------------------------------------- /classes/class_09.md: -------------------------------------------------------------------------------- 1 | ## Having 2 | 3 | The HAVING clause is used in combination with the GROUP BY clause to restrict the groups of returned rows to only those whose the condition is TRUE. 4 | 5 | #### Syntax 6 | 7 | ```sql 8 | SELECT expression1, expression2, ... expression_n, 9 | aggregate_function (expression) 10 | FROM tables 11 | [WHERE conditions] 12 | GROUP BY expression1, expression2, ... expression_n 13 | HAVING condition; 14 | ``` 15 | 16 | #### Example 17 | 18 | ```sql 19 | -- Find customers that rented only one film 20 | SELECT c.customer_id, first_name, last_name, COUNT(*) 21 | FROM rental r1, customer c 22 | WHERE c.customer_id = r1.customer_id 23 | GROUP BY c.customer_id, first_name, last_name 24 | HAVING COUNT(*) = 1 25 | ``` 26 | 27 | ```sql 28 | -- Show the films' ratings where the minimum film duration in that group is greater than 46 29 | SELECT rating, MIN(`length`) 30 | FROM film 31 | GROUP BY rating 32 | HAVING MIN(`length`) > 46 33 | ``` 34 | 35 | ```sql 36 | -- Show ratings that have less than 195 films 37 | SELECT rating, COUNT(*) AS total 38 | FROM film 39 | GROUP BY rating 40 | HAVING COUNT(*) < 195 41 | 42 | -- same but with subqueries 43 | SELECT DISTINCT rating, 44 | (SELECT COUNT(*) FROM film f3 WHERE f3.rating = f1.rating) AS total 45 | FROM film f1 46 | WHERE (SELECT COUNT(*) 47 | FROM film f2 WHERE f1.rating = f2.rating) < 195 48 | ``` 49 | 50 | ```sql 51 | -- Show ratings where their film duration average is grater than all films duration average. 52 | SELECT rating, AVG(`length`) 53 | FROM film 54 | GROUP BY rating 55 | HAVING AVG(`length`) > (SELECT AVG(`length`) FROM film) 56 | ``` 57 | 58 | ### Exercises: 59 | 60 | 1. Get the amount of cities per country in the database. Sort them by country, country_id. 61 | 62 | 2. Get the amount of cities per country in the database. Show only the countries with more than 10 cities, order from the highest amount of cities to the lowest 63 | 64 | 3. Generate a report with customer (first, last) name, address, total films rented and the total money spent renting films. 65 | - Show the ones who spent more money first . 66 | 67 | 4. Which film categories have the larger film duration (comparing average)? 68 | - Order by average in descending order 69 | 70 | 5. Show sales per film rating -------------------------------------------------------------------------------- /classes/class_10.md: -------------------------------------------------------------------------------- 1 | ## CARTESIAN PRODUCT 2 | This is what we saw in previous classes to get results from multiple tables 3 | 4 | ![cartesian-product](../images/cartesian-product.png) 5 | 6 | ## INNER JOIN 7 | 8 | [INNER] JOIN selects all rows from both participating tables to appear in the result if and only if both tables meet the conditions specified in the ON clause. 9 | 10 | ### ON clause 11 | 12 | ![inner-join](../images/inner-join.png) 13 | 14 | Example (analyze with explain plan): 15 | 16 | ```sql 17 | SELECT * 18 | FROM film 19 | INNER JOIN `language` 20 | ON film.language_id = `language`.language_id; 21 | 22 | -- Try this 23 | SELECT * 24 | FROM `language`, film 25 | WHERE film.language_id = `language`.language_id 26 | ``` 27 | 28 | Discuss results. 29 | 30 | ### Using clause 31 | 32 | When column names match in both tables the USING clause can be used. 33 | 34 | ![inner-join-using-clause](../images/inner-join-using-clause.png) 35 | 36 | Example 37 | 38 | ```sql 39 | SELECT * 40 | FROM film 41 | INNER JOIN `language` 42 | USING (language_id) 43 | ``` 44 | 45 | ### INNER JOIN with alias 46 | 47 | Table names can be defined and used like this: 48 | 49 | Example 50 | 51 | ```sql 52 | SELECT * 53 | FROM film AS f 54 | INNER JOIN `language` AS l 55 | ON f.language_id = l.language_id 56 | ``` 57 | 58 | ### INNER JOIN using three tables 59 | 60 | ![inner-join-more-tables](../images/inner-join-more-tables.png) 61 | 62 | ### First part 63 | ![inner-join-more-tables-explanation-1](../images/inner-join-more-tables-explanation-1.png) 64 | 65 | 66 | ### Second part 67 | ![inner-join-more-tables-explanation-2](../images/inner-join-more-tables-explanation-2.png) 68 | 69 | 70 | ### Final Result 71 | ![inner-join-more-tables-explanation-3](../images/inner-join-more-tables-explanation-3.png) 72 | 73 | Example: 74 | 75 | ```sql 76 | SELECT * 77 | FROM film 78 | INNER JOIN film_category 79 | ON film.film_id = film_category.film_id 80 | INNER JOIN category 81 | ON film_category.category_id = category.category_id; 82 | 83 | -- same? 84 | SELECT * 85 | FROM film, film_category, category 86 | WHERE film.film_id = film_category.film_id 87 | AND film_category.category_id = category.category_id; 88 | 89 | -- with using 90 | SELECT * 91 | FROM film 92 | INNER JOIN film_category 93 | USING ( film_id ) 94 | INNER JOIN category 95 | USING ( category_id ); 96 | 97 | ``` 98 | 99 | ## NATURAL JOIN 100 | 101 | NATURAL JOIN is such a join that performs the same task as an INNER (or LEFT JOIN), in which the ON or USING clause refers to all columns that the tables to be joined have in common. 102 | 103 | The MySQL NATURAL JOIN is structured in such a way that, columns with the same name of associate tables will appear once only. 104 | 105 | 1. The associated tables have one or more pairs of identically named columns. 106 | 2. The columns must be the same data type. 107 | 3. Don’t use ON clause in a NATURAL JOIN. 108 | 109 | 110 | ![natural-join](../images/natural-join.png) 111 | 112 | Example: 113 | 114 | ```sql 115 | SELECT * 116 | FROM film 117 | NATURAL JOIN `language` 118 | ``` 119 | 120 | What is going on here? 121 | 122 | ![what](../images/what.jpeg) 123 | 124 | ## Some examples 125 | 126 | ```sql 127 | -- find films pairs with same duration 128 | SELECT f1.title, f2.title, f1.`length` 129 | FROM film f1, film f2 130 | WHERE f1.`length` = f2.`length` AND f1.film_id < f2.film_id; 131 | 132 | -- with join 133 | SELECT f1.title, f2.title, f1.`length` 134 | FROM film f1 135 | INNER JOIN film f2 USING(`length`) 136 | WHERE f1.film_id < f2.film_id 137 | ``` 138 | 139 | ```sql 140 | -- natural join the same table... ??? 141 | SELECT * 142 | FROM actor a1 143 | NATURAL JOIN actor a2 144 | ``` 145 | 146 | 147 | ## LEFT OUTER JOIN 148 | LEFT [OUTER] JOIN joins two tables and fetches rows based on a condition, which match in both tables and including the unmatched rows from the table written before the JOIN clause. 149 | 150 | ![left-outer-join](../images/left-outer-join.png) 151 | 152 | 153 | Example: 154 | 155 | ```sql 156 | -- add a new copy of ACADEMY DINOSAUR to store 1 157 | INSERT INTO inventory 158 | (film_id, store_id, last_update) 159 | VALUES(1, 1, '2017-02-15 05:09:17.000'); 160 | 161 | -- this shows what? 162 | SELECT title, rental.* 163 | FROM film 164 | INNER JOIN inventory USING (film_id) 165 | LEFT OUTER JOIN rental USING (inventory_id) 166 | WHERE store_id = 1 167 | AND film_id = 1; 168 | ``` 169 | 170 | ## RIGHT OUTER JOIN 171 | 172 | RIGHT [OUTER] JOIN joins two tables and fetches rows based on a condition, which match in both tables and including the unmatched rows available from the table written after the JOIN clause. 173 | 174 | ![right-outer-join](../images/right-outer-join.png) 175 | -------------------------------------------------------------------------------- /classes/class_11.md: -------------------------------------------------------------------------------- 1 | ## Exercises 2 | 3 | 4 | 4. Find all the film titles that are not in the inventory. 5 | 6 | 5. Find all the films that are in the inventory but were never rented. 7 | - Show title and inventory_id. 8 | - This exercise is complicated. 9 | - hint: use sub-queries in FROM and in WHERE or use left join and ask if one of the fields is null 10 | 11 | 6. Generate a report with: 12 | - customer (first, last) name, store id, film title, 13 | - when the film was rented and returned for each of these customers 14 | - order by store_id, customer last_name 15 | 16 | 7. Show sales per store (money of rented films) 17 | - show store's city, country, manager info and total sales (money) 18 | - (optional) Use concat to show city and country and manager first and last name 19 | 20 | 21 | 22 | 9. Which actor has appeared in the most films? 23 | 24 | 25 | -------------------------------------------------------------------------------- /classes/class_12.md: -------------------------------------------------------------------------------- 1 | ## What is Normalization? 2 | Normalization is a database design technique which organizes tables in a manner that reduces redundancy and dependency of data. 3 | 4 | ![Presentation](./normalization.pptx) 5 | -------------------------------------------------------------------------------- /classes/class_13.md: -------------------------------------------------------------------------------- 1 | ## INSERT Statement 2 | 3 | The INSERT statement is used to insert a single record or multiple records into a table. 4 | 5 | Syntax 6 | 7 | In its simplest form, the syntax for the INSERT statement when inserting a single record using the VALUES keyword is: 8 | 9 | ```sql 10 | INSERT INTO table 11 | (column1, column2, ... ) 12 | VALUES 13 | (expression1, expression2, ... ), 14 | (expression1, expression2, ... ), 15 | ...; 16 | ``` 17 | 18 | In its simplest form, the syntax for the INSERT statement when inserting multiple records using a sub-select in MySQL is: 19 | 20 | ```sql 21 | INSERT INTO table 22 | (column1, column2, ... ) 23 | SELECT expression1, expression2, ... 24 | FROM source_table 25 | [WHERE conditions]; 26 | ``` 27 | 28 | Example - Using VALUES keyword 29 | ```sql 30 | INSERT INTO suppliers 31 | (supplier_id, supplier_name) 32 | VALUES 33 | (1000, 'Dell'); 34 | ``` 35 | 36 | Example - Using sub-query 37 | 38 | ```sql 39 | INSERT INTO suppliers 40 | (supplier_id, supplier_name) 41 | SELECT account_no, name 42 | FROM customers 43 | WHERE customer_id < 5000; 44 | ``` 45 | 46 | ## UPDATE Statement 47 | 48 | The UPDATE statement is used to update existing records in a table in a database. 49 | There are 3 syntaxes for the UPDATE statement depending on the type of update that you wish to perform. 50 | 51 | Syntax 52 | 53 | In its simplest form, the syntax for the UPDATE statement when updating one table in is: 54 | 55 | ```sql 56 | UPDATE table 57 | SET column1 = expression1, 58 | column2 = expression2, 59 | ... 60 | [WHERE conditions]; 61 | ``` 62 | 63 | OR 64 | 65 | The syntax for the UPDATE statement when updating one table with data from another table in MySQL is: 66 | 67 | ```sql 68 | UPDATE table1 69 | SET column1 = (SELECT expression1 70 | FROM table2 71 | WHERE conditions) 72 | [WHERE conditions]; 73 | ``` 74 | 75 | OR 76 | 77 | ```sql 78 | The syntax for MySQL UPDATE statement when updating multiple tables is: 79 | 80 | UPDATE table1, table2, ... 81 | SET column1 = expression1, 82 | column2 = expression2, 83 | ... 84 | WHERE table1.column = table2.column 85 | AND conditions; 86 | ``` 87 | 88 | Example - Update single column 89 | 90 | ```sql 91 | UPDATE customers 92 | SET last_name = 'Anderson' 93 | WHERE customer_id = 5000; 94 | ``` 95 | 96 | Example - Update multiple columns 97 | 98 | ```sql 99 | UPDATE customers 100 | SET state = 'California', 101 | customer_rep = 32 102 | WHERE customer_id > 100; 103 | ``` 104 | 105 | Example - Update table with data from another table 106 | 107 | ```sql 108 | UPDATE customers 109 | SET city = (SELECT city 110 | FROM suppliers 111 | WHERE suppliers.supplier_name = customers.customer_name) 112 | WHERE customer_id > 2000; 113 | ``` 114 | 115 | Example - Update multiple Tables 116 | ```sql 117 | UPDATE customers, suppliers 118 | SET customers.city = suppliers.city 119 | WHERE customers.customer_id = suppliers.supplier_id; 120 | ``` 121 | 122 | ## DELETE Statement 123 | 124 | The DELETE statement is used to delete a single record or multiple records from a table. 125 | 126 | Syntax 127 | 128 | In its simplest form, the syntax for the DELETE statement in is: 129 | ```sql 130 | DELETE FROM table 131 | [WHERE conditions]; 132 | ``` 133 | 134 | Example - With One condition 135 | ```sql 136 | DELETE FROM contacts 137 | WHERE last_name = 'Johnson'; 138 | ``` 139 | 140 | Example - With Two conditions 141 | ```sql 142 | DELETE FROM contacts 143 | WHERE last_name = 'Johnson' 144 | AND contact_id < 1000; 145 | ``` 146 | 147 | Example - With LIMIT modifier 148 | 149 | ```sql 150 | DELETE FROM contacts 151 | WHERE last_name = 'Johnson' 152 | ORDER BY contact_id DESC 153 | LIMIT 1; 154 | ``` 155 | 156 | Example - Using EXISTS Condition 157 | ```sql 158 | DELETE FROM suppliers 159 | WHERE EXISTS 160 | ( SELECT * 161 | FROM customers 162 | WHERE customers.customer_id = suppliers.supplier_id 163 | AND customer_id > 500 ); 164 | ``` 165 | 166 | This DELETE example would delete all records in the suppliers table where there is a record in the customers 167 | table whose customer_id is greater than 500, and the customer_id matches the supplier_id. 168 | 169 | 170 | ## TRUNCATE TABLE Statement 171 | 172 | The TRUNCATE TABLE statement is used to remove all records from a table. It performs the same function as a DELETE statement without a WHERE clause. 173 | 174 | `Warning: If you truncate a table, the TRUNCATE TABLE statement can not be rolled back.` 175 | 176 | 177 | Syntax 178 | 179 | The syntax for the TRUNCATE TABLE statement is: 180 | 181 | ```sql 182 | TRUNCATE TABLE [database_name.]table_name; 183 | ``` 184 | 185 | Notes 186 | 187 | - When you truncate a table, the AUTO_INCREMENT counters on the table will be reset. 188 | - MySQL truncates the table by dropping and creating the table. Thus, the DELETE triggers for the table do not fire during the truncation. 189 | - Starting in MySQL 5.5, you can not truncate an InnoDB table that is referenced by a foreign key in another table. 190 | - Starting in MySQL 5.6, you can not truncate a NDB table that is referenced by a foreign key in another table. 191 | 192 | Example 193 | ```sql 194 | TRUNCATE TABLE customers; 195 | ``` 196 | 197 | This example would truncate the table called customers and remove all records from that table. 198 | 199 | 200 | ## IS NULL Condition 201 | 202 | The **IS NULL** Condition is used to test for a NULL value in a **SELECT, INSERT, UPDATE, or DELETE** statement. 203 | 204 | Syntax 205 | 206 | The syntax for the IS NULL Condition in MySQL is: 207 | 208 | ```sql 209 | expression IS NULL 210 | ``` 211 | 212 | Example - With INSERT Statement 213 | 214 | ```sql 215 | INSERT INTO contacts 216 | (contact_id, contact_name) 217 | SELECT account_no, supplier_name 218 | FROM suppliers 219 | WHERE category IS NULL; 220 | ``` 221 | 222 | Example - With UPDATE Statement 223 | 224 | ```sql 225 | UPDATE contacts 226 | SET last_name = 'TBD' 227 | WHERE last_name IS NULL; 228 | ``` 229 | 230 | Example - With DELETE Statement 231 | 232 | ```sql 233 | DELETE FROM contacts 234 | WHERE last_name IS NULL; 235 | ``` 236 | 237 | ## IS NOT NULL 238 | 239 | The **IS NOT NULL** condition is used to test for a NOT NULL value in a **SELECT, INSERT, UPDATE, or DELETE** statement. 240 | 241 | Syntax 242 | 243 | The syntax for the IS NOT NULL Condition in MySQL is: 244 | 245 | ```sql 246 | expression IS NOT NULL 247 | ``` 248 | 249 | Example - With SELECT Statement 250 | 251 | ```sql 252 | SELECT * 253 | FROM contacts 254 | WHERE last_name IS NOT NULL; 255 | ``` 256 | 257 | ## Excersises 258 | 259 | Write the statements with all the needed subqueries, do not use hard-coded ids unless is specified. 260 | Check which fields are mandatory and which ones can be ommited (use default value). 261 | 262 | 1. Add a new customer 263 | - To store 1 264 | - For address use an existing address. The one that has the biggest address_id in 'United States' 265 | 266 | 2. Add a rental 267 | - Make easy to select any film title. I.e. I should be able to put 'film tile' in the where, and not the id. 268 | - Do not check if the film is already rented, just use any from the inventory, e.g. the one with highest id. 269 | - Select any staff_id from Store 2. 270 | 271 | 3. Update film year based on the rating 272 | - For example if rating is 'G' release date will be '2001' 273 | - You can choose the mapping between rating and year. 274 | - Write as many statements are needed. 275 | 276 | 4. Return a film 277 | - Write the necessary statements and queries for the following steps. 278 | - Find a film that was not yet returned. And use that rental id. Pick the latest that was rented for example. 279 | - Use the id to return the film. 280 | 281 | 5. Try to delete a film 282 | - Check what happens, describe what to do. 283 | - Write all the necessary delete statements to entirely remove the film from the DB. 284 | 285 | 6. Rent a film 286 | - Find an inventory id that is available for rent (available in store) pick any movie. Save this id somewhere. 287 | - Add a rental entry 288 | - Add a payment entry 289 | - Use sub-queries for everything, except for the inventory id that can be used directly in the queries. 290 | 291 | Once you're done. Restore the database data using the populate script from class 3. 292 | 293 | -------------------------------------------------------------------------------- /classes/class_14.md: -------------------------------------------------------------------------------- 1 | ## Functions 2 | 3 | - [String Functions](class_14_1.md) 4 | - [Date and Time Functions](class_14_2.md) 5 | - [Numeric Functions](class_14_3.md) 6 | - [MySQL - Functions and Operators Reference](https://dev.mysql.com/doc/refman/5.7/en/functions.html) 7 | 8 | ## Exercises 9 | 10 | 1. Write a query that gets all the customers that live in Argentina. Show the first and last name in one column, the address and the city. 11 | 12 | 2. Write a query that shows the film title, language and rating. Rating shall be shown as the full text described here: https://en.wikipedia.org/wiki/Motion_picture_content_rating_system#United_States. Hint: use case. 13 | 14 | 3. Write a search query that shows all the films (title and release year) an actor was part of. Assume the actor comes from a text box introduced by hand from a web page. Make sure to "adjust" the input text to try to find the films as effectively as you think is possible. 15 | 16 | 4. Find all the rentals done in the months of May and June. Show the film title, customer name and if it was returned or not. There should be returned column with two possible values 'Yes' and 'No'. 17 | 18 | 5. Investigate CAST and CONVERT functions. Explain the differences if any, write examples based on sakila DB. 19 | 20 | 6. Investigate NVL, ISNULL, IFNULL, COALESCE, etc type of function. Explain what they do. Which ones are not in MySql and write usage examples. 21 | -------------------------------------------------------------------------------- /classes/class_15.md: -------------------------------------------------------------------------------- 1 | A VIEW is not a physical table, but rather, it is in essence a virtual table created by a query joining one or more tables. 2 | 3 | ### Create VIEW 4 | 5 | Syntax 6 | 7 | The syntax for the CREATE VIEW statement in MySQL is: 8 | ```sql 9 | CREATE [OR REPLACE] VIEW view_name AS 10 | SELECT columns 11 | FROM tables 12 | [WHERE conditions]; 13 | ``` 14 | #### OR REPLACE 15 | Optional. If you do not specify this clause and the VIEW already exists, the CREATE VIEW statement will return an error. 16 | #### view_name 17 | The name of the VIEW that you wish to create in MySQL. 18 | #### WHERE conditions 19 | Optional. The conditions that must be met for the records to be included in the VIEW. 20 | Example 21 | 22 | Here is an example of how to use the CREATE VIEW statement to create a view in MySQL: 23 | 24 | ```sql 25 | CREATE VIEW hardware_suppliers AS 26 | SELECT supplier_id, supplier_name 27 | FROM suppliers 28 | WHERE category_type = 'Hardware'; 29 | ``` 30 | 31 | This CREATE VIEW example would create a virtual table based on the result set of the SELECT statement. You can now query the MySQL VIEW as follows: 32 | 33 | ```sql 34 | SELECT * 35 | FROM hardware_suppliers; 36 | ``` 37 | 38 | ### Update VIEW 39 | 40 | You can modify the definition of a VIEW in MySQL without dropping it by using the ALTER VIEW statement. 41 | 42 | Syntax 43 | 44 | The syntax for the ALTER VIEW statement in MySQL is: 45 | ```sql 46 | ALTER VIEW view_name AS 47 | SELECT columns 48 | FROM table 49 | WHERE conditions; 50 | ``` 51 | 52 | Example 53 | 54 | Here is an example of how you would use the ALTER VIEW statement in MySQL: 55 | 56 | ```sql 57 | ALTER VIEW hardware_suppliers AS 58 | SELECT supplier_id, supplier_name, address, city 59 | FROM suppliers 60 | WHERE category_type = 'Hardware'; 61 | ``` 62 | 63 | This ALTER VIEW example in MySQL would update the definition of the VIEW called hardware_suppliers without dropping it. In this example, we are adding the address and city columns to the VIEW. 64 | 65 | ### Drop VIEW 66 | 67 | Once a VIEW has been created in MySQL, you can drop it with the DROP VIEW statement. 68 | 69 | Syntax 70 | 71 | The syntax for the DROP VIEW statement in MySQL is: 72 | ```sql 73 | DROP VIEW [IF EXISTS] view_name; 74 | view_name 75 | ``` 76 | 77 | The name of the view that you wish to drop. 78 | #### IF EXISTS 79 | Optional. If you do not specify this clause and the VIEW does not exist, the DROP VIEW statement will return an error. 80 | Example 81 | 82 | Here is an example of how to use the DROP VIEW statement in MySQL: 83 | ```sql 84 | DROP VIEW hardware_suppliers; 85 | ``` 86 | 87 | This DROP VIEW example would drop/delete the MySQL VIEW called hardware_suppliers. 88 | 89 | 90 | ## Exercises: 91 | 92 | 1. Create a view named **list_of_customers**, it should contain the following columns: 93 | - customer id 94 | - customer full name, 95 | - address 96 | - zip code 97 | - phone 98 | - city 99 | - country 100 | - status (when active column is 1 show it as 'active', otherwise is 'inactive') 101 | - store id 102 | 103 | 2. Create a view named **film_details**, it should contain the following columns: 104 | film id, title, description, category, price, length, rating, actors - as a string of all the actors separated by comma. Hint use GROUP_CONCAT 105 | 106 | 3. Create view **sales_by_film_category**, it should return 'category' and 'total_rental' columns. 107 | 108 | 4. Create a view called **actor_information** where it should return, actor id, first name, last name and the amount of films he/she acted on. 109 | 110 | 5. Analyze view **actor_info**, explain the entire query and specially how the sub query works. Be very specific, take some time and decompose each part and give an explanation for each. 111 | 112 | 6. Materialized views, write a description, why they are used, alternatives, DBMS were they exist, etc. -------------------------------------------------------------------------------- /classes/class_16.md: -------------------------------------------------------------------------------- 1 | ## Constraints and Triggers 2 | 3 | - [Constraints](class_16_1.md) 4 | - [Triggers](class_16_2.md) 5 | 6 | 7 | ## Exercises 8 | Needs the **employee** table (defined in the [triggers](class_16_2.md) section) created and populated. 9 | 10 | 1- Insert a new employee to , but with an null email. Explain what happens. 11 | 12 | 2- Run the first the query 13 | 14 | ```sql 15 | UPDATE employees SET employeeNumber = employeeNumber - 20 16 | ``` 17 | What did happen? Explain. 18 | Then run this other 19 | ```sql 20 | UPDATE employees SET employeeNumber = employeeNumber + 20 21 | ``` 22 | Explain this case also. 23 | 24 | 3- Add a age column to the table employee where and it can only accept values from 16 up to 70 years old. 25 | 26 | 4- Describe the *referential integrity* between tables film, actor and film_actor in sakila db. 27 | 28 | 5- Create a new column called **lastUpdate** to table employee and use trigger(s) to keep the date-time updated on inserts and updates operations. **Bonus**: add a column **lastUpdateUser** and the respective trigger(s) to specify who was the last MySQL user that changed the row (assume multiple users, other than root, can connect to MySQL and change this table). 29 | 30 | 6- Find all the triggers in sakila db related to loading film_text table. What do they do? Explain each of them using its source code for the explanation. 31 | -------------------------------------------------------------------------------- /classes/class_16_1.md: -------------------------------------------------------------------------------- 1 | ### SQL Constraints 2 | Constraints are the rules enforced on data columns on a table. These are used to limit the type of data that can go into a table. This ensures the accuracy and reliability of the data in the database. 3 | 4 | Constraints can either be column level or table level. Column level constraints are applied only to one column whereas, table level constraints are applied to the entire table. 5 | 6 | #### NOT NULL Constraint − Ensures that a column cannot have NULL value. 7 | 8 | By default, a column can hold NULL values. If you do not want a column to have a NULL value, then you need to define such a constraint on this column specifying that NULL is now not allowed for that column. 9 | 10 | A NULL is not the same as no data, rather, it represents unknown data. 11 | 12 | #### Example 13 | For example, the following SQL query creates a new table called CUSTOMERS and adds five columns, three of which, are ID NAME and AGE, In this we specify not to accept NULLs − 14 | 15 | ```sql 16 | CREATE TABLE CUSTOMERS( 17 | ID INT NOT NULL, 18 | NAME VARCHAR (20) NOT NULL, 19 | AGE INT NOT NULL, 20 | ADDRESS CHAR (25) , 21 | SALARY DECIMAL (18, 2), 22 | PRIMARY KEY (ID) 23 | ); 24 | ``` 25 | 26 | If CUSTOMERS table has already been created, then to add a NOT NULL constraint to the SALARY column, you would write a query like the one that is shown in the following code block. 27 | 28 | ```sql 29 | ALTER TABLE CUSTOMERS 30 | MODIFY SALARY DECIMAL (18, 2) NOT NULL; 31 | ``` 32 | #### DEFAULT Constraint − Provides a default value for a column when none is specified. 33 | 34 | The DEFAULT constraint provides a default value to a column when the INSERT INTO statement does not provide a specific value. 35 | 36 | ##### Example 37 | For example, the following SQL creates a new table called CUSTOMERS and adds five columns. Here, the SALARY column is set to 5000.00 by default, so in case the INSERT INTO statement does not provide a value for this column, then by default this column would be set to 5000.00. 38 | 39 | ```sql 40 | CREATE TABLE CUSTOMERS( 41 | ID INT NOT NULL, 42 | NAME VARCHAR (20) NOT NULL, 43 | AGE INT NOT NULL, 44 | ADDRESS CHAR (25) , 45 | SALARY DECIMAL (18, 2) DEFAULT 5000.00, 46 | PRIMARY KEY (ID) 47 | ); 48 | ``` 49 | If the CUSTOMERS table has already been created, then to add a DEFAULT constraint to the SALARY column, you would write a query like the one which is shown in the code block below. 50 | 51 | ```sql 52 | ALTER TABLE CUSTOMERS 53 | MODIFY SALARY DECIMAL (18, 2) DEFAULT 5000.00; 54 | ``` 55 | ##### Drop Default Constraint 56 | To drop a DEFAULT constraint, use the following SQL query. 57 | ```sql 58 | ALTER TABLE CUSTOMERS 59 | ALTER COLUMN SALARY DROP DEFAULT; 60 | ``` 61 | #### UNIQUE Constraint − Ensures that all values in a column are different. 62 | 63 | The UNIQUE Constraint prevents two records from having identical values in a column. In the CUSTOMERS table, for example, you might want to prevent two or more people from having an identical age. 64 | 65 | ##### Example 66 | For example, the following SQL query creates a new table called CUSTOMERS and adds five columns. Here, the AGE column is set to UNIQUE, so that you cannot have two records with the same age. 67 | 68 | ```sql 69 | CREATE TABLE CUSTOMERS( 70 | ID INT NOT NULL, 71 | NAME VARCHAR (20) NOT NULL, 72 | AGE INT NOT NULL UNIQUE, 73 | ADDRESS CHAR (25) , 74 | SALARY DECIMAL (18, 2), 75 | PRIMARY KEY (ID) 76 | ); 77 | ``` 78 | If the CUSTOMERS table has already been created, then to add a UNIQUE constraint to the AGE column. You would write a statement like the query that is given in the code block below. 79 | 80 | ```sql 81 | ALTER TABLE CUSTOMERS 82 | MODIFY AGE INT NOT NULL UNIQUE; 83 | ``` 84 | You can also use the following syntax, which supports naming the constraint in multiple columns as well. 85 | ```sql 86 | ALTER TABLE CUSTOMERS 87 | ADD CONSTRAINT myUniqueConstraint UNIQUE(AGE, SALARY); 88 | ```` 89 | ##### DROP a UNIQUE Constraint 90 | To drop a UNIQUE constraint, use the following SQL query. 91 | 92 | ```sql 93 | ALTER TABLE CUSTOMERS 94 | DROP CONSTRAINT myUniqueConstraint; 95 | ``` 96 | If you are using MySQL, then you can use the following syntax − 97 | ```sql 98 | ALTER TABLE CUSTOMERS 99 | DROP INDEX myUniqueConstraint; 100 | ``` 101 | #### PRIMARY Key − Uniquely identifies each row/record in a database table. 102 | 103 | A primary key is a field in a table which uniquely identifies each row/record in a database table. Primary keys must contain unique values. A primary key column cannot have NULL values. 104 | 105 | A table can have only one primary key, which may consist of single or multiple fields. When multiple fields are used as a primary key, they are called a composite key. 106 | 107 | If a table has a primary key defined on any field(s), then you cannot have two records having the same value of that field(s). 108 | 109 | Note − You would use these concepts while creating database tables. 110 | 111 | ##### Create Primary Key 112 | Here is the syntax to define the ID attribute as a primary key in a CUSTOMERS table. 113 | 114 | ```sql 115 | CREATE TABLE CUSTOMERS( 116 | ID INT NOT NULL, 117 | NAME VARCHAR (20) NOT NULL, 118 | AGE INT NOT NULL, 119 | ADDRESS CHAR (25) , 120 | SALARY DECIMAL (18, 2), 121 | PRIMARY KEY (ID) 122 | ); 123 | ``` 124 | To create a PRIMARY KEY constraint on the "ID" column when the CUSTOMERS table already exists, use the following SQL syntax − 125 | 126 | ALTER TABLE CUSTOMER ADD PRIMARY KEY (ID); 127 | NOTE − If you use the ALTER TABLE statement to add a primary key, the primary key column(s) should have already been declared to not contain NULL values (when the table was first created). 128 | 129 | For defining a PRIMARY KEY constraint on multiple columns, use the SQL syntax given below. 130 | 131 | ```sql 132 | CREATE TABLE CUSTOMERS( 133 | ID INT NOT NULL, 134 | NAME VARCHAR (20) NOT NULL, 135 | AGE INT NOT NULL, 136 | ADDRESS CHAR (25) , 137 | SALARY DECIMAL (18, 2), 138 | PRIMARY KEY (ID, NAME) 139 | ); 140 | ``` 141 | To create a PRIMARY KEY constraint on the "ID" and "NAMES" columns when CUSTOMERS table already exists, use the following SQL syntax. 142 | 143 | ```sql 144 | ALTER TABLE CUSTOMERS 145 | ADD CONSTRAINT PK_CUSTID PRIMARY KEY (ID, NAME); 146 | ``` 147 | ##### Delete Primary Key 148 | You can clear the primary key constraints from the table with the syntax given below. 149 | ```sql 150 | ALTER TABLE CUSTOMERS DROP PRIMARY KEY ; 151 | ``` 152 | #### FOREIGN Key − Uniquely identifies a row/record in any of the given database table. 153 | 154 | A foreign key is a key used to link two tables together. This is sometimes also called as a referencing key. 155 | 156 | A Foreign Key is a column or a combination of columns whose values match a Primary Key in a different table. 157 | 158 | The relationship between 2 tables matches the Primary Key in one of the tables with a Foreign Key in the second table. 159 | 160 | If a table has a primary key defined on any field(s), then you cannot have two records having the same value of that field(s). 161 | 162 | ##### Example 163 | Consider the structure of the following two tables. 164 | 165 | CUSTOMERS table 166 | 167 | ```sql 168 | CREATE TABLE CUSTOMERS( 169 | ID INT NOT NULL, 170 | NAME VARCHAR (20) NOT NULL, 171 | AGE INT NOT NULL, 172 | ADDRESS CHAR (25) , 173 | SALARY DECIMAL (18, 2), 174 | PRIMARY KEY (ID) 175 | ); 176 | ``` 177 | 178 | ORDERS table 179 | 180 | ```sql 181 | CREATE TABLE ORDERS ( 182 | ID INT NOT NULL, 183 | DATE DATETIME, 184 | CUSTOMER_ID INT references CUSTOMERS(ID), 185 | AMOUNT double, 186 | PRIMARY KEY (ID) 187 | ); 188 | ``` 189 | If the ORDERS table has already been created and the foreign key has not yet been set, the use the syntax for specifying a foreign key by altering a table. 190 | ```sql 191 | ALTER TABLE ORDERS 192 | ADD FOREIGN KEY (Customer_ID) REFERENCES CUSTOMERS (ID); 193 | ``` 194 | ##### DROP a FOREIGN KEY Constraint 195 | To drop a FOREIGN KEY constraint, use the following SQL syntax. 196 | 197 | ```sql 198 | ALTER TABLE ORDERS 199 | DROP FOREIGN KEY; 200 | ``` 201 | #### CHECK Constraint − The CHECK constraint ensures that all the values in a column satisfies certain conditions. 202 | 203 | The CHECK Constraint enables a condition to check the value being entered into a record. If the condition evaluates to false, the record violates the constraint and isn't entered the table. 204 | 205 | ##### Example 206 | For example, the following program creates a new table called CUSTOMERS and adds five columns. Here, we add a CHECK with AGE column, so that you cannot have any CUSTOMER who is below 18 years. 207 | 208 | ```sql 209 | CREATE TABLE CUSTOMERS( 210 | ID INT NOT NULL, 211 | NAME VARCHAR (20) NOT NULL, 212 | AGE INT NOT NULL CHECK (AGE >= 18), 213 | ADDRESS CHAR (25) , 214 | SALARY DECIMAL (18, 2), 215 | PRIMARY KEY (ID) 216 | ); 217 | ``` 218 | If the CUSTOMERS table has already been created, then to add a CHECK constraint to AGE column, you would write a statement like the one given below. 219 | 220 | ```sql 221 | ALTER TABLE CUSTOMERS 222 | MODIFY AGE INT NOT NULL CHECK (AGE >= 18 ); 223 | ``` 224 | You can also use the following syntax, which supports naming the constraint in multiple columns as well − 225 | 226 | ```sql 227 | ALTER TABLE CUSTOMERS 228 | ADD CONSTRAINT myCheckConstraint CHECK(AGE >= 18); 229 | ``` 230 | ##### DROP a CHECK Constraint 231 | To drop a CHECK constraint, use the following SQL syntax. This syntax does not work with MySQL. 232 | 233 | ```sql 234 | ALTER TABLE CUSTOMERS 235 | DROP CONSTRAINT myCheckConstraint; 236 | ``` -------------------------------------------------------------------------------- /classes/class_16_2.md: -------------------------------------------------------------------------------- 1 | ## Triggers 2 | 3 | A SQL trigger is a set of SQL statements stored in the database catalog. A SQL trigger is executed or fired whenever an event associated with a table occurs e.g., insert, update or delete. 4 | 5 | A SQL trigger is a special type of stored procedure. It is special because it is not called directly like a stored procedure. The main difference between a trigger and a stored procedure is that a trigger is called automatically when a data modification event is made against a table whereas a stored procedure must be called explicitly. 6 | 7 | It is important to understand SQL trigger’s advantages and disadvantages so that you can use it appropriately. In the following sections, we will discuss the advantages and disadvantages of using SQL triggers. 8 | 9 | ### Advantages of using SQL triggers 10 | 11 | * SQL triggers provide an alternative way to check the integrity of data. 12 | * SQL triggers can catch errors in business logic in the database layer. 13 | * SQL triggers provide an alternative way to run scheduled tasks. By using SQL triggers, you don’t have to wait to run the scheduled tasks because the triggers are invoked automatically before or after a change is made to the data in the tables. 14 | * SQL triggers are very useful to audit the changes of data in tables. 15 | 16 | ### Disadvantages of using SQL triggers 17 | 18 | * SQL triggers only can provide an extended validation and they cannot replace all the validations. Some simple validations have to be done in the application layer. For example, you can validate user’s inputs in the client side by using JavaScript or in the server side using server-side scripting languages such as JSP, PHP, ASP.NET, Perl, etc. 19 | * SQL triggers are invoked and executed invisible from the client applications, therefore, it is difficult to figure out what happen in the database layer. 20 | * SQL triggers may increase the overhead of the database server. 21 | 22 | 23 | ## MySQL triggers 24 | 25 | In MySQL, a trigger is a set of SQL statements that is invoked automatically when a change is made to the data on the associated table. A trigger can be defined to be invoked either before or after the data is changed by INSERT, UPDATE or DELETE statement. Before MySQL version 5.7.2, you can to define maximum six triggers for each table. 26 | 27 | 28 | * **BEFORE INSERT** – activated before data is inserted into the table. 29 | * **AFTER INSERT** – activated after data is inserted into the table. 30 | * **BEFORE UPDATE** – activated before data in the table is updated. 31 | * **AFTER UPDATE** – activated after data in the table is updated. 32 | * **BEFORE DELETE** – activated before data is removed from the table. 33 | * **AFTER DELETE** – activated after data is removed from the table. 34 | 35 | 36 | However, from MySQL version 5.7.2+, you can define multiple triggers for the same trigger event and action time. 37 | 38 | When you use a statement that does not use INSERT, DELETE or UPDATE statement to change data in a table, the triggers associated with the table are not invoked. For example, the TRUNCATE statement removes all data of a table but does not invoke the trigger associated with that table. 39 | 40 | There are some statements that use the INSERT statement behind the scenes such as REPLACE statement or LOAD DATA statement. If you use these statements, the corresponding triggers associated with the table are invoked. 41 | 42 | You must use a unique name for each trigger associated with a table. However, you can have the same trigger name defined for different tables though it is a good practice. 43 | 44 | You should name the triggers using the following naming convention: 45 | 46 | ``` 47 | (BEFORE | AFTER)_tableName_(INSERT| UPDATE | DELETE) 48 | ``` 49 | 50 | For example, before_order_update is a trigger invoked before a row in the order table is updated. 51 | 52 | The following naming convention is as good as the one above. 53 | 54 | ``` 55 | tablename_(BEFORE | AFTER)_(INSERT| UPDATE | DELETE) 56 | ``` 57 | 58 | For example, **order_before_update ** is the same as before_update_update trigger above. 59 | 60 | ### MySQL trigger limitations 61 | 62 | MySQL triggers cover all features defined in the standard SQL. However, there are some limitations that you should know before using them in your applications. 63 | 64 | MySQL triggers cannot: 65 | 66 | * Use SHOW, LOAD DATA, LOAD TABLE, BACKUP DATABASE, RESTORE, FLUSH and RETURN statements. 67 | * Use statements that commit or rollback implicitly or explicitly such as COMMIT , ROLLBACK , START TRANSACTION , LOCK/UNLOCK TABLES , ALTER , CREATE , DROP , RENAME , etc. 68 | * Use prepared statements such as PREPARE, EXECUTE, etc. 69 | * Use dynamic SQL statements. 70 | 71 | From MySQL version 5.1.4, a trigger can call a stored procedure or stored function, which was a limitation is the previous versions. 72 | 73 | ### MySQL trigger syntax 74 | 75 | In order to create a new trigger, you use the CREATE TRIGGER statement. The following illustrates the syntax of the CREATE TRIGGER statement: 76 | 77 | ```sql 78 | CREATE TRIGGER trigger_name trigger_time trigger_event 79 | ON table_name 80 | FOR EACH ROW 81 | BEGIN 82 | ... 83 | END; 84 | ``` 85 | Let’s examine the syntax above in more detail. 86 | 87 | You put the trigger name after the CREATE TRIGGER statement. The trigger name should follow the naming convention [trigger time]_[table name]_[trigger event], for example before_employees_update. 88 | 89 | Trigger activation time can be BEFORE or AFTER. You must specify the activation time when you define a trigger. You use the BEFORE keyword if you want to process action prior to the change is made on the table and AFTER if you need to process action after the change is made. 90 | 91 | The trigger event can be INSERT, UPDATE or DELETE. This event causes the trigger to be invoked. A trigger only can be invoked by one event. To define a trigger that is invoked by multiple events, you have to define multiple triggers, one for each event. 92 | A trigger must be associated with a specific table. Without a table trigger would not exist therefore you have to specify the table name after the ON keyword. 93 | You place the SQL statements between BEGIN and END block. This is where you define the logic for the trigger. 94 | 95 | ### MySQL trigger example 96 | 97 | Let’s start creating a trigger in MySQL to log the changes of the employees table. 98 | 99 | ```sql 100 | CREATE TABLE `employees` ( 101 | `employeeNumber` int(11) NOT NULL, 102 | `lastName` varchar(50) NOT NULL, 103 | `firstName` varchar(50) NOT NULL, 104 | `extension` varchar(10) NOT NULL, 105 | `email` varchar(100) NOT NULL, 106 | `officeCode` varchar(10) NOT NULL, 107 | `reportsTo` int(11) DEFAULT NULL, 108 | `jobTitle` varchar(50) NOT NULL, 109 | PRIMARY KEY (`employeeNumber`) 110 | ); 111 | ``` 112 | ```sql 113 | insert into `employees`(`employeeNumber`,`lastName`,`firstName`,`extension`,`email`,`officeCode`,`reportsTo`,`jobTitle`) values 114 | 115 | (1002,'Murphy','Diane','x5800','dmurphy@classicmodelcars.com','1',NULL,'President'), 116 | 117 | (1056,'Patterson','Mary','x4611','mpatterso@classicmodelcars.com','1',1002,'VP Sales'), 118 | 119 | (1076,'Firrelli','Jeff','x9273','jfirrelli@classicmodelcars.com','1',1002,'VP Marketing'); 120 | 121 | ``` 122 | 123 | First, create a new table named **employees_audit** to keep the changes of the employee table. The following statement creates the employee_audit table. 124 | 125 | ```sql 126 | CREATE TABLE employees_audit ( 127 | id INT AUTO_INCREMENT PRIMARY KEY, 128 | employeeNumber INT NOT NULL, 129 | lastname VARCHAR(50) NOT NULL, 130 | changedat DATETIME DEFAULT NULL, 131 | action VARCHAR(50) DEFAULT NULL 132 | ); 133 | ``` 134 | 135 | Next, create a BEFORE UPDATE trigger that is invoked before a change is made to the employees table. 136 | 137 | ```sql 138 | DELIMITER $$ 139 | CREATE TRIGGER before_employee_update 140 | BEFORE UPDATE ON employees 141 | FOR EACH ROW 142 | BEGIN 143 | INSERT INTO employees_audit 144 | SET action = 'update', 145 | employeeNumber = OLD.employeeNumber, 146 | lastname = OLD.lastname, 147 | changedat = NOW(); 148 | END$$ 149 | DELIMITER ; 150 | ``` 151 | 152 | Inside the body of the trigger, we used the OLD keyword to access employeeNumber and lastname column of the row affected by the trigger. 153 | 154 | Notice that in a trigger defined for INSERT, you can use NEW keyword only. You cannot use the OLD keyword. However, in the trigger defined for DELETE, there is no new row so you can use the OLD keyword only. In the UPDATE trigger, OLD refers to the row before it is updated and NEW refers to the row after it is updated. 155 | 156 | After that, update the employees table to check whether the trigger is invoked. 157 | 158 | ```sql 159 | UPDATE employees 160 | SET 161 | lastName = 'Phan' 162 | WHERE 163 | employeeNumber = 1056; 164 | ``` 165 | 166 | Finally, to check if the trigger was invoked by the UPDATE statement, you can query the employees_audit table using the following query: 167 | 168 | ```sql 169 | SELECT 170 | * 171 | FROM 172 | employees_audit; 173 | ``` 174 | 175 | it should show data that reflects the trigger was actually invoked. -------------------------------------------------------------------------------- /classes/class_17.md: -------------------------------------------------------------------------------- 1 | ### [Indexes](class_17_1.md) 2 | 3 | ### [MySQL Full-Text Search](class_17_2.md) 4 | This is a nice feature to take into account. 5 | 6 | #### Exercises 7 | For all the exercises include the queries in the class file. 8 | 9 | 1. Create two or three queries using **address** table in sakila db: 10 | * include **postal_code** in where (try with in/not it operator) 11 | * eventually join the table with city/country tables. 12 | * measure execution time. 13 | * Then create an index for **postal_code** on **address** table. 14 | * measure execution time again and compare with the previous ones. 15 | * Explain the results 16 | 17 | 2. Run queries using **actor** table, searching for first and last name columns independently. Explain the differences and why is that happening? 18 | 19 | 3. Compare results finding text in the description on table film with **LIKE** and in the film_text using **MATCH** ... **AGAINST**. Explain the results. -------------------------------------------------------------------------------- /classes/class_17_1.md: -------------------------------------------------------------------------------- 1 | ## Indexes 2 | 3 | A database index, or just index, helps speed up the retrieval of data from tables. When you query data from a table, first MySQL checks if the indexes exist, then MySQL uses the indexes to select exact physical corresponding rows of the table instead of scanning the whole table. 4 | 5 | A database index is similar to an index of a book. If you want to find a topic, you look up in the index first, and then you open the page that has the topic without scanning the whole book. 6 | 7 | It is highly recommended that you create indices on columns of a table from which you often query the data. Notice that all primary key columns are in the primary index of the table automatically. 8 | 9 | If index helps speed up the querying data, why don’t we use indexes for all columns? If you create an index for every column, MySQL has to build and maintain the index table. Whenever a change is made to the rows of the table, MySQL has to rebuild the index, which takes time as well as decreases the performance of the database server. 10 | 11 | ### Creating MySQL Index 12 | 13 | You often create indexes when you create tables. MySQL automatically adds any column that is declared as **PRIMARY KEY**, **KEY** , **UNIQUE** or **INDEX** to the index. In addition, you can add indexes to the tables that already have data. 14 | 15 | In order to create indexes, you use the **CREATE INDEX** statement. The following illustrates the syntax of the **CREATE INDEX** statement: 16 | ```sql 17 | CREATE [UNIQUE | FULLTEXT | SPATIAL] INDEX index_name 18 | [ USING BTREE | HASH ] 19 | ON table_name 20 | (index_col1 [(length)] [ASC | DESC], 21 | index_col2 [(length)] [ASC | DESC], 22 | ... 23 | index_col_n [(length)] [ASC | DESC]); 24 | ``` 25 | ##### UNIQUE 26 | Optional. The UNIQUE modifier indicates that the combination of values in the indexed columns must be unique. 27 | ##### FULLTEXT 28 | Optional. The FULLTEXT modifier indexes the entire column and does not allow prefixing. InnoDB and MyISAM tables support this option. 29 | ##### SPATIAL 30 | Optional. The SPATIAL modifier indexes the entire column and does not allow indexed columns to contain NULL values. InnoDB (starting in MySQL 5.7) and MyISAM tables support this option. 31 | ##### index_name 32 | The name to assign to the index. 33 | ##### table_name 34 | The name of the table in which to create the index. 35 | index_col1, index_col2, ... index_col_n 36 | The columns to use in the index. 37 | ##### length 38 | Optional. If specified, only a prefix of the column is indexed not the entire column. For non-binary string columns, this value is the given number of characters of the column to index. For binary string columns, this value is the given number of bytes of the column to index. 39 | 40 | ##### ASC 41 | Optional. The index is sorted in ascending order for that column. 42 | ##### DESC 43 | Optional. The index is sorted in descending order for that column. 44 | 45 | ### Example of creating index in MySQL 46 | 47 | In the sample database, you can add postalCode column of the customers table to the index by using the CREATE INDEX statement as follows: 48 | 49 | ```sql 50 | CREATE INDEX postalCode ON customers(postalCode); 51 | ``` 52 | 53 | ### Removing Indexes 54 | 55 | Besides creating an index, you can also remove index by using the DROP INDEX statement. Interestingly, the DROP INDEX statement is also mapped to ALTER TABLE statement. The following is the syntax of removing the index: 56 | 57 | ```sql 58 | DROP INDEX index_name ON table_name 59 | ``` 60 | 61 | For example, if you want to drop index postalCode of the employees table, which we have created above, you can execute the following query: 62 | 63 | ```sql 64 | DROP INDEX postalCode ON customers 65 | ``` -------------------------------------------------------------------------------- /classes/class_17_2.md: -------------------------------------------------------------------------------- 1 | ## MySQL Full-Text Search 2 | 3 | MySQL supports text searching by using the LIKE operator and regular expression. However, when the text column is large and the number of rows in a table is increased, using these methods has some limitations: 4 | 5 | * Performance: MySQL has to scan the whole table to find the exact text based on a pattern in the LIKE statement or pattern in the regular expressions. 6 | * Flexible search: with the LIKE operator and regular expression searches, it is difficult to have a flexible search query e.g., to find product whose description contains car but not classic. 7 | * Relevance ranking: there is no way to specify which row in the result set is more relevant to the search terms. 8 | * Because of these limitations, MySQL extended a very nice feature so-called full-text search. Technically, MySQL creates an index from the words of the enabled full-text search columns and performs searches on this index. MySQL uses a sophisticated algorithm to determine the rows matched against the search query. 9 | 10 | ##### The following are some important features of MySQL full-text search: 11 | 12 | * Native SQL-like interface: you use the SQL-like statement to use the full-text search. 13 | * Fully dynamic index: MySQL automatically updates the index of text column whenever the data of that column changes. 14 | * Moderate index size: it doesn’t take much memory to store the index. 15 | * Last but not least, it is fast to search based on complex search queries. 16 | * Notice that not all storage engines support the full-text search feature. In MySQL version 5.6 or later, only MyISAM and InnoDB storage engines support full-text search. 17 | 18 | 19 | ## Defining FULLTEXT Indexes for MySQL Full-Text Searching 20 | 21 | Before performing a full-text search in a column of a table, you must index its data. MySQL will recreate the full-text index whenever the data of the column changes. In MySQL, the full-text index is a kind of index that has a name FULLTEXT. 22 | 23 | MySQL supports indexing and re-indexing data automatically for a full-text search enabled column. MySQL version 5.6 or later allows you to define a full-text index for a column whose data type is CHAR, VARCHAR or TEXT in MyISAM or InnoDB table type. Notice that MySQL supported full-text index in the InnoDB tables since version 5.6. 24 | 25 | MySQL allows you to define the FULLTEXT index by using the CREATE TABLE statement when you create the table or ALTER TABLE or CREATE INDEX statement for the existing tables. 26 | 27 | #### Defining FULLTEXT index using CREATE TABLE statement 28 | 29 | Typically, you define the FULLTEXT index for a column when you create a new table using the CREATE TABLE statement as follows: 30 | 31 | ```sql 32 | CREATE TABLE table_name( 33 | column1 data_type, 34 | column2 data_type, 35 | column3 data_type, 36 | … 37 | PRIMARY_KEY(key_column), 38 | FULLTEXT (column1,column2,..) 39 | ); 40 | ``` 41 | 42 | To create the FULLTEXT index, you place a list of comma-separated columns in parentheses after the FULLTEXT keyword. 43 | 44 | The following statement creates a new table named posts that has a FULLTEXT index that includes the post_content column. 45 | 46 | ``` 47 | CREATE TABLE posts ( 48 | id int(4) NOT NULL AUTO_INCREMENT, 49 | title varchar(255) NOT NULL, 50 | post_content text, 51 | PRIMARY KEY (id), 52 | FULLTEXT KEY post_content (post_content) 53 | ); 54 | ``` 55 | 56 | ### Defining FULLTEXT index for existing tables 57 | 58 | In case you already have existing tables and want to define full-text indexes, you can use the ALTER TABLE statement or CREATE INDEX statement. 59 | 60 | ### Defining FULLTEXT index using ALTER TABLE statement 61 | 62 | The following syntax defines a FULLTEXT index using the ALTER TABLE statement: 63 | 64 | ```sql 65 | ALTER TABLE table_name 66 | ADD FULLTEXT(column_name1, column_name2,…) 67 | ``` 68 | 69 | You put the table_name is the ADD FULLTEXT clause that defines a FULLTEXT index for one or more columns. 70 | 71 | For example, you can define a FULLTEXT index for the productDescription and productLine columns in the products table of the sample database as follows: 72 | 73 | ```sql 74 | ALTER TABLE products 75 | ADD FULLTEXT(productDescription,productLine) 76 | ``` 77 | 78 | ### Defining FULLTEXT index using CREATE INDEX statement 79 | 80 | You can also use the CREATE INDEX statement to create a FULLTEXT index for existing tables. See the following syntax: 81 | 82 | ```sql 83 | CREATE FULLTEXT INDEX index_name 84 | ON table_name(idx_column_name,...) 85 | ``` 86 | 87 | The following statement creates a FULLTEXT index for the addressLine1 and addressLine2 columns of the offices table. 88 | 89 | ```sql 90 | CREATE FULLTEXT INDEX address 91 | ON offices(addressLine1,addressLine2) 92 | ``` 93 | 94 | Notice that for a table which has many rows, it is faster to load the data into the table that has no FULLTEXT index first and then create the FULLTEXT index, than loading a large amount of data into a table that has an existing FULLTEXT index. 95 | 96 | ### Removing full-text search columns 97 | 98 | To remove a FULLTEXT index, you just delete the index using the ALTER TABLE … DROP INDEX statement. For example, the following statement removes the address FULLTEXT index in the offices table: 99 | 100 | ```sql 101 | ALTER TABLE offices 102 | DROP INDEX address; 103 | ``` 104 | 105 | ### MySQL natural language full-text search example 106 | 107 | We will use the products table in the sample database for the demonstration. 108 | 109 | 110 | First, you need to enable full-text search in the productLine column of the products table using the ALTER TABLE ADD FULLTEXT statement: 111 | 112 | ```sql 113 | ALTER TABLE products 114 | ADD FULLTEXT(productline); 115 | ``` 116 | 117 | Second, you can search for products whose product lines contain the term Classic . You use the MATCH() and AGAINST() functions as the following query: 118 | 119 | ``` 120 | SELECT productName, productline 121 | FROM products 122 | WHERE MATCH(productline) AGAINST('Classic'); 123 | ``` 124 | 125 | To search for product whose product line contains Classic or Vintage term, you can perform the following query: 126 | 127 | ```sql 128 | SELECT productName, productline 129 | FROM products 130 | WHERE MATCH(productline) AGAINST('Classic,Vintage'); 131 | ``` 132 | 133 | The AGAINST() function uses IN NATURAL LANGUAGE MODE search modifier by default therefore you can omit it in the query. There are other search modifiers e.g., IN BOOLEAN MODE for Boolean text searches. 134 | 135 | You can explicitly use the IN NATURAL LANGUAGE MODE search modifier in your query as follows: 136 | 137 | ```sql 138 | SELECT productName, productline 139 | FROM products 140 | WHERE MATCH(productline) 141 | AGAINST('Classic,Vintage' IN NATURAL LANGUAGE MODE) 142 | ``` 143 | 144 | By default, MySQL performs searches in the case-insensitive fashion. However, you can instruct MySQL to perform case-sensitive searches using binary collation for indexed columns. 145 | 146 | ### Sort the result set by relevance 147 | 148 | A very important feature of full-text search is how MySQL ranks the rows in the result set based on their relevance. When the MATCH() function is used in the WHERE clause, MySQL returns the rows that are more relevant first. 149 | 150 | The following example shows you how MySQL sorts the result set by the relevance. 151 | 152 | First, you enable the full-text search feature for the productName column of the products table. 153 | 154 | ```sql 155 | ALTER TABLE products 156 | ADD FULLTEXT(productName); 157 | ``` 158 | 159 | Second, you search for products whose names contain Ford and/or 1932 using the following query: 160 | 161 | ```sql 162 | SELECT productName, productline 163 | FROM products 164 | WHERE MATCH(productName) AGAINST('1932,Ford') 165 | ``` 166 | 167 | The products, whose names contain both 1932 and Ford are returned first and then the products whose names contains the only Ford keyword. 168 | -------------------------------------------------------------------------------- /classes/class_18.md: -------------------------------------------------------------------------------- 1 | # Definition of stored procedures 2 | 3 | A stored procedure is a segment of declarative SQL statements stored inside the database catalog. A stored procedure can be invoked by triggers, other stored procedures, and applications such as Java, Python, PHP, etc. 4 | 5 | ![mysql-stored-procedure1](../images/mysql-stored-procedure1.jpg) 6 | 7 | A stored procedure that calls itself is known as a recursive stored procedure. Most database management systems support recursive stored procedures. However, MySQL does not support it very well. You should check your version of MySQL database before implementing recursive stored procedures in MySQL. 8 | 9 | # Stored Procedures in MySQL 10 | 11 | MySQL is known as the most popular open source RDBMS which is widely used by both community and enterprise. However, during the first decade of its existence, it did not support stored procedures, stored functions, triggers, and events. Since MySQL version 5.0, those features were added to MySQL database engine to make it more flexible and powerful. 12 | 13 | ## MySQL stored procedures advantages 14 | 15 | * Typically stored procedures help increase the performance of the applications. Once created, stored procedures are compiled and stored in the database. However, MySQL implements the stored procedures slightly different. MySQL stored procedures are compiled on demand. After compiling a stored procedure, MySQL puts it into a cache. And MySQL maintains its own stored procedure cache for every single connection. If an application uses a stored procedure multiple times in a single connection, the compiled version is used, otherwise, the stored procedure works like a query. 16 | * Stored procedures help reduce the traffic between application and database server because instead of sending multiple lengthy SQL statements, the application has to send only name and parameters of the stored procedure. 17 | * Stored procedures are reusable and transparent to any applications. Stored procedures expose the database interface to all applications so that developers don’t have to develop functions that are already supported in stored procedures. 18 | * Stored procedures are secure. The database administrator can grant appropriate permissions to applications that access stored procedures in the database without giving any permissions on the underlying database tables. 19 | * Besides those advantages, stored procedures have their own disadvantages, which you should be aware of before using them in your databases. 20 | 21 | ## MySQL stored procedures disadvantages 22 | 23 | * If you use a lot of stored procedures, the memory usage of every connection that is using those stored procedures will increase substantially. In addition, if you overuse a large number of logical operations inside store procedures, the CPU usage will also increase because the database server is not well-designed for logical operations. 24 | * Constructs of stored procedures make it more difficult to develop stored procedures that have complicated business logic. 25 | * It is difficult to debug stored procedures. Only a few database management systems allow you to debug stored procedures. Unfortunately, MySQL does not provide facilities for debugging stored procedures. 26 | * It is not easy to develop and maintain stored procedures. Developing and maintaining stored procedures are often required a specialized skill set that not all application developers possess. This may lead to problems in both application development and maintenance phases. 27 | 28 | MySQL stored procedures have their own advantages and disadvantages. When you develop applications, you should decide whether you should or should not use stored procedure based on the business requirements. 29 | 30 | 31 | # Getting Started with MySQL Stored Procedures 32 | 33 | ### Writing the first MySQL stored procedure 34 | 35 | We are going to develop a simple stored procedure named GetAllProducts() to help you get familiar with the syntax. The GetAllProducts() stored procedure selects all products from the products table. 36 | 37 | Launch the mysql client tool and type the following commands: 38 | ```sql 39 | DELIMITER // 40 | CREATE PROCEDURE GetAllProducts() 41 | BEGIN 42 | SELECT * FROM products; 43 | END // 44 | DELIMITER ; 45 | ``` 46 | 47 | Let’s examine the stored procedure in greater detail: 48 | 49 | * The first command is DELIMITER // , which is not related to the stored procedure syntax. The DELIMITER statement changes the standard delimiter which is semicolon ( ; ) to another. In this case, the delimiter is changed from the semicolon( ; ) to double-slashes // Why do we have to change the delimiter? Because we want to pass the stored procedure to the server as a whole rather than letting MySQL tool interpret each statement at a time. Following the END keyword, we use the delimiter // to indicate the end of the stored procedure. The last command ( DELIMITER; ) changes the delimiter back to the semicolon (;). 50 | * We use the **CREATE PROCEDURE** statement to create a new stored procedure. We specify the name of stored procedure after the **CREATE PROCEDURE** statement. In this case, the name of the stored procedure is GetAllProducts . We put the parentheses after the name of the stored procedure. 51 | * The section between **BEGIN** and **END** is called the body of the stored procedure. You put the declarative SQL statements in the body to handle business logic. In this stored procedure, we use a simple SELECT statement to query data from the products table. 52 | 53 | 54 | # Calling stored procedures 55 | 56 | In order to call a stored procedure, you use the following SQL command: 57 | 58 | ```sql 59 | CALL STORED_PROCEDURE_NAME(); 60 | ``` 61 | 62 | You use the CALL statement to call a stored procedure e.g., to call the GetAllProducts() stored procedure, you use the following statement: 63 | 64 | ```sql 65 | CALL GetAllProducts(); 66 | ``` 67 | 68 | If you execute the statement above, you will get all products in the products table. 69 | 70 | # MySQL Stored Procedure Variables 71 | 72 | A variable is a named data object whose value can change during the stored procedure execution. We typically use the variables in stored procedures to hold the immediate results. These variables are local to the stored procedure. 73 | 74 | You must declare a variable before you can use it. 75 | 76 | ### Declaring variables 77 | 78 | To declare a variable inside a stored procedure, you use the DECLARE statement as follows: 79 | 80 | ```sql 81 | DECLARE variable_name datatype(size) DEFAULT default_value; 82 | ``` 83 | 84 | Let’s examine the statement above in more detail: 85 | 86 | * First, you specify the variable name after the DECLARE keyword. The variable name must follow the naming rules of MySQL table column names. 87 | * Second, you specify the data type of the variable and its size. A variable can have any MySQL data types such as INT, VARCHAR , DATETIME , etc. 88 | * Third, when you declare a variable, its initial value is NULL. You can assign the variable a default value using the DEFAULT keyword. 89 | 90 | For example, we can declare a variable named total_sale with the data type INT and default value 0 as follows: 91 | 92 | ```sql 93 | DECLARE total_sale INT DEFAULT 0; 94 | ``` 95 | 96 | MySQL allows you to declare two or more variables that share the same data type using a single DECLARE statement as following: 97 | 98 | ```sql 99 | DECLARE x, y INT DEFAULT 0; 100 | ``` 101 | We declared two integer variables x and y, and set their default values to zero. 102 | 103 | ## Assigning variables 104 | 105 | Once you declared a variable, you can start using it. To assign a variable another value, you use the SET statement, for example: 106 | 107 | ```sql 108 | DECLARE total_count INT DEFAULT 0; 109 | SET total_count = 10; 110 | ``` 111 | 112 | The value of the total_count variable is 10 after the assignment. 113 | 114 | Besides the SET statement, you can use the SELECT INTO statement to assign the result of a query, which returns a scalar value, to a variable. See the following example: 115 | 116 | ```sql 117 | DECLARE total_products INT DEFAULT 0 118 | 119 | SELECT COUNT(*) INTO total_products 120 | FROM products 121 | ``` 122 | In the example above: 123 | 124 | * First, we declare a variable named total_products and initialize its value to 0. 125 | * Then, we used the SELECT INTO statement to assign the total_products variable the number of products that we selected from the products table in the sample database. 126 | 127 | ### Variables scope 128 | 129 | A variable has its own scope that defines its lifetime. If you declare a variable inside a stored procedure, it will be out of scope when the END statement of stored procedure reached. 130 | 131 | If you declare a variable inside BEGIN END block, it will be out of scope if the END is reached. You can declare two or more variables with the same name in different scopes because a variable is only effective in its own scope. However, declaring variables with the same name in different scopes is not good programming practice. 132 | 133 | A variable that begins with the @ sign is session variable. It is available and accessible until the session ends. 134 | 135 | # MySQL Stored Procedure Parameters 136 | 137 | Almost stored procedures that you develop require parameters. The parameters make the stored procedure more flexible and useful. In MySQL, a parameter has one of three modes: **IN**, **OUT**, or **INOUT**. 138 | 139 | * {+IN+} – is the default mode. When you define an IN parameter in a stored procedure, the calling program has to pass an argument to the stored procedure. In addition, the value of an IN parameter is protected. It means that even the value of the IN parameter is changed inside the stored procedure, its original value is retained after the stored procedure ends. In other words, the stored procedure only works on the copy of the IN parameter. 140 | * {+OUT+} – the value of an OUT parameter can be changed inside the stored procedure and its new value is passed back to the calling program. Notice that the stored procedure cannot access the initial value of the OUT parameter when it starts. 141 | * {+INOUT+} – an INOUT parameter is the combination of IN and OUT parameters. It means that the calling program may pass the argument, and the stored procedure can modify the INOUT parameter and pass the new value back to the calling program. 142 | 143 | The syntax of defining a parameter in the stored procedures is as follows: 144 | 145 | ```sql 146 | MODE param_name param_type(param_size) 147 | ``` 148 | 149 | * The MODE could be IN , OUT,,or INOUT , depending on the purpose of the parameter in the stored procedure. 150 | * The param_name is the name of the parameter. The name of the parameter must follow the naming rules of the column name in MySQL. 151 | * Followed the parameter name is its data type and size. Like a variable, the data type of the parameter can be any valid MySQL data type. 152 | 153 | Each parameter is separated by a comma (,) if the stored procedure has more than one parameter. 154 | 155 | Let’s practice with some examples to get a better understanding. We will use the tables in the sample database for the demonstration. 156 | 157 | ## MySQL stored procedure parameter examples 158 | 159 | #### The IN parameter example 160 | 161 | The following example illustrates how to use the IN parameter in the GetOfficeByCountry stored procedure that selects offices located in a particular country. 162 | 163 | ```sql 164 | DELIMITER // 165 | CREATE PROCEDURE GetOfficeByCountry(IN countryName VARCHAR(255)) 166 | BEGIN 167 | SELECT * 168 | FROM offices 169 | WHERE country = countryName; 170 | END // 171 | DELIMITER ; 172 | ```` 173 | 174 | The countryName is the IN parameter of the stored procedure. Inside the stored procedure, we select all offices that locate in the country specified by the countryName parameter. 175 | 176 | Suppose, we want to get all offices in the USA, we just need to pass a value (USA) to the stored procedure as follows: 177 | 178 | ```sql 179 | CALL GetOfficeByCountry('USA'); 180 | ``` 181 | 182 | To get all offices in France, we pass the France literal string to the GetOfficeByCountry stored procedure as follows: 183 | 184 | ```sql 185 | CALL GetOfficeByCountry('France') 186 | ``` 187 | 188 | 189 | ### The OUT parameter example 190 | 191 | The following stored procedure returns the number of orders by order status. It has two parameters: 192 | 193 | * orderStatus : the IN parameter that is the order status which we want to count the orders. 194 | * total : the OUT parameter that stores the number of orders for a specific order status. 195 | 196 | The following is the source code of the CountOrderByStatus stored procedure. 197 | 198 | ```sql 199 | DELIMITER $$ 200 | CREATE PROCEDURE CountOrderByStatus( 201 | IN orderStatus VARCHAR(25), 202 | OUT total INT) 203 | BEGIN 204 | SELECT count(orderNumber) 205 | INTO total 206 | FROM orders 207 | WHERE status = orderStatus; 208 | END$$ 209 | DELIMITER ; 210 | ``` 211 | 212 | To get the number of shipped orders, we call the CountOrderByStatus stored procedure and pass the order status as Shipped, and also pass an argument ( @total ) to get the return value. 213 | 214 | ```sql 215 | CALL CountOrderByStatus('Shipped',@total); 216 | SELECT @total; 217 | ``` 218 | 219 | To get the number of orders that are in process, we call the CountOrderByStatus stored procedure as follows: 220 | 221 | ```sql 222 | CALL CountOrderByStatus('in process',@total); 223 | SELECT @total AS total_in_process; 224 | ``` 225 | 226 | ## The INOUT parameter example 227 | 228 | The following example demonstrates how to use an INOUT parameter in the stored procedure. 229 | 230 | ```sql 231 | DELIMITER $$ 232 | CREATE PROCEDURE set_counter(INOUT count INT(4),IN inc INT(4)) 233 | BEGIN 234 | SET count = count + inc; 235 | END$$ 236 | DELIMITER ; 237 | ``` 238 | 239 | How it works. 240 | 241 | * The set_counter stored procedure accepts one INOUT parameter ( count ) and one IN parameter ( inc ). 242 | * Inside the stored procedure, we increase the counter ( count ) by the value of the inc parameter. 243 | 244 | See how we call the set_counter stored procedure: 245 | 246 | ```sql 247 | SET @counter = 1; 248 | CALL set_counter(@counter,1); -- 2 249 | CALL set_counter(@counter,1); -- 3 250 | CALL set_counter(@counter,5); -- 8 251 | SELECT @counter; -- 8 252 | ``` -------------------------------------------------------------------------------- /classes/class_18_1.md: -------------------------------------------------------------------------------- 1 | # MySQL Stored Procedures That Return Multiple Values 2 | 3 | 4 | MySQL stored function returns only one value. To develop stored programs that return multiple values, you need to use stored procedures with INOUT or OUT parameters. 5 | 6 | ## Stored procedures that return multiple values example 7 | 8 | Let’s take a look at the orders table in the sample database. 9 | 10 | The following stored procedure accepts customer number and returns the total number of orders that was shipped, canceled, resolved, and disputed. 11 | 12 | ```sql 13 | DELIMITER $$ 14 | 15 | CREATE PROCEDURE get_order_by_cust( 16 | IN cust_no INT, 17 | OUT shipped INT, 18 | OUT canceled INT, 19 | OUT resolved INT, 20 | OUT disputed INT) 21 | BEGIN 22 | -- shipped 23 | SELECT 24 | count(*) INTO shipped 25 | FROM 26 | orders 27 | WHERE 28 | customerNumber = cust_no 29 | AND status = 'Shipped'; 30 | 31 | -- canceled 32 | SELECT 33 | count(*) INTO canceled 34 | FROM 35 | orders 36 | WHERE 37 | customerNumber = cust_no 38 | AND status = 'Canceled'; 39 | 40 | -- resolved 41 | SELECT 42 | count(*) INTO resolved 43 | FROM 44 | orders 45 | WHERE 46 | customerNumber = cust_no 47 | AND status = 'Resolved'; 48 | 49 | -- disputed 50 | SELECT 51 | count(*) INTO disputed 52 | FROM 53 | orders 54 | WHERE 55 | customerNumber = cust_no 56 | AND status = 'Disputed'; 57 | 58 | END 59 | ``` 60 | 61 | In addition to the IN parameter, the stored procedure takes 4 additional OUT parameters: shipped, canceled, resolved, and disputed. Inside the stored procedure, you use a SELECT statement with the COUNT function to get the corresponding total of orders based on the order’s status and assign it to the respective parameter. 62 | 63 | To use the get_order_by_cust stored procedure, you pass customer number and four user-defined variables to get the out values. 64 | 65 | After executing the stored procedure, you use the SELECT statement to output the variable values. 66 | 67 | ```sql 68 | CALL get_order_by_cust(141,@shipped,@canceled,@resolved,@disputed); 69 | SELECT @shipped,@canceled,@resolved,@disputed; 70 | ``` 71 | 72 | # MySQL IF Statement 73 | 74 | 75 | The MySQL IF statement allows you to execute a set of SQL statements based on a certain condition or value of an expression. To form an expression in MySQL, you can combine literals, variables, operators, and even functions. An expression can return one of three values TRUE FALSE, or NULL. 76 | 77 | Note that there is an IF function that is different from the IF statement specified in this tutorial. 78 | 79 | ## MySQL IF statement syntax 80 | 81 | The following illustrates the syntax of the IF statement: 82 | 83 | ```sql 84 | IF expression THEN 85 | statements; 86 | END IF; 87 | ``` 88 | 89 | If the expression evaluates to TRUE , then the statements will be executed, otherwise, the control is passed to the next statement following the END IF. 90 | 91 | ## MySQL IF ELSE statement 92 | 93 | In case you want to execute statements when the expression evaluates to FALSE , you use the IF ELSE statement as follows: 94 | 95 | ```sql 96 | IF expression THEN 97 | statements; 98 | ELSE 99 | else-statements; 100 | END IF; 101 | ``` 102 | 103 | ## MySQL IF ELSEIF ELSE statement 104 | 105 | If you want to execute statements conditionally based on multiple expressions, you use the IF ELSEIF ELSE statement as follows: 106 | 107 | ```sql 108 | IF expression THEN 109 | statements; 110 | ELSEIF elseif-expression THEN 111 | elseif-statements; 112 | ... 113 | ELSE 114 | else-statements; 115 | END IF; 116 | ``` 117 | 118 | If the expression evaluates to TRUE , the statements in the IF branch executes. If the expression evaluates to FALSE , MySQL will check the elseif-expression and execute the elseif-statements in the ELSEIF branch if the elseif_expression evaluates to TRUE . 119 | 120 | The IF statement may have multiple ELSEIF branches to check multiple expressions. If no expression evaluates to TRUE, the else-statements in the ELSE branch will execute. 121 | 122 | 123 | ## MySQL IF statement examples 124 | 125 | The following example illustrates how to use the IF ESLEIF ELSE statement. The GetCustomerLevel() stored procedure accepts two parameters customer number and customer level. 126 | 127 | First, it gets the credit limit from the customers table. 128 | 129 | Then, based on the credit limit, it determines the customer level: PLATINUM , GOLD , and SILVER . 130 | 131 | The parameter p_customerlevel stores the level of the customer and is used by the calling program. 132 | 133 | ```sql 134 | DELIMITER $$ 135 | 136 | CREATE PROCEDURE GetCustomerLevel( 137 | in p_customerNumber int(11), 138 | out p_customerLevel varchar(10)) 139 | BEGIN 140 | DECLARE creditlim double; 141 | 142 | SELECT creditlimit INTO creditlim 143 | FROM customers 144 | WHERE customerNumber = p_customerNumber; 145 | 146 | IF creditlim > 50000 THEN 147 | SET p_customerLevel = 'PLATINUM'; 148 | ELSEIF (creditlim <= 50000 AND creditlim >= 10000) THEN 149 | SET p_customerLevel = 'GOLD'; 150 | ELSEIF creditlim < 10000 THEN 151 | SET p_customerLevel = 'SILVER'; 152 | END IF; 153 | 154 | END$$ 155 | ``` 156 | 157 | The following flowchart demonstrates the logic of determining customer level. 158 | 159 | ![mysql-if-statement-flow-chart](../images/mysql-if-statement-flow-chart.png) 160 | 161 | 162 | # MySQL CASE Statement 163 | 164 | 165 | Besides the IF statement, MySQL provides an alternative conditional statement called CASE. The MySQL CASE statement makes the code more readable and efficient. 166 | 167 | There are two forms of the CASE statements: simple and searched CASE statements. 168 | 169 | ## Simple CASE statement 170 | 171 | Let’s take a look at the syntax of the simple CASE statement: 172 | 173 | ```sql 174 | CASE case_expression 175 | WHEN when_expression_1 THEN commands 176 | WHEN when_expression_2 THEN commands 177 | ... 178 | ELSE commands 179 | END CASE; 180 | ``` 181 | 182 | You use the simple CASE statement to check the value of an expression against a set of unique values. 183 | 184 | The case_expression can be any valid expression. We compare the value of the case_expression with when_expression in each WHEN clause e.g., when_expression_1 , when_expression_2 , etc. If the value of the case_expression and when_expression_n are equal, the commands in the corresponding WHEN branch executes. 185 | 186 | In case none of the when_expression in the WHEN clause matches the value of the case_expression , the commands in the ELSE clause will execute. The ELSE clause is optional. If you omit the ELSE clause and no match found, MySQL will raise an error. 187 | 188 | The following example illustrates how to use the simple CASE statement: 189 | 190 | ```sql 191 | DELIMITER $$ 192 | 193 | CREATE PROCEDURE GetCustomerShipping( 194 | in p_customerNumber int(11), 195 | out p_shiping varchar(50)) 196 | BEGIN 197 | DECLARE customerCountry varchar(50); 198 | 199 | SELECT country INTO customerCountry 200 | FROM customers 201 | WHERE customerNumber = p_customerNumber; 202 | 203 | CASE customerCountry 204 | WHEN 'USA' THEN 205 | SET p_shiping = '2-day Shipping'; 206 | WHEN 'Canada' THEN 207 | SET p_shiping = '3-day Shipping'; 208 | ELSE 209 | SET p_shiping = '5-day Shipping'; 210 | END CASE; 211 | 212 | END$$ 213 | ``` 214 | 215 | How the stored procedure works. 216 | 217 | * The GetCustomerShipping stored procedure accepts customer number as an IN parameter and returns shipping period based on the country of the customer. 218 | * Inside the stored procedure, first we get the country of the customer based on the input customer number. Then we use the simple CASE statement to compare the country of the customer to determine the shipping period. If the customer locates in USA , the shipping period is 2-day shipping . If the customer is in Canada , the shipping period is 3-day shipping The customers from other countries have 5-day shipping . 219 | 220 | The following flowchart demonstrates the logic of determining shipping period. 221 | 222 | ![mysql-case-statement](../images/mysql-case-statement.png) 223 | 224 | The following is the test script for the stored procedure above: 225 | 226 | ```sql 227 | SET @customerNo = 112; 228 | 229 | SELECT country into @country 230 | FROM customers 231 | WHERE customernumber = @customerNo; 232 | 233 | CALL GetCustomerShipping(@customerNo,@shipping); 234 | 235 | SELECT @customerNo AS Customer, 236 | @country AS Country, 237 | @shipping AS Shipping; 238 | ``` 239 | 240 | ## Searched CASE statement 241 | 242 | The simple CASE statement only allows you match a value of an expression against a set of distinct values. In order to perform more complex matches such as ranges, you use the searched CASE statement. The searched CASE statement is equivalent to the IF statement, however, its construct is much more readable. 243 | 244 | The following illustrates the syntax of the searched CASE statement: 245 | 246 | ```sql 247 | CASE 248 | WHEN condition_1 THEN commands 249 | WHEN condition_2 THEN commands 250 | ... 251 | ELSE commands 252 | END CASE; 253 | ``` 254 | 255 | MySQL evaluates each condition in the WHEN clause until it finds a condition whose value is TRUE , then corresponding commands in the THEN clause will execute. 256 | 257 | If no condition is TRUE , the command in the ELSE clause will execute. If you don’t specify the ELSE clause and no condition is TRUE , MySQL will issue an error message. 258 | 259 | MySQL does not allow you to have empty commands in the THEN or ELSE clause. If you don’t want to handle the logic in the ELSE clause while preventing MySQL raise an error, you can put an empty BEGIN END block in the ELSE clause. 260 | 261 | The following example demonstrates using searched CASE statement to find customer level SILVER , GOLD or PLATINUM based on customer’s credit limit. 262 | 263 | ```sql 264 | DELIMITER $$ 265 | 266 | CREATE PROCEDURE GetCustomerLevel( 267 | in p_customerNumber int(11), 268 | out p_customerLevel varchar(10)) 269 | BEGIN 270 | DECLARE creditlim double; 271 | 272 | SELECT creditlimit INTO creditlim 273 | FROM customers 274 | WHERE customerNumber = p_customerNumber; 275 | 276 | CASE 277 | WHEN creditlim > 50000 THEN 278 | SET p_customerLevel = 'PLATINUM'; 279 | WHEN (creditlim <= 50000 AND creditlim >= 10000) THEN 280 | SET p_customerLevel = 'GOLD'; 281 | WHEN creditlim < 10000 THEN 282 | SET p_customerLevel = 'SILVER'; 283 | END CASE; 284 | 285 | END$$ 286 | ``` 287 | 288 | If the credit limit is 289 | 290 | * greater than 50K, then the customer is the PLATINUM customer 291 | * less than 50K and greater than 10K, then the customer is the GOLD customer 292 | * less than 10K, then the customer is the SILVER customer. 293 | 294 | We can test our stored procedure by executing the following test script: 295 | 296 | ```sql 297 | CALL GetCustomerLevel(112,@level); 298 | SELECT @level AS 'Customer Level'; 299 | ``` 300 | 301 | ### Hints for Choosing Between IF and CASE Statements 302 | 303 | 304 | MySQL provides both IF and CASE statements to enable you to execute a block of SQL code based on certain conditions, which is known as flow control. So what statement should you use? For the most developers, choosing between IF and CASE is just a matter of personal preference. However, when you decide to use IF or CASE , you should take the following points into the consideration: 305 | 306 | * A simple CASE statement is more readable than the IF statement when you compare a single expression against a range of unique values. In addition, the simple CASE statement is more efficient than the IF statement. 307 | * When you check complex expressions based on multiple values, the IF statement is easier to understand. 308 | * If you choose to use the CASE statement, you have to make sure that at least one of the CASE condition is matched. Otherwise, you need to define an error handler to catch the error. Recall that you don’t have to do this with the IF statement. 309 | * In most organization, there is always something called development guidelines document that provides developers with naming convention and guidelines on programming style. You should refer to this document and follow the development practices. 310 | * In some situations, mixing between IF and CASE make your stored procedure more readable and efficient. -------------------------------------------------------------------------------- /classes/class_18_2.md: -------------------------------------------------------------------------------- 1 | # MySQL Loop in Stored Procedures 2 | 3 | MySQL provides loop statements that allow you to execute a block of SQL code repeatedly based on a condition. There are three loop statements in MySQL: WHILE, REPEAT and LOOP. 4 | 5 | We will examine each loop statement in more detail in the following sections. 6 | 7 | ## WHILE loop 8 | 9 | The syntax of the WHILE statement is as follows: 10 | 11 | ```sql 12 | WHILE expression DO 13 | statements 14 | END WHILE 15 | ``` 16 | 17 | The WHILE loop checks the expressionat the beginning of each iteration. If the expressionevaluates to TRUE, MySQL will execute statementsbetween WHILEand END WHILE until the expressionevaluates to FALSE. The WHILE loop is called pretest loop because it checks the expression before the statements execute. 18 | 19 | Here is an example of using the WHILE loop statement in a stored procedure: 20 | 21 | ```sql 22 | DELIMITER $$ 23 | DROP PROCEDURE IF EXISTS test_mysql_while_loop$$ 24 | CREATE PROCEDURE test_mysql_while_loop() 25 | BEGIN 26 | DECLARE x INT; 27 | DECLARE str VARCHAR(255); 28 | 29 | SET x = 1; 30 | SET str = ''; 31 | 32 | WHILE x <= 5 DO 33 | SET str = CONCAT(str,x,','); 34 | SET x = x + 1; 35 | END WHILE; 36 | 37 | SELECT str; 38 | END$$ 39 | DELIMITER ; 40 | ``` 41 | 42 | In the test_mysql_while_loop stored procedure above: 43 | 44 | * First, we build str string repeatedly until the value of the x variable is greater than 5. 45 | * Then, we display the final string using the SELECT statement. 46 | 47 | Notice that if we don’t initialize the x variable, its default value is NULL. Therefore, the condition in the WHILE loop statement is always TRUE and you will have an indefinite loop, which is not expected. 48 | 49 | Let’s test the test_mysql_while_loopstored procedure: 50 | 51 | ```sql 52 | CALL test_mysql_while_loop(); 53 | ``` 54 | 55 | 56 | ## REPEAT loop 57 | 58 | The syntax of the REPEAT loop statement is as follows: 59 | 60 | ```sql 61 | REPEAT 62 | statements; 63 | UNTIL expression 64 | END REPEAT 65 | ``` 66 | 67 | First, MySQL executes the statements, and then it evaluates the expression. If the expression evaluates to FALSE, MySQL executes the statements repeatedly until the expression evaluates to TRUE. 68 | 69 | Because the REPEAT loop statement checks the expression after the execution of statements therefore the REPEAT loop statement is also known as the post-test loop. 70 | 71 | We can rewrite the test_mysql_while_loop stored procedure that uses WHILE loop statement above using the REPEAT loop statement: 72 | 73 | ```sql 74 | DELIMITER $$ 75 | DROP PROCEDURE IF EXISTS mysql_test_repeat_loop$$ 76 | CREATE PROCEDURE mysql_test_repeat_loop() 77 | BEGIN 78 | DECLARE x INT; 79 | DECLARE str VARCHAR(255); 80 | 81 | SET x = 1; 82 | SET str = ''; 83 | 84 | REPEAT 85 | SET str = CONCAT(str,x,','); 86 | SET x = x + 1; 87 | UNTIL x > 5 88 | END REPEAT; 89 | 90 | SELECT str; 91 | END$$ 92 | DELIMITER ; 93 | ``` 94 | 95 | It is noted that there is no semicolon (;) in the UNTIL expression. 96 | 97 | ```sql 98 | CALL mysql_test_repeat_loop(); 99 | ```` 100 | 101 | ## LOOP, LEAVE and ITERATE statements 102 | 103 | There are two statements that allow you to control the loop: 104 | 105 | * The LEAVE statement allows you to exit the loop immediately without waiting for checking the condition. The LEAVE statement works like the break statement in other languages such as PHP, C/C++, Java, etc. 106 | * The ITERATE statement allows you to skip the entire code under it and start a new iteration. The ITERATE statement is similar to the continue statement in PHP, C/C++, Java, etc. 107 | 108 | MySQL also gives you a LOOPstatement that executes a block of code repeatedly with an additional flexibility of using a loop label. 109 | 110 | The following is an example of using the LOOP loop statement. 111 | 112 | ```sql 113 | CREATE PROCEDURE test_mysql_loop() 114 | BEGIN 115 | DECLARE x INT; 116 | DECLARE str VARCHAR(255); 117 | 118 | SET x = 1; 119 | SET str = ''; 120 | 121 | loop_label: LOOP 122 | IF x > 10 THEN 123 | LEAVE loop_label; 124 | END IF; 125 | 126 | SET x = x + 1; 127 | IF (x mod 2) THEN 128 | ITERATE loop_label; 129 | ELSE 130 | SET str = CONCAT(str,x,','); 131 | END IF; 132 | END LOOP; 133 | 134 | SELECT str; 135 | 136 | END; 137 | ``` 138 | 139 | * The stored procedure only constructs a string with even numbers e.g., 2, 4, 6, etc. 140 | * We put a loop_label loop label before the LOOPstatement. 141 | * If the value of x is greater than 10, the loop is terminated because of the LEAVE statement. 142 | * If the value of the x is an odd number, the ITERATE statement ignores everything below it and starts a new iteration. 143 | * If the value of the x is an even number, the block in the ELSE statement will build the string with even numbers. 144 | 145 | # MySQL Cursor 146 | 147 | 148 | ## Introduction to MySQL cursor 149 | 150 | To handle a result set inside a stored procedure, you use a cursor. A cursor allows you to iterate a set of rows returned by a query and process each row accordingly. 151 | 152 | MySQL cursor is read-only, non-scrollable and asensitive. 153 | 154 | * Read only: you cannot update data in the underlying table through the cursor. 155 | * Non-scrollable: you can only fetch rows in the order determined by the SELECT statement. You cannot fetch rows in the reversed order. In addition, you cannot skip rows or jump to a specific row in the result set. 156 | * Asensitive: there are two kinds of cursors: asensitive cursor and insensitive cursor. An asensitive cursor points to the actual data, whereas an insensitive cursor uses a temporary copy of the data. An asensitive cursor performs faster than an insensitive cursor because it does not have to make a temporary copy of data. However, any change that made to the data from other connections will affect the data that is being used by an asensitive cursor, therefore, it is safer if you don’t update the data that is being used by an asensitive cursor. MySQL cursor is asensitive. 157 | 158 | You can use MySQL cursors in stored procedures, stored functions, and triggers. 159 | 160 | ## Working with MySQL cursor 161 | 162 | First, you have to declare a cursor by using the DECLARE statement: 163 | 164 | ```sql 165 | DECLARE cursor_name CURSOR FOR SELECT_statement; 166 | ``` 167 | 168 | The cursor declaration must be after any variable declaration. If you declare a cursor before variables declaration, MySQL will issue an error. A cursor must always be associated with a SELECT statement. 169 | 170 | Next, you open the cursor by using the OPEN statement. The OPEN statement initializes the result set for the cursor, therefore, you must call the OPEN statement before fetching rows from the result set. 171 | 172 | ```sql 173 | OPEN cursor_name; 174 | ``` 175 | 176 | Then, you use the FETCH statement to retrieve the next row pointed by the cursor and move the cursor to the next row in the result set. 177 | 178 | ```sql 179 | FETCH cursor_name INTO variables list; 180 | ``` 181 | 182 | After that, you can check to see if there is any row available before fetching it. 183 | 184 | Finally, you call the CLOSE statement to deactivate the cursor and release the memory associated with it as follows: 185 | 186 | ```sql 187 | CLOSE cursor_name; 188 | ``` 189 | 190 | When the cursor is no longer used, you should close it. 191 | 192 | When working with MySQL cursor, you must also declare a NOT FOUND handler to handle the situation when the cursor could not find any row. Because each time you call the FETCH statement, the cursor attempts to read the next row in the result set. When the cursor reaches the end of the result set, it will not be able to get the data, and a condition is raised. The handler is used to handle this condition. 193 | 194 | To declare a NOT FOUND handler, you use the following syntax: 195 | 196 | ```sql 197 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET finished = 1; 198 | ``` 199 | 200 | Where finished is a variable to indicate that the cursor has reached the end of the result set. Notice that the handler declaration must appear after variable and cursor declaration inside the stored procedures. 201 | 202 | The following diagram illustrates how MySQL cursor works. 203 | 204 | ![mysql-cursor](../images/mysql-cursor.png) 205 | 206 | ## MySQL Cursor Example 207 | 208 | We are going to develop a stored procedure that builds an email list of all employees in the employees table in the MySQL sample database. 209 | 210 | First, we declare some variables, a cursor for looping over the emails of employees, and a NOT FOUND handler: 211 | 212 | ```sql 213 | DECLARE finished INTEGER DEFAULT 0; 214 | DECLARE email varchar(255) DEFAULT ""; 215 | 216 | -- declare cursor for employee email 217 | DEClARE email_cursor CURSOR FOR 218 | SELECT email FROM employees; 219 | 220 | -- declare NOT FOUND handler 221 | DECLARE CONTINUE HANDLER 222 | FOR NOT FOUND SET finished = 1; 223 | ``` 224 | 225 | Next, we open the email_cursor by using the OPEN statement: 226 | 227 | ```sql 228 | OPEN email_cursor; 229 | ``` 230 | 231 | Then, we iterate the email list, and concatenate all emails where each email is separated by a semicolon(;): 232 | 233 | ```sql 234 | get_email: LOOP 235 | FETCH email_cursor INTO v_email; 236 | IF v_finished = 1 THEN 237 | LEAVE get_email; 238 | END IF; 239 | -- build email list 240 | SET email_list = CONCAT(v_email,";",email_list); 241 | END LOOP get_email; 242 | ``` 243 | 244 | After that, inside the loop we used the v_finished variable to check if there is any email in the list to terminate the loop. 245 | 246 | Finally, we close the cursor using the CLOSE statement: 247 | ```sql 248 | CLOSE email_cursor; 249 | ``` 250 | 251 | The build_email_list stored procedure is as follows: 252 | 253 | ```sql 254 | DELIMITER $$ 255 | 256 | CREATE PROCEDURE build_email_list (INOUT email_list varchar(4000)) 257 | BEGIN 258 | 259 | DECLARE v_finished INTEGER DEFAULT 0; 260 | DECLARE v_email varchar(100) DEFAULT ""; 261 | 262 | -- declare cursor for employee email 263 | DEClARE email_cursor CURSOR FOR 264 | SELECT email FROM employees; 265 | 266 | -- declare NOT FOUND handler 267 | DECLARE CONTINUE HANDLER 268 | FOR NOT FOUND SET v_finished = 1; 269 | 270 | OPEN email_cursor; 271 | 272 | get_email: LOOP 273 | 274 | FETCH email_cursor INTO v_email; 275 | 276 | IF v_finished = 1 THEN 277 | LEAVE get_email; 278 | END IF; 279 | 280 | -- build email list 281 | SET email_list = CONCAT(v_email,";",email_list); 282 | 283 | END LOOP get_email; 284 | 285 | CLOSE email_cursor; 286 | 287 | END$$ 288 | ``` 289 | 290 | You can test the build_email_list stored procedure using the following script: 291 | 292 | ```sql 293 | SET @email_list = ""; 294 | CALL build_email_list(@email_list); 295 | SELECT @email_list; 296 | ``` 297 | -------------------------------------------------------------------------------- /classes/class_18_3.md: -------------------------------------------------------------------------------- 1 | # Listing Stored Procedures in a MySQL Database 2 | 3 | MySQL provides us with several useful statements that help manage stored procedures more effectively. Those statements include listing stored procedures and showing the stored procedure’s source code. 4 | 5 | ## Displaying characteristics of stored procedures 6 | 7 | To display characteristics of a stored procedure, you use the SHOW PROCEDURE STATUS statement as follows: 8 | 9 | ```sql 10 | SHOW PROCEDURE STATUS [LIKE 'pattern' | WHERE expr]; 11 | ``` 12 | 13 | The SHOW PROCEDURE STATUS statement is a MySQL extension to SQL standard. This statement gives you the stored procedure’s characteristics including database, stored procedure name, type, creator, etc. 14 | 15 | You can use LIKE or WHERE clause to filter out the stored procedure based on various criteria. 16 | 17 | To list all stored procedures of the databases that you have the privilege to access, you use the SHOW PROCEDURE STATUS statement as follows: 18 | 19 | ```sql 20 | SHOW PROCEDURE STATUS; 21 | ``` 22 | 23 | If you want to show just stored procedure in a particular database, you can use the WHERE clause in the SHOW PROCEDURE STATUS statement: 24 | 25 | ```sql 26 | SHOW PROCEDURE STATUS WHERE db = 'classicmodels'; 27 | ``` 28 | 29 | If you want to show stored procedures that have a particular pattern e.g., its name contains product, you can use LIKE operator as the following command: 30 | 31 | ```sql 32 | SHOW PROCEDURE STATUS WHERE name LIKE '%product%' 33 | ``` 34 | 35 | ## Displaying stored procedure’s source code 36 | 37 | To display source code of a particular stored procedure, you use the SHOW CREATE PROCEDURE statement as follows: 38 | 39 | ```sql 40 | SHOW CREATE PROCEDURE stored_procedure_name 41 | ``` 42 | 43 | You specify the name of the stored procedure after the SHOW CREATE PROCEDURE keywords. For example, to display the code of the GetAllProducts stored procedure, you use the following statement: 44 | 45 | ```sql 46 | SHOW CREATE PROCEDURE GetAllProducts 47 | ``` 48 | 49 | # MySQL Error Handling in Stored Procedures 50 | 51 | When an error occurs inside a stored procedure, it is important to handle it appropriately, such as continuing or exiting the current code block’s execution, and issuing a meaningful error message. 52 | 53 | MySQL provides an easy way to define handlers that handle from general conditions such as warnings or exceptions to specific conditions e.g., specific error codes. 54 | 55 | ## Declaring a handler 56 | 57 | To declare a handler, you use the DECLARE HANDLER statement as follows: 58 | 59 | ```sql 60 | DECLARE action HANDLER FOR condition_value statement; 61 | ``` 62 | 63 | If a condition whose value matches the condition_value , MySQL will execute the statement and continue or exit the current code block based on the action . 64 | 65 | The action accepts one of the following values: 66 | 67 | * CONTINUE : the execution of the enclosing code block ( BEGIN … END ) continues. 68 | * EXIT : the execution of the enclosing code block, where the handler is declared, terminates. 69 | 70 | The condition_value specifies a particular condition or a class of conditions that activates the handler. The condition_value accepts one of the following values: 71 | 72 | * A MySQL error code. 73 | * A standard SQLSTATE value. Or it can be an SQLWARNING , NOTFOUND or SQLEXCEPTION condition, which is shorthand for the class of SQLSTATE values. The NOTFOUND condition is used for a cursor or SELECT INTO variable_list statement. 74 | * A named condition associated with either a MySQL error code or SQLSTATE value. 75 | 76 | The statement could be a simple statement or a compound statement enclosing by the BEGIN and END keywords. 77 | 78 | ## MySQL error handling examples 79 | 80 | Let’s look into several examples of declaring handlers. 81 | 82 | The following handler means that if an error occurs, set the value of the has_error variable to 1 and continue the execution. 83 | 84 | ```sql 85 | DECLARE CONTINUE HANDLER FOR SQLEXCEPTION SET has_error = 1; 86 | ``` 87 | 88 | The following is another handler which means that in case any error occurs, rollback the previous operation, issue an error message, and exit the current code block. If you declare it inside the BEGIN END block of a stored procedure, it will terminate stored procedure immediately. 89 | 90 | ```sql 91 | DECLARE EXIT HANDLER FOR SQLEXCEPTION 92 | BEGIN 93 | ROLLBACK; 94 | SELECT 'An error has occurred, operation rollbacked and the stored procedure was terminated'; 95 | END; 96 | ``` 97 | 98 | The following handler means that if there are no more rows to fetch, in case of a cursor or SELECT INTO statement, set the value of the no_row_found variable to 1 and continue execution. 99 | 100 | ```sql 101 | DECLARE CONTINUE HANDLER FOR NOT FOUND SET no_row_found = 1; 102 | ``` 103 | 104 | The following handler means that if a duplicate key error occurs, MySQL error 1062 is issued. It issues an error message and continues execution. 105 | 106 | ```sql 107 | DECLARE CONTINUE HANDLER FOR 1062 108 | SELECT 'Error, duplicate key occurred'; 109 | ``` 110 | 111 | ## MySQL handler example in stored procedures 112 | 113 | First, we create a new table named article_tags for the demonstration: 114 | 115 | ```sql 116 | CREATE TABLE article_tags( 117 | article_id INT, 118 | tag_id INT, 119 | PRIMARY KEY(article_id,tag_id) 120 | ); 121 | ``` 122 | 123 | The article_tags table stores the relationships between articles and tags. Each article may have many tags and vice versa. For the sake of simplicity, we don’t create articles and tags tables, as well as the foreign keys in the article_tags table. 124 | 125 | Next, we create a stored procedure that inserts article id and tag id into the article_tags table: 126 | 127 | ```sql 128 | DELIMITER $$ 129 | 130 | CREATE PROCEDURE insert_article_tags(IN article_id INT, IN tag_id INT) 131 | BEGIN 132 | 133 | DECLARE CONTINUE HANDLER FOR 1062 134 | SELECT CONCAT('duplicate keys (',article_id,',',tag_id,') found') AS msg; 135 | 136 | -- insert a new record into article_tags 137 | INSERT INTO article_tags(article_id,tag_id) 138 | VALUES(article_id,tag_id); 139 | 140 | -- return tag count for the article 141 | SELECT COUNT(*) FROM article_tags; 142 | END 143 | ``` 144 | 145 | Then, we add tag id 1, 2 and 3 for the article 1 by calling the insert_article_tags stored procedure as follows: 146 | 147 | ```sql 148 | CALL insert_article_tags(1,1); 149 | CALL insert_article_tags(1,2); 150 | CALL insert_article_tags(1,3); 151 | ``` 152 | 153 | After that, we try to insert a duplicate key to check if the handler is really invoked. 154 | 155 | ```sql 156 | CALL insert_article_tags(1,3); 157 | ``` 158 | 159 | We got an error message. However, because we declared the handler as a CONTINUE handler, the stored procedure continued the execution. As the result, we got the tag count for the article as well. 160 | 161 | ![mysql-error-handling](../images/mysql-error-handling.jpg) 162 | 163 | If we change the CONTINUE in the handler declaration to EXIT , we will get an error message only. 164 | 165 | ```sql 166 | DELIMITER $$ 167 | 168 | CREATE PROCEDURE insert_article_tags_2(IN article_id INT, IN tag_id INT) 169 | BEGIN 170 | 171 | DECLARE EXIT HANDLER FOR SQLEXCEPTION 172 | SELECT 'SQLException invoked'; 173 | 174 | DECLARE EXIT HANDLER FOR 1062 175 | SELECT 'MySQL error code 1062 invoked'; 176 | 177 | DECLARE EXIT HANDLER FOR SQLSTATE '23000' 178 | SELECT 'SQLSTATE 23000 invoked'; 179 | 180 | -- insert a new record into article_tags 181 | INSERT INTO article_tags(article_id,tag_id) 182 | VALUES(article_id,tag_id); 183 | 184 | -- return tag count for the article 185 | SELECT COUNT(*) FROM article_tags; 186 | END 187 | ``` 188 | 189 | Finally, we can try to add a duplicate key to see the effect. 190 | 191 | ```sql 192 | CALL insert_article_tags_2(1,3); 193 | ``` 194 | 195 | ![mysql-error-handling-duplicate-keys](../images/mysql-error-handling-duplicate-keys.jpg) 196 | 197 | ## MySQL handler precedence 198 | 199 | In case there are multiple handlers that are eligible for handling an error, MySQL will call the most specific handler to handle the error first. 200 | 201 | An error always maps to one MySQL error code because in MySQL it is the most specific. An SQLSTATE may map to many MySQL error codes therefore it is less specific. An SQLEXCPETION or an SQLWARNING is the shorthand for a class of SQLSTATES values so it is the most generic. 202 | 203 | Based on the handler precedence’s rules, MySQL error code handler, SQLSTATE handler and SQLEXCEPTION takes the first, second and third precedence. 204 | 205 | Suppose we declare three handlers in the insert_article_tags_3 stored procedure as follows: 206 | 207 | ```sql 208 | DELIMITER $$ 209 | 210 | CREATE PROCEDURE insert_article_tags_3(IN article_id INT, IN tag_id INT) 211 | BEGIN 212 | 213 | DECLARE EXIT HANDLER FOR 1062 SELECT 'Duplicate keys error encountered'; 214 | DECLARE EXIT HANDLER FOR SQLEXCEPTION SELECT 'SQLException encountered'; 215 | DECLARE EXIT HANDLER FOR SQLSTATE '23000' SELECT 'SQLSTATE 23000'; 216 | 217 | -- insert a new record into article_tags 218 | INSERT INTO article_tags(article_id,tag_id) 219 | VALUES(article_id,tag_id); 220 | 221 | -- return tag count for the article 222 | SELECT COUNT(*) FROM article_tags; 223 | END 224 | ``` 225 | 226 | We try to insert a duplicate key into the article_tags table by calling the stored procedure: 227 | 228 | ```sql 229 | CALL insert_article_tags_3(1,3); 230 | ``` 231 | 232 | As you see the MySQL error code handler is called. 233 | 234 | ![MySQL-handler-precedence](../images/MySQL-handler-precedence.jpg) 235 | 236 | Using named error condition 237 | 238 | Let’s start with an error handler declaration. 239 | 240 | ```sql 241 | DECLARE EXIT HANDLER FOR 1051 SELECT 'Please create table abc first'; 242 | SELECT * FROM abc; 243 | ``` 244 | 245 | What does the number 1051 really mean? Imagine you have a big stored procedure polluted with those numbers all over places; it will become a nightmare to maintain the code. 246 | 247 | Fortunately, MySQL provides us with the DECLARE CONDITION statement that declares a named error condition, which associates with a condition. 248 | 249 | The syntax of the DECLARE CONDITION statement is as follows: 250 | 251 | ```sql 252 | DECLARE condition_name CONDITION FOR condition_value; 253 | ``` 254 | 255 | The condition_value can be a MySQL error code such as 1015 or a SQLSTATE value. The condition_value is represented by the condition_name . 256 | 257 | After declaration, we can refer to condition_name instead of condition_value . 258 | 259 | So we can rewrite the code above as follows: 260 | 261 | ```sql 262 | DECLARE table_not_found CONDITION for 1051; 263 | DECLARE EXIT HANDLER FOR table_not_found SELECT 'Please create table abc first'; 264 | SELECT * FROM abc; 265 | ``` 266 | 267 | This code is obviously more readable than the previous one. 268 | 269 | # Raising Error Conditions with MySQL SIGNAL / RESIGNAL Statements 270 | 271 | 272 | ## MySQL SIGNAL statement 273 | 274 | You use the SIGNAL statement to return an error or warning condition to the caller from a stored program e.g., stored procedure, stored function, trigger or event. The SIGNAL statement provides you with control over which information for returning such as value and messageSQLSTATE. 275 | 276 | The following illustrates syntax of the SIGNAL statement: 277 | 278 | ```sql 279 | SIGNAL SQLSTATE | condition_name; 280 | SET condition_information_item_name_1 = value_1, 281 | condition_information_item_name_1 = value_2, etc; 282 | ``` 283 | 284 | Following the SIGNAL keyword is a SQLSTATE value or a condition name declared by the DECLARE CONDITION statement. Notice that the SIGNAL statement must always specify a SQLSTATE value or a named condition that defined with an SQLSTATE value. 285 | 286 | To provide the caller with information, you use the SET clause. If you want to return multiple condition information item names with values, you need to separate each name/value pair by a comma. 287 | 288 | The condition_information_item_name can be MESSAGE_TEXT, MYSQL_ERRORNO, CURSOR_NAME , etc. 289 | 290 | The following stored procedure adds an order line item into an existing sales order. It issues an error message if the order number does not exist. 291 | 292 | ```sql 293 | DELIMITER $$ 294 | 295 | CREATE PROCEDURE AddOrderItem( 296 | in orderNo int, 297 | in productCode varchar(45), 298 | in qty int, 299 | in price double, 300 | in lineNo int ) 301 | BEGIN 302 | DECLARE C INT; 303 | 304 | SELECT COUNT(orderNumber) INTO C 305 | FROM orders 306 | WHERE orderNumber = orderNo; 307 | 308 | -- check if orderNumber exists 309 | IF(C != 1) THEN 310 | SIGNAL SQLSTATE '45000' 311 | SET MESSAGE_TEXT = 'Order No not found in orders table'; 312 | END IF; 313 | -- more code below 314 | -- ... 315 | END 316 | ``` 317 | 318 | First, it counts the orders with the input order number that we pass to the stored procedure. 319 | 320 | Second, if the number of order is not 1, it raises an error with SQLSTATE 45000 along with an error message saying that order number does not exist in the orders table. 321 | 322 | Notice that 45000 is a generic SQLSTATE value that illustrates an unhandled user-defined exception. 323 | 324 | If we call the stored procedure AddOrderItem() and pass a nonexistent order number, we will get an error message. 325 | 326 | ```sql 327 | CALL AddOrderItem(10,'S10_1678',1,95.7,1); 328 | ``` 329 | 330 | ![mysql-signal](../images/mysql-signal.jpg) 331 | 332 | ## MySQL RESIGNAL statement 333 | 334 | Besides the SIGNAL statement, MySQL also provides the RESIGNAL statement used to raise a warning or error condition. 335 | 336 | The RESIGNAL statement is similar to SIGNAL statement in term of functionality and syntax, except that: 337 | 338 | * You must use the RESIGNAL statement within an error or warning handler, otherwise, you will get an error message saying that “RESIGNAL when handler is not active”. Notice that you can use SIGNAL statement anywhere inside a stored procedure. 339 | * You can omit all attributes of the RESIGNAL statement, even the SQLSTATE value. 340 | 341 | If you use the RESIGNAL statement alone, all attributes are the same as the ones passed to the condition handler. 342 | 343 | The following stored procedure changes the error message before issuing it to the caller. 344 | 345 | ``sql 346 | DELIMITER $$ 347 | 348 | CREATE PROCEDURE Divide(IN numerator INT, IN denominator INT, OUT result double) 349 | BEGIN 350 | DECLARE division_by_zero CONDITION FOR SQLSTATE '22012'; 351 | 352 | DECLARE CONTINUE HANDLER FOR division_by_zero 353 | RESIGNAL SET MESSAGE_TEXT = 'Division by zero / Denominator cannot be zero'; 354 | -- 355 | IF denominator = 0 THEN 356 | SIGNAL division_by_zero; 357 | ELSE 358 | SET result := numerator / denominator; 359 | END IF; 360 | END 361 | ``` 362 | 363 | Let’s call the Divide() stored procedure. 364 | 365 | ```sql 366 | CALL Divide(10,0,@result); 367 | ``` 368 | 369 | ![mysql-resignal](../images/mysql-resignal.jpg) -------------------------------------------------------------------------------- /classes/class_18_4.md: -------------------------------------------------------------------------------- 1 | # MySQL Stored Function 2 | 3 | A stored function is a special kind stored program that returns a single value. You use stored functions to encapsulate common formulas or business rules that are reusable among SQL statements or stored programs. 4 | 5 | Different from a stored procedure, you can use a stored function in SQL statements wherever an expression is used. This helps improve the readability and maintainability of the procedural code. 6 | 7 | ## MySQL stored function syntax 8 | 9 | The following illustrates the simplest syntax for creating a new stored function: 10 | 11 | ```sql 12 | CREATE FUNCTION function_name(param1,param2,…) 13 | RETURNS datatype 14 | [NOT] DETERMINISTIC 15 | statements 16 | ``` 17 | 18 | First, you specify the name of the stored function after CREATE FUNCTION clause. 19 | 20 | Second, you list all parameters of the stored function inside the parentheses. By default, all parameters are IN parameters. You cannot specify IN , OUT or INOUT modifiers to the parameters. 21 | 22 | Third, you must specify the data type of the return value in the RETURNS statement. It can be any valid MySQL data types. 23 | 24 | Fourth, for the same input parameters, if the stored function returns the same result, it is considered deterministic and otherwise the stored function is not deterministic. You have to decide whether a stored function is deterministic or not. If you declare it incorrectly, the stored function may produce an unexpected result, or the available optimization is not used which degrades the performance. 25 | 26 | Fifth, you write the code in the body of the stored function. It can be a single statement or a compound statement. Inside the body section, you have to specify at least one RETURN statement. The RETURN statement returns a value to the caller. Whenever the RETURN statement is reached, the stored function’s execution is terminated immediately. 27 | 28 | ## MySQL stored function example 29 | 30 | Let’s take a look at an example of using stored function. We will use the customers table in the sample database for the demonstration. 31 | 32 | The following example is a function that returns the level of a customer based on credit limit. We use the IF statement to decide the credit limit. 33 | 34 | ```sql 35 | DELIMITER $$ 36 | 37 | CREATE FUNCTION CustomerLevel(p_creditLimit double) RETURNS VARCHAR(10) 38 | DETERMINISTIC 39 | BEGIN 40 | DECLARE lvl varchar(10); 41 | 42 | IF p_creditLimit > 50000 THEN 43 | SET lvl = 'PLATINUM'; 44 | ELSEIF (p_creditLimit <= 50000 AND p_creditLimit >= 10000) THEN 45 | SET lvl = 'GOLD'; 46 | ELSEIF p_creditLimit < 10000 THEN 47 | SET lvl = 'SILVER'; 48 | END IF; 49 | 50 | RETURN (lvl); 51 | END 52 | ``` 53 | 54 | Now, we can call the CustomerLevel() in an SQL SELECT statement as follows: 55 | 56 | ```sql 57 | SELECT 58 | customerName, CustomerLevel(creditLimit) 59 | FROM 60 | customers 61 | ORDER BY customerName; 62 | ``` 63 | 64 | We also rewrite the GetCustomerLevel() stored procedure that we developed in the MySQL IF statement tutorial as follows: 65 | 66 | ```sql 67 | DELIMITER $$ 68 | 69 | CREATE PROCEDURE GetCustomerLevel( 70 | IN p_customerNumber INT(11), 71 | OUT p_customerLevel varchar(10) 72 | ) 73 | BEGIN 74 | DECLARE creditlim DOUBLE; 75 | 76 | SELECT creditlimit INTO creditlim 77 | FROM customers 78 | WHERE customerNumber = p_customerNumber; 79 | 80 | SELECT CUSTOMERLEVEL(creditlim) 81 | INTO p_customerLevel; 82 | 83 | END 84 | ``` 85 | 86 | As you can see, the GetCustomerLevel() stored procedure is much more readable when using the CustomerLevel() stored function. 87 | 88 | Notice that a stored function returns a single value only. If you include a SELECT statement without the INTO clause, you will get an error. 89 | 90 | In addition, if a stored function contains SQL statements, you should not use it inside other SQL statements; otherwise, the stored function will slow down the speed of the query. -------------------------------------------------------------------------------- /classes/class_18_5.md: -------------------------------------------------------------------------------- 1 | ### Exercises 2 | 3 | 1. Write a function that returns the amount of copies of a film in a store in sakila-db. Pass either the film id or the film name and the store id. 4 | 2. Write a stored procedure with an output parameter that contains a list of customer first and last names separated by ";", that live in a certain country. You pass the country it gives you the list of people living there. **USE A CURSOR**, do not use any aggregation function (ike CONTCAT_WS. 5 | 3. Review the function **inventory_in_stock** and the procedure **film_in_stock** explain the code, write usage examples. -------------------------------------------------------------------------------- /classes/class_19.md: -------------------------------------------------------------------------------- 1 | # Dockerized installation 2 | 3 | 1. Download Image. 4 | Pull image from oficial repository: 5 | `docker pull mongo:latest` 6 | **OR**, preferably inside the school download image from [this link](http://networking.itsv.edu.ar/descargas/mongo/mongodb.docker.img) and : 7 | `docker load -i mongodb.docker.img` 8 | 9 | 2. Run command to load container. 10 | ` docker run --name mongo-test -v path/to/files:/data/db -p 27017:27017 -d mongo` 11 | 12 | 2. Start container (on reboot or stop container). 13 | ` docker start mongo-test ` 14 | 15 | # Ubuntu installation 16 | 17 | Please, see [this link] (https://docs.mongodb.com/tutorials/install-mongodb-on-ubuntu/). 18 | 19 | # Install tools 20 | 21 | On ubuntu 16.04: 22 | 23 | ``` 24 | sudo apt-key adv --keyserver hkp://keyserver.ubuntu.com:80 --recv 0C49F3730359A14518585931BC711F9BA15703C6 25 | 26 | echo "deb [ arch=amd64,arm64 ] http://repo.mongodb.org/apt/ubuntu xenial/mongodb-org/3.4 multiverse" | sudo tee /etc/apt/sources.list.d/mongodb-org-3.4.list 27 | 28 | sudo apt-get update 29 | 30 | sudo apt-get install mongodb-org-shell mongodb-org-tools 31 | ``` 32 | 33 | 34 | 35 | # Install dataset 36 | 1. Download ide from (this link)[http://networking.itsv.edu.ar/descargas/mongo/mongobooster-4.0.1-x86_64.AppImage] 37 | Change linux permissions `chmod +x mongobooster-4.0.1-x86_64.AppImage` 38 | 1. Download dataset from (this link)[http://networking.itsv.edu.ar/descargas/mongo/primer-dataset.json] 39 | 1. Download import script from (this link)[http://networking.itsv.edu.ar/descargas/mongo/import_script.js] 40 | 1. Run IDE (Doble click) 41 | 1. Create new conection (host: localhost:27017) 42 | 1. Connect to database 43 | 1. Click on local-> create collection -> name collection as restaurant 44 | 1. Select restaurant collection 45 | 1. Open script **'import_script.js'** 46 | 1. Change file_js url, and name of connection. 47 | 1. Run Script 48 | 1. :umbrella_on_ground: 49 | 50 | ### OR.... 51 | If you install mongo shell, can try this method: 52 | 53 | `mongoimport --db test --collection restaurants --drop --file ~/downloads/primer-dataset.json` 54 | -------------------------------------------------------------------------------- /classes/class_20.md: -------------------------------------------------------------------------------- 1 | # Exercises 2 | 3 | We try translate class 4 exercises to mongodb. Please download sakila db json's from [here](http://static1.1.sqspcdn.com/static/f/359481/26067410/1427081957890/sakila.tgz?token=zFkfE4QSKgfurxrUF1lieRHKNS8%3D). 4 | 5 | 1. Show title and special_features of films that are PG-13 6 | 2. Get a list of all the different films duration. 7 | 3. Show title, rental_rate and replacement_cost of films that have replacement_cost from 20.00 up to 24.00 8 | 4. Show title, category and rating of films that have 'Behind the Scenes' as special_features 9 | 5. Show first name and last name of actors that acted in 'ZOOLANDER FICTION' 10 | 6. Show the address, city and country of the store with id 1 11 | 7. Show pair of film titles and rating of films that have the same rating. 12 | 8. Get all the films that are available in store id 2 and the manager first/last name of this store (the manager will appear in all the rows). 13 | 14 | ## Resultados 15 | 16 | #### Para Reemplazar los tipo de datos (cast) y guardar algunos string como float 17 | 18 | ```javascript 19 | db.films.find().forEach( function (x) { 20 | x['Rental Duration'] = parseFloat(x['Rental Duration']); 21 | x['Replacement Cost'] = parseFloat(x['Replacement Cost']); 22 | x['Length'] = parseFloat(x['Length']); 23 | db.films.save(x); 24 | }); 25 | ``` 26 | 27 | 28 | ## Show title and special_features of films that are PG-13 29 | 30 | > `db.films.find({Rating:'PG-13'}, {Title:1, 'Special Features':1})` 31 | 32 | ## Get a list of all the different films duration. 33 | > `db.films.distinct("Length")` 34 | ## Show title, rental_rate and replacement_cost of films that have replacement_cost from 20.00 up to 24.00 35 | > `db.films.find({Rating:'PG-13'}, {Title:1, 'Rental Duration':1})` 36 | ## Show title, category and rating of films that have 'Behind the Scenes' as special_features 37 | > `db.films.find({'Replacement Cost':{$gte:20.00,$lte:24.00}}, {Title:1, 'Rental Duration':1, 'Replacement Cost':1})` 38 | ## Show first name and last name of actors that acted in 'ZOOLANDER FICTION' 39 | ### One Query way 40 | > `db.films.find({Title:'ZOOLANDER FICTION'},{"Actors.First name":1, "Actors.Last name":1})` 41 | 42 | ### Logical way 43 | ``` javascript 44 | db.films.find({Title:'ZOOLANDER FICTION'}).forEach((it)=> { 45 | var doc = []; 46 | it.Actors.forEach((act)=>{ 47 | doc.push({'First Name':act['First name'],'Last Name':act['Last name']}); 48 | }) 49 | printjson(doc); 50 | }); 51 | ``` 52 | 53 | ## 54 | db.stores.find({_id:1}, {Address:1, City:1, Country:1}) 55 | 56 | ## 7 57 | ### Only one query way 58 | ```javsacript 59 | db.films.aggregate( 60 | [ 61 | { $group : { _id : "$Rating", films: { $push: "$Title" } } } 62 | ] 63 | ) 64 | ``` 65 | ### Logical way 66 | 67 | ``` javascript 68 | var by_rating = {}; 69 | db.films.find({}).forEach((film)=> { 70 | if (by_rating[film.Rating]==undefined){by_rating[film.Rating] = []} 71 | by_rating[film.Rating].push({'Title':film.Title,'Rating':film.Rating}) 72 | }); 73 | printjson(by_rating); 74 | ``` 75 | 76 | ## Get all the films that are unavailable in store id 2 and the manager first/last name of this store (the manager will appear in all the rows). 77 | 78 | ``` javascript 79 | var staff_store2_ids = [] 80 | var staff_store2_names = {} 81 | var films_available = [] 82 | db.stores.find({_id:2}, {"Staff.staffId":1, "Staff.Last Name":1, "Staff.First Name":1, _id:0}).forEach(staff=>{ 83 | var fn = staff.Staff[0]['First Name'] 84 | var ln = staff.Staff[0]['Last Name'] 85 | var id =staff.Staff[0].staffId.value 86 | staff_store2_ids.push(id) 87 | staff_store2_names[id] = {fn:fn,ln:ln} 88 | }) 89 | 90 | 91 | 92 | var rented_id_pair_staff={} 93 | db.customers.find({"Rentals": { $elemMatch: {'Return Date': null, staffId:{$in:staff_store2_ids}} }}, {'Rentals.$': 1}).forEach(res=>{ 94 | //console.log(res.) 95 | res.Rentals.forEach(rent=>{ 96 | rented_id_pair_staff[rent.filmId.value]=rent.staffId.value 97 | }) 98 | }) 99 | 100 | db.films.find({_id:{$in: Object.keys(rented_id_pair_staff)}}).forEach((it)=> { 101 | films_available.push({film:it, staff_data:staff_store2_names[it._id.value]}) 102 | }); 103 | 104 | console.log(films_available) 105 | ``` 106 | 107 | 108 | 109 | 110 | 111 | -------------------------------------------------------------------------------- /classes/class_21.md: -------------------------------------------------------------------------------- 1 | # Redis 2 | Redis is an open source, advanced key-value store and an apt solution for building highperformance, scalable web applications. 3 | 4 | 5 | - Redis holds its database entirely in the memory, using the disk only for persistence. 6 | 7 | - Redis has a relatively rich set of data types when compared to many key-value data stores. 8 | 9 | - Redis can replicate data to any number of slaves. 10 | 11 | ## Redis Advantages 12 | Following are certain advantages of Redis. 13 | 14 | - Exceptionally fast − Redis is very fast and can perform about 110000 SETs per second, about 81000 GETs per second. 15 | 16 | - Supports rich data types − Redis natively supports most of the datatypes that developers already know such as list, set, sorted set, and hashes. This makes it easy to solve a variety of problems as we know which problem can be handled better by which data type. 17 | 18 | - Operations are atomic − All Redis operations are atomic, which ensures that if two clients concurrently access, Redis server will receive the updated value. 19 | 20 | - Multi-utility tool − Redis is a multi-utility tool and can be used in a number of use cases such as caching, messaging-queues (Redis natively supports Publish/Subscribe), any short-lived data in your application, such as web application sessions, web page hit counts, etc. 21 | 22 | ### Installing Redis 23 | Run: 24 | ``` 25 | docker run -d --name redis -p 6379:6379 redis 26 | ``` 27 | To run commands 28 | ``` 29 | docker exec -it redis /bin/sh 30 | redis-cli 31 | ``` 32 | ### Configuration 33 | https://www.tutorialspoint.com/redis/redis_configuration.htm 34 | 35 | ### Strings 36 | Please do the tutorials: 37 | 38 | https://www.tutorialspoint.com/redis/redis_keys.htm 39 | https://www.tutorialspoint.com/redis/redis_strings.htm 40 | 41 | ### Hashes 42 | https://www.tutorialspoint.com/redis/redis_hashes.htm 43 | 44 | ### Lists 45 | https://www.tutorialspoint.com/redis/redis_lists.htm 46 | 47 | ### Sets 48 | https://www.tutorialspoint.com/redis/redis_sets.htm 49 | 50 | ### Channels 51 | https://www.tutorialspoint.com/redis/redis_pub_sub.htm 52 | 53 | ### Backup 54 | https://www.tutorialspoint.com/redis/redis_backup.htm 55 | 56 | 57 | ## Exercises 58 | 59 | 1 - Install Redis with docker. 60 | * Add port mapping. 61 | * Set up a bindmount volume. 62 | 63 | 2 - Connect to Redis and run basic commands 64 | * Write the command to connect using the cli 65 | * do a ping 66 | * get config values 67 | * etc 68 | 69 | 3 - Write examples with string 70 | 71 | 4 - Write examples with hashes 72 | 73 | 5 - Write examples with Lists 74 | 75 | 6 - Write examples with Sets 76 | 77 | 7 - Write examples with Sorted Sets 78 | 79 | 8 - Write examples using Publish Subscribe 80 | 81 | 9 - Write examples using Transactions 82 | 83 | 10 - Investigate backups 84 | 85 | 11 - Investigate Benchmarks - Run some 86 | 87 | 12 - Write a driver application (client) in Python, do some operations with it. 88 | -------------------------------------------------------------------------------- /classes/class_22.md: -------------------------------------------------------------------------------- 1 | [Essentials_7.1_01_Architecture_Overview.pptx](../images/Essentials_7.1_01_Architecture_Overview.pptx) 2 | 3 | [Essentials_7.1_LabManual_1_Node.docx](../images/Essentials_7.1_LabManual_1_Node.docx) 4 | 5 | 6 | [OLAPIntro.pdf](../images/OLAPIntro.pdf) 7 | 8 | ```sql 9 | Vertica Excercises #1 10 | 11 | -- 1 Exaplain this query 12 | 13 | SELECT fat_content 14 | FROM ( 15 | SELECT DISTINCT fat_content 16 | FROM product_dimension 17 | WHERE department_description 18 | IN ('Dairy') ) AS food 19 | ORDER BY fat_content 20 | LIMIT 5; 21 | 22 | -- 2 Explain this query 23 | 24 | SELECT order_number, date_ordered 25 | FROM store.store_orders_fact orders 26 | WHERE orders.store_key IN ( 27 | SELECT store_key 28 | FROM store.store_dimension 29 | WHERE store_state = 'MA') 30 | AND orders.vendor_key NOT IN ( 31 | SELECT vendor_key 32 | FROM public.vendor_dimension 33 | WHERE vendor_state = 'MA') 34 | AND date_ordered < '2003-03-01'; 35 | 36 | 37 | -- 3 Requests female and male customers with the maximum 38 | -- annual income from customers 39 | 40 | SELECT customer_name, annual_income 41 | FROM public.customer_dimension 42 | WHERE (customer_gender, annual_income) IN 43 | (SELECT customer_gender, MAX(annual_income) 44 | FROM public.customer_dimension 45 | GROUP BY customer_gender); 46 | 47 | 48 | -- 4 IN predicate 49 | -- Find all products supplied by stores in MA 50 | 51 | SELECT DISTINCT s.product_key, p.product_description 52 | FROM store.store_sales_fact s, public.product_dimension p 53 | WHERE s.product_key = p.product_key 54 | AND s.product_version = p.product_version 55 | AND s.store_key IN 56 | (SELECT store_key 57 | FROM store.store_dimension 58 | WHERE store_state = 'MA') 59 | ORDER BY s.product_key; 60 | 61 | -- 5 62 | -- EXISTS predicate 63 | -- Get a list of all the orders placed by all stores on 64 | -- January 2, 2003 for the vendors with records in the 65 | -- vendor_dimension table 66 | 67 | 68 | 69 | -- 6 70 | -- EXISTS predicate 71 | -- Orders placed by the vendor who got the best deal 72 | -- on January 4, 2004 73 | 74 | 75 | -- 7 76 | -- Equi join 77 | -- Joins online_sales_fact table and the call_center_dimension 78 | -- table with the ON clause 79 | 80 | ``` -------------------------------------------------------------------------------- /classes/exercises-results.md: -------------------------------------------------------------------------------- 1 | # Class 13: 2 | 3 | 1- Add a new customer 4 | - To store 1 5 | - For address use an existing address. The one that has the biggest address_id in 'United States' 6 | 7 | ```sql 8 | INSERT INTO sakila.customer 9 | (store_id, first_name, last_name, email, address_id, active) 10 | SELECT 1, 'Pepe', 'Suarez', 'pepesuarez@gmail.com', MAX(a.address_id), 1 11 | FROM address a 12 | WHERE (SELECT c.country_id 13 | FROM country c, city c1 14 | WHERE c.country = "United States" 15 | AND c.country_id = c1.country_id 16 | AND c1.city_id = a.city_id); 17 | 18 | 19 | SELECT * 20 | FROM customer 21 | WHERE last_name = "Suarez"; 22 | ``` 23 | 24 | 2- Add a rental 25 | - Make easy to select any film title. I.e. I should be able to put 'film tile' in the where, and not the id. 26 | - Do not check if the film is already rented, just use any from the inventory, e.g. the one with highest id. 27 | - Select any staff_id from Store 2. 28 | 29 | ```sql 30 | INSERT INTO sakila.rental 31 | (rental_date, inventory_id, customer_id, return_date, staff_id) 32 | SELECT CURRENT_TIMESTAMP, 33 | (SELECT MAX(r.inventory_id) 34 | FROM inventory r 35 | INNER JOIN film USING(film_id) 36 | WHERE film.title = "ARABIA DOGMA" -- Put film here 37 | LIMIT 1), 38 | 600, -- Put user here (in this case is the previous one insterted in excersise 1 39 | NULL, 40 | (SELECT staff_id 41 | FROM staff 42 | INNER JOIN store USING(store_id) 43 | WHERE store.store_id = 2 44 | LIMIT 1); 45 | ``` 46 | 47 | 3- Update film year based on the rating 48 | - For example if rating is 'G' release date will be '2001' 49 | - You can choose the mapping between rating and year. 50 | - Write as many statements are needed. 51 | 52 | ```sql 53 | UPDATE sakila.film 54 | SET release_year='2001' 55 | WHERE rating = "G"; 56 | 57 | UPDATE sakila.film 58 | SET release_year='2005' 59 | WHERE rating = "PG"; 60 | 61 | UPDATE sakila.film 62 | SET release_year='2010' 63 | WHERE rating = "PG-13"; 64 | 65 | UPDATE sakila.film 66 | SET release_year='2015' 67 | WHERE rating = "R"; 68 | 69 | UPDATE sakila.film 70 | SET release_year='2020' 71 | WHERE rating = "NC-17"; 72 | ``` 73 | 74 | 4- Return a film 75 | - Write the necessary statements and queries for the following steps. 76 | - Find a film that was not yet returned. And use that rental id. Pick the latest that was rented for example. 77 | - Use the id to return the film. 78 | 79 | ```sql 80 | #Rental id devuelto 11496 , el precio 2,99, el customer = 155, staff = 1 81 | SELECT rental_id, rental_rate, customer_id, staff_id 82 | FROM film 83 | INNER JOIN inventory USING(film_id) 84 | INNER JOIN rental USING(inventory_id) 85 | WHERE rental.return_date IS NULL 86 | LIMIT 1; 87 | 88 | #Hago un update a rental para decir que la pelicula fue devuelta 89 | UPDATE sakila.rental 90 | SET return_date=CURRENT_TIMESTAMP 91 | WHERE rental_id=11496; 92 | ``` 93 | 94 | 5- Try to delete a film 95 | - Check what happens, describe what to do. 96 | - Write all the necessary delete statements to entirely remove the film from the DB. 97 | 98 | ```sql 99 | DELETE FROM payment 100 | WHERE rental_id IN (SELECT rental_id 101 | FROM rental 102 | INNER JOIN inventory USING (inventory_id) 103 | WHERE film_id = 1); 104 | 105 | DELETE FROM rental 106 | WHERE inventory_id IN (SELECT inventory_id 107 | FROM inventory 108 | WHERE film_id = 1); 109 | 110 | DELETE FROM inventory WHERE film_id = 1; 111 | 112 | DELETE film_actor FROM film_actor WHERE film_id = 1; 113 | 114 | DELETE film_category FROM film_category WHERE film_id = 1; 115 | 116 | DELETE film FROM film WHERE film_id = 1; 117 | 118 | ``` 119 | 120 | 6- Rent a film 121 | - Find an inventory id that is available for rent (available in store) pick any movie. Save this id somewhere. 122 | - Add a rental entry 123 | - Add a payment entry 124 | - Use sub-queries for everything, except for the inventory id that can be used directly in the queries. 125 | 126 | ```sql 127 | SELECT inventory_id, film_id 128 | 129 | FROM inventory 130 | 131 | WHERE inventory_id NOT IN (SELECT inventory_id 132 | 133 | FROM inventory 134 | 135 | INNER JOIN rental USING (inventory_id) 136 | 137 | WHERE return_date IS NULL) 138 | 139 | # inventory id to use: 10 140 | 141 | # film id to use: 2 142 | 143 | INSERT INTO sakila.rental 144 | 145 | (rental_date, inventory_id, customer_id, staff_id) 146 | 147 | VALUES( 148 | 149 | CURRENT_DATE(), 150 | 151 | 10, 152 | 153 | (SELECT customer_id FROM customer ORDER BY customer_id DESC LIMIT 1), 154 | 155 | (SELECT staff_id FROM staff WHERE store_id = (SELECT store_id FROM inventory WHERE inventory_id = 10)) 156 | 157 | ); 158 | 159 | INSERT INTO sakila.payment 160 | 161 | (customer_id, staff_id, rental_id, amount, payment_date) 162 | 163 | VALUES( 164 | 165 | (SELECT customer_id FROM customer ORDER BY customer_id DESC LIMIT 1), 166 | 167 | (SELECT staff_id FROM staff LIMIT 1), 168 | 169 | (SELECT rental_id FROM rental ORDER BY rental_id DESC LIMIT 1) , 170 | 171 | (SELECT rental_rate FROM film WHERE film_id = 2), 172 | 173 | CURRENT_DATE()); 174 | 175 | ``` 176 | 177 | # Class 14 178 | 179 | ```sql 180 | -- 1 181 | 182 | SELECT CONCAT_WS(" ",first_name,last_name) as full_name, address.address, city.city 183 | FROM customer 184 | INNER JOIN address USING(address_id) 185 | INNER JOIN city USING(city_id) 186 | INNER JOIN country USING(country_id) 187 | WHERE country.country LIKE 'Argentina'; 188 | ``` 189 | 190 | ```sql 191 | -- 2 192 | 193 | SELECT title, 194 | `language`.name, 195 | CASE 196 | WHEN rating = 'G' THEN 'All Ages Are Admitted.' 197 | WHEN rating = 'PG' THEN 'Some Material May Not Be Suitable For Children.' 198 | WHEN rating = 'PG-13' THEN 'Some Material May Be Inappropriate For Children Under 13.' 199 | WHEN rating = 'R' THEN 'Under 17 Requires Accompanying Parent Or Adult Guardian.' 200 | WHEN rating = 'NC-17' THEN 'No One 17 and Under Admitted.' 201 | END AS rating_description 202 | FROM film 203 | INNER JOIN `language` USING (language_id); 204 | ``` 205 | 206 | ```sql 207 | -- 3 208 | 209 | SELECT title, release_year 210 | FROM film 211 | INNER JOIN film_actor USING(film_id) 212 | INNER JOIN actor USING(actor_id) 213 | WHERE CONCAT_WS(" ",first_name,last_name) LIKE TRIM(UPPER(" johNNy lollobRigidA ")); 214 | ``` 215 | 216 | ```sql 217 | -- 4 218 | 219 | SELECT film.title, 220 | CONCAT_WS(" ", customer.first_name, customer.last_name) as full_name, 221 | CASE WHEN rental.return_date IS NOT NULL THEN 'Yes' 222 | ELSE 'No' END AS was_returned, 223 | MONTHNAME(rental.rental_date) as month 224 | FROM film 225 | INNER JOIN inventory USING(film_id) 226 | INNER JOIN rental USING(inventory_id) 227 | INNER JOIN customer USING(customer_id) 228 | WHERE MONTHNAME(rental.rental_date) LIKE 'May' 229 | OR MONTHNAME(rental.rental_date) LIKE 'June'; 230 | ``` 231 | 232 | ```sql 233 | -- 5 234 | 235 | -- CAST and CONVERT have barely no differences between them. 236 | -- While CAST has a slightly distinct syntax than CONVERT,they're both used to convert data from one type to another. 237 | 238 | SELECT CAST(last_update AS DATE) as only_date 239 | FROM rental; 240 | 241 | SELECT CONVERT("2006-02-15", DATETIME); 242 | ``` 243 | 244 | ```sql 245 | -- 6 246 | 247 | -- NVL() and IFNULL() functions work in the same way: 248 | -- they check whether an expression is NULL or not; if it is, they return a second expression (a default value). 249 | 250 | -- NVL() is an Oracle function, so here is an IFNULL() example: 251 | 252 | SELECT rental_id, IFNULL(return_date, 'La pelicula no fue devuelta aun') as fecha_de_devolucion 253 | FROM rental 254 | WHERE rental_id = 12610 255 | OR rental_id = 12611; 256 | 257 | -- ISNULL() function returns 1 if the expression passed is NULL, otherwise it returns 0. 258 | 259 | SELECT rental_id, ISNULL(return_date) as pelicula_faltante 260 | FROM rental 261 | WHERE rental_id = 12610 262 | OR rental_id = 12611; 263 | 264 | -- COALESCE() function returns the first non-NULL argument of the passed list. 265 | 266 | SELECT COALESCE(NULL, 267 | NULL, 268 | (SELECT return_date 269 | FROM rental 270 | WHERE rental_id = 12610), -- null date 271 | (SELECT return_date 272 | FROM rental 273 | WHERE rental_id = 12611)) as primer_valor_no_nulo; 274 | ``` 275 | 276 | # Class 15 277 | 278 | ```sql 279 | -- 1 280 | 281 | CREATE OR REPLACE VIEW list_of_customers AS 282 | SELECT customer_id, 283 | CONCAT_WS(" " ,first_name, last_name) as full_name, 284 | address, 285 | postal_code, 286 | phone, 287 | city, 288 | country, 289 | CASE 290 | WHEN active = 1 THEN 'active' 291 | ELSE 'inactive' 292 | END AS status, 293 | store_id 294 | FROM customer 295 | INNER JOIN address USING(address_id) 296 | INNER JOIN city USING(city_id) 297 | INNER JOIN country USING(country_id); 298 | 299 | SELECT * FROM list_of_customers; 300 | ``` 301 | 302 | ```sql 303 | -- 2 304 | 305 | CREATE OR REPLACE VIEW film_details AS 306 | SELECT film_id, 307 | title, 308 | description, 309 | name, 310 | rental_rate, 311 | `length`, 312 | rating, 313 | GROUP_CONCAT(DISTINCT CONCAT_WS(" " ,first_name, last_name) SEPARATOR ',') AS actores 314 | FROM film 315 | INNER JOIN film_category USING(film_id) 316 | INNER JOIN category USING(category_id) 317 | INNER JOIN film_actor USING(film_id) 318 | INNER JOIN actor USING(actor_id) 319 | GROUP BY 1,4; 320 | 321 | SELECT * FROM film_details; 322 | ``` 323 | 324 | ```sql 325 | -- 3 326 | 327 | CREATE OR REPLACE VIEW sales_by_film_category AS 328 | SELECT DISTINCT category.name, SUM(amount) as total_rental FROM category 329 | INNER JOIN film_category USING(category_id) 330 | INNER JOIN film USING(film_id) 331 | INNER JOIN inventory USING(film_id) 332 | INNER JOIN rental USING(inventory_id) 333 | INNER JOIN payment USING(rental_id) 334 | GROUP BY 1; 335 | 336 | 337 | SELECT * FROM sales_by_film_category; 338 | ``` 339 | 340 | ```sql 341 | -- 4 342 | 343 | CREATE OR REPLACE VIEW actor_information AS 344 | SELECT actor_id as id, 345 | first_name, 346 | last_name, 347 | (SELECT COUNT(film_id) 348 | FROM film 349 | INNER JOIN film_actor USING(film_id) 350 | INNER JOIN actor USING(actor_id) 351 | WHERE actor_id = id) AS films_participated_in 352 | FROM actor; 353 | 354 | SELECT * FROM actor_information; 355 | ``` 356 | 357 | ```sql 358 | -- 5 359 | 360 | -- This view fetches values from table actor, and joins them whenever it can with values from tables film_actor, film_category 361 | -- and category. This meaning that they will only be joined in case the actor has acted in a film. 362 | -- It displays the data in four columns. The first three of them are just basic actor data: its name, surname and id. 363 | -- The fourth column, called film_info, displays every film the actor has acted on, grouped by category. 364 | -- The query achieves this by concatenating every category with the group of films that belongs to it and, after that, 365 | -- concatenating the groups of categories with its films together. 366 | ``` 367 | 368 | ```sql 369 | -- 6 370 | 371 | -- Materialized views are a form of chaching query results.The main difference between this type of views the ordinary ones 372 | -- is that Materialized views are concrete tables that store the results of a query. 373 | -- They are used to improve performance and exist in a variety of DBMSs, but not in MySQL. In this last scenario you could 374 | -- implement some workaround by using triggers or stored procedures. 375 | ``` 376 | 377 | # Class 16 378 | 379 | ```sql 380 | CREATE TABLE `employees` ( 381 | `employeeNumber` int(11) NOT NULL, 382 | `lastName` varchar(50) NOT NULL, 383 | `firstName` varchar(50) NOT NULL, 384 | `extension` varchar(10) NOT NULL, 385 | `email` varchar(100) NOT NULL, 386 | `officeCode` varchar(10) NOT NULL, 387 | `reportsTo` int(11) DEFAULT NULL, 388 | `jobTitle` varchar(50) NOT NULL, 389 | PRIMARY KEY (`employeeNumber`) 390 | ); 391 | 392 | INSERT INTO `employees`(`employeeNumber`,`lastName`,`firstName`,`extension`,`email`,`officeCode`,`reportsTo`,`jobTitle`) VALUES 393 | (1002,'Murphy','Diane','x5800','dmurphy@classicmodelcars.com','1',NULL,'President'), 394 | (1056,'Patterson','Mary','x4611','mpatterso@classicmodelcars.com','1',1002,'VP Sales'), 395 | (1076,'Firrelli','Jeff','x9273','jfirrelli@classicmodelcars.com','1',1002,'VP Marketing'); 396 | 397 | CREATE TABLE employees_audit ( 398 | id INT AUTO_INCREMENT PRIMARY KEY, 399 | employeeNumber INT NOT NULL, 400 | lastname VARCHAR(50) NOT NULL, 401 | changedat DATETIME DEFAULT NULL, 402 | action VARCHAR(50) DEFAULT NULL 403 | ); 404 | ``` 405 | 406 | ```sql 407 | -- 1 408 | 409 | -- It throws an error because of the NOT NULL constraint we added on the email attribute when we created the table. 410 | 411 | INSERT INTO `employees`(`employeeNumber`,`lastName`,`firstName`,`extension`,`email`,`officeCode`,`reportsTo`,`jobTitle`) VALUES 412 | (1056,'Patterson','Mary','x4611',NULL,'1',1002,'VP Sales'); 413 | ``` 414 | 415 | ```sql 416 | -- 2 417 | 418 | UPDATE employees set employeeNumber = employeeNumber - 20; 419 | 420 | -- Esa querie funciona y actualiza todas las rows, porque el motor la ejecuta sequencialmente el update, por lo que aunque la distancia entre 2 ids es 20 el update ocurre primero en la fila del medio y por lo tanto nunca coliciona. 421 | 422 | UPDATE employees set employeeNumber = employeeNumber + 20; 423 | 424 | -- En este caso, cuando la fila del medio actualiza su valor, este es el mismo que la de la tercer fila por lo tanto tanto no puede hacer el update por el constraint de la primary key. 425 | 426 | ``` 427 | 428 | ```sql 429 | -- 3 430 | 431 | ALTER TABLE employees 432 | ADD age TINYINT UNSIGNED DEFAULT 69; 433 | 434 | ALTER TABLE employees 435 | ADD CONSTRAINT age CHECK(age >= 16 AND age <= 70); 436 | ``` 437 | 438 | ```sql 439 | -- 5 440 | 441 | ALTER TABLE employees 442 | ADD COLUMN lastUpdate DATETIME; 443 | 444 | 445 | ALTER TABLE employees 446 | ADD COLUMN lastUpdateUser VARCHAR(255); 447 | 448 | 449 | CREATE TRIGGER before_employee_update 450 | BEFORE UPDATE ON employees 451 | FOR EACH ROW 452 | BEGIN 453 | SET NEW.lastUpdate=NOW(); 454 | SET NEW.lastUpdateUser=CURRENT_USER; 455 | END; 456 | 457 | 458 | update employees set lastName = 'Phanny' where employeeNumber = 1076; 459 | ``` 460 | 461 | ```sql 462 | -- 6 463 | 464 | -- ins_film Inserts a new film_text entry, with the same values as the added film. 465 | 466 | BEGIN 467 | INSERT INTO film_text (film_id, title, description) 468 | VALUES (new.film_id, new.title, new.description); 469 | END 470 | 471 | -- upd_film Updates the corresponding existing film_text entry for the updated film. 472 | 473 | BEGIN 474 | IF (old.title != new.title) OR (old.description != new.description) OR (old.film_id != new.film_id) 475 | THEN 476 | UPDATE film_text 477 | SET title=new.title, 478 | description=new.description, 479 | film_id=new.film_id 480 | WHERE film_id=old.film_id; 481 | END IF; 482 | END 483 | 484 | -- del_film Deletes the corresponding existing film_text entry for the deleted film. 485 | 486 | BEGIN 487 | DELETE FROM film_text WHERE film_id = old.film_id; 488 | END 489 | ``` -------------------------------------------------------------------------------- /classes/monogdb-querys.md: -------------------------------------------------------------------------------- 1 | # Query REFERENCE 2 | 3 | ## Select All Documents in a Collection 4 | db.films.find( {} ) 5 | 6 | ## Specify Equality Condition 7 | 8 | To specify equality conditions, use : expressions in the query filter document: 9 | > `{ : , ... }` 10 | 11 | #### Specify Conditions Using Query Operators 12 | > `{ : { : }, ... }` 13 | 14 | #### Specify AND Conditions 15 | A compound query can specify conditions for more than one field in the collection’s documents. Implicitly, a logical AND conjunction connects the clauses of a compound query so that the query selects the documents in the collection that match all the conditions. 16 | 17 | >`db.customers.find({'First Name':'MARY', 'Last Name':'SMITH'})` 18 | 19 | #### Specify OR Conditions 20 | Using the **$or** operator, you can specify a compound query that joins each clause with a logical OR conjunction so that the query selects the documents in the collection that match at least one condition. 21 | 22 | > `db.films.find( { $or: [ { Category: "Documentary" }, { Rating: { $lt: 30 } } ] } )` 23 | 24 | #### Specify AND as well as OR Conditions 25 | In the following example, the compound query document selects all documents in the collection where the film Category is Documentary and Length is equals 86 Or Rating is less than 30. 26 | 27 | > `db.films.find( {Category: "Documentary", $or: [ { Length:'86' }, { Rating: { $lt: 30 } } ] } ) ` 28 | 29 | ### Filter equal 30 | * Example for comparations where (equals) 31 | > `db.films.find({Length:86})` 32 | 33 | * Example for comparations where (less than...) 34 | > `db.films.find({Length: {$lt:86 }})` 35 | * Example for comparations where (less than or equals ...) 36 | > `db.films.find({Length: {$lte:86 }})` 37 | 38 | * Example for comparations where (grater than...) 39 | > `db.films.find({Length: {$gt:86 }})` 40 | * Example for comparations where (grater than or equals ...) 41 | > `db.films.find({Length: {$gte:86 }})` 42 | 43 | 44 | ### Filter likes 45 | 46 | * Example for where like = 'MARY' 47 | >`db.customers.find({'First Name':'MARY'})` 48 | 49 | * With where like = "MAR%" 50 | >`db.customers.find({'First Name':/^MAR/})` 51 | 52 | * With where like = "%ARY" 53 | >`db.customers.find({'First Name':/ARY$/})` 54 | 55 | * With where like = "%AR%" 56 | >`db.customers.find({'First Name':/AR/})` 57 | 58 | ### In clause 59 | 60 | > `db.films.find({Rating: {$in:["G","PG"]}})` 61 | 62 | ## Return the Specified Fields and the _id Field Only 63 | A projection can explicitly include several fields by setting the to 1 in the projection document. The following operation returns all documents that match the query. In the result set, only the title and, by default, the _id fields return in the matching documents. 64 | 65 | > `db.films.find({Rating: {$in:["G","PG"]}} , {Title:1} )` 66 | 67 | If you need remove _id field, setting **_id** to 0: 68 | 69 | > `db.films.find({Rating: {$in:["G","PG"]}} , {Title:1, _id:0} )` 70 | 71 | 72 | -------------------------------------------------------------------------------- /classes/multidimension.md: -------------------------------------------------------------------------------- 1 | ## What is Dimensional Model? 2 | A dimensional model is a data structure technique optimized for Data warehousing tools. The concept of Dimensional Modelling was developed by Ralph Kimball and is comprised of "fact" and "dimension" tables. 3 | 4 | A Dimensional model is designed to read, summarize, analyze numeric information like values, balances, counts, weights, etc. in a data warehouse. In contrast, relation models are optimized for addition, updating and deletion of data in a real-time Online Transaction System. 5 | 6 | These dimensional and relational models have their unique way of data storage that has specific advantages. 7 | 8 | For instance, in the relational mode, normalization and ER models reduce redundancy in data. On the contrary, dimensional model arranges data in such a way that it is easier to retrieve information and generate reports. 9 | 10 | ## Elements of Dimensional Data Model 11 | ### Fact 12 | Facts are the measurements/metrics or facts from your business process. For a Sales business process, a measurement would be quarterly sales number 13 | 14 | ### Dimension 15 | Dimension provides the context surrounding a business process event. In simple terms, they give who, what, where of a fact. In the Sales business process, for the fact quarterly sales number, dimensions would be 16 | 17 | - Who – Customer Names 18 | - Where – Location 19 | - What – Product Name 20 | 21 | In other words, a dimension is a window to view information in the facts. 22 | 23 | ### Attributes 24 | The Attributes are the various characteristics of the dimension. 25 | 26 | In the Location dimension, the attributes can be 27 | 28 | State 29 | Country 30 | Zipcode etc. 31 | Attributes are used to search, filter, or classify facts. Dimension Tables contain Attributes 32 | 33 | ### Fact Table 34 | A fact table is a primary table in a dimensional model. 35 | 36 | A Fact Table contains 37 | 38 | Measurements/facts 39 | Foreign key to dimension table 40 | 41 | ### Dimension table 42 | - A dimension table contains dimensions of a fact. 43 | - They are joined to fact table via a foreign key. 44 | - Dimension tables are de-normalized tables. 45 | - The Dimension Attributes are the various columns in a dimension table 46 | - Dimensions offers descriptive characteristics of the facts with the help of their attributes 47 | - No set limit set for given for number of dimensions 48 | - The dimension can also contain one or more hierarchical relationships 49 | 50 | ## What is a Star Schema? 51 | 52 | The star schema is the simplest type of Data Warehouse schema. It is known as star schema as its structure resembles a star. In the Star schema, the center of the star can have one fact tables and numbers of associated dimension tables. It is also known as Star Join Schema and is optimized for querying large data sets. 53 | 54 | ![star-schema](../images/star-schema.png) 55 | 56 | ## Introduction to the PostgreSQL **CUBE** 57 | PostgreSQL CUBE is a subclause of the GROUP BY clause. The CUBE allows you to generate multiple grouping sets. 58 | 59 | The following query uses the CUBE subclause to generate multiple grouping sets: 60 | 61 | ```sql 62 | SELECT 63 | brand, 64 | segment, 65 | SUM (quantity) 66 | FROM 67 | sales 68 | GROUP BY 69 | CUBE (brand, segment) 70 | ORDER BY 71 | brand, 72 | segment; 73 | ``` 74 | 75 | ![cube-example](../images/cube-example.png) 76 | 77 | The following query performs a partial cube: 78 | 79 | ```sql 80 | SELECT 81 | brand, 82 | segment, 83 | SUM (quantity) 84 | FROM 85 | sales 86 | GROUP BY 87 | brand, 88 | CUBE (segment) 89 | ORDER BY 90 | brand, 91 | segment; 92 | ``` 93 | 94 | ![partial-cube-example](../images/partial-cube-example.png) 95 | 96 | ## Introduction to the PostgreSQL **ROLLUP** 97 | 98 | The PostgreSQL ROLLUP is a subclause of the GROUP BY clause that offers a shorthand for defining multiple grouping sets. 99 | 100 | Different from the CUBE subclause, ROLLUP does not generate all possible grouping sets based on the specified columns. It just makes a subset of those. 101 | 102 | PostgreSQL ROLLUP examples 103 | The following query uses the ROLLUP subclause to find the number of products sold by brand (subtotal) and by all brands and segments (total). 104 | 105 | ```sql 106 | SELECT 107 | brand, 108 | segment, 109 | SUM (quantity) 110 | FROM 111 | sales 112 | GROUP BY 113 | ROLLUP (brand, segment) 114 | ORDER BY 115 | brand, 116 | segment; 117 | ``` 118 | 119 | ![rollup-example](../images/rollup-example.png) 120 | 121 | The following statement performs a partial roll-up: 122 | 123 | ``` 124 | SELECT 125 | segment, 126 | brand, 127 | SUM (quantity) 128 | FROM 129 | sales 130 | GROUP BY 131 | segment, 132 | ROLLUP (brand) 133 | ORDER BY 134 | segment, 135 | brand; 136 | ``` 137 | 138 | ![partial-rollup-example](../images/partial-rollup-example.png) 139 | 140 | 141 | ## Excersices 142 | 143 | 1. Retrieve Internet Sales Amount As Per Customer. In other words, we can say show the Detail of amount spent by customers during purchase from Internet. 144 | 145 | 2. View Internet Sales amount detail between year 2005 to 2008 146 | 147 | 3. View Internet Sales by product category and sub-category. 148 | 149 | 4. View Internet Sales and Freight Cost by product category, sub-category and product. 150 | 151 | 5. Retrieve only those products whose names begin with “A” and Internet sales amount <5000 152 | 153 | 6. What is sales amount in all the countries?? 154 | 155 | 7. Retrieve all the products in descending order of their Internet sales amount of year 2007 156 | 157 | 8. Generate a report with Internet Sales sub total, grand total per year and month. 158 | 159 | 9. TBD 160 | 161 | 10. TBD -------------------------------------------------------------------------------- /classes/multidimensional-model.md: -------------------------------------------------------------------------------- 1 | ## What is Dimensional Model? 2 | A dimensional model is a data structure technique optimized for Data warehousing tools. The concept of Dimensional Modelling was developed by Ralph Kimball and is comprised of "fact" and "dimension" tables. 3 | 4 | A Dimensional model is designed to read, summarize, analyze numeric information like values, balances, counts, weights, etc. in a data warehouse. In contrast, relation models are optimized for addition, updating and deletion of data in a real-time Online Transaction System. 5 | 6 | These dimensional and relational models have their unique way of data storage that has specific advantages. 7 | 8 | For instance, in the relational mode, normalization and ER models reduce redundancy in data. On the contrary, dimensional model arranges data in such a way that it is easier to retrieve information and generate reports. 9 | 10 | ## Elements of Dimensional Data Model 11 | ### Fact 12 | Facts are the measurements/metrics or facts from your business process. For a Sales business process, a measurement would be quarterly sales number 13 | 14 | ### Dimension 15 | Dimension provides the context surrounding a business process event. In simple terms, they give who, what, where of a fact. In the Sales business process, for the fact quarterly sales number, dimensions would be 16 | 17 | - Who – Customer Names 18 | - Where – Location 19 | - What – Product Name 20 | 21 | In other words, a dimension is a window to view information in the facts. 22 | 23 | ### Attributes 24 | The Attributes are the various characteristics of the dimension. 25 | 26 | In the Location dimension, the attributes can be 27 | 28 | State 29 | Country 30 | Zipcode etc. 31 | Attributes are used to search, filter, or classify facts. Dimension Tables contain Attributes 32 | 33 | ### Fact Table 34 | A fact table is a primary table in a dimensional model. 35 | 36 | A Fact Table contains 37 | 38 | Measurements/facts 39 | Foreign key to dimension table 40 | 41 | ### Dimension table 42 | - A dimension table contains dimensions of a fact. 43 | - They are joined to fact table via a foreign key. 44 | - Dimension tables are de-normalized tables. 45 | - The Dimension Attributes are the various columns in a dimension table 46 | - Dimensions offers descriptive characteristics of the facts with the help of their attributes 47 | - No set limit set for given for number of dimensions 48 | - The dimension can also contain one or more hierarchical relationships 49 | 50 | ## What is a Star Schema? 51 | 52 | The star schema is the simplest type of Data Warehouse schema. It is known as star schema as its structure resembles a star. In the Star schema, the center of the star can have one fact tables and numbers of associated dimension tables. It is also known as Star Join Schema and is optimized for querying large data sets. 53 | 54 | ![star-schema](../images/star-schema.png) 55 | 56 | ## Introduction to the PostgreSQL **CUBE** 57 | PostgreSQL CUBE is a subclause of the GROUP BY clause. The CUBE allows you to generate multiple grouping sets. 58 | 59 | The following query uses the CUBE subclause to generate multiple grouping sets: 60 | 61 | ```sql 62 | SELECT 63 | brand, 64 | segment, 65 | SUM (quantity) 66 | FROM 67 | sales 68 | GROUP BY 69 | CUBE (brand, segment) 70 | ORDER BY 71 | brand, 72 | segment; 73 | ``` 74 | 75 | ![cube-example](../images/cube-example.png) 76 | 77 | The following query performs a partial cube: 78 | 79 | ```sql 80 | SELECT 81 | brand, 82 | segment, 83 | SUM (quantity) 84 | FROM 85 | sales 86 | GROUP BY 87 | brand, 88 | CUBE (segment) 89 | ORDER BY 90 | brand, 91 | segment; 92 | ``` 93 | 94 | ![partial-cube-example](../images/partial-cube-example.png) 95 | 96 | ## Introduction to the PostgreSQL **ROLLUP** 97 | 98 | The PostgreSQL ROLLUP is a subclause of the GROUP BY clause that offers a shorthand for defining multiple grouping sets. 99 | 100 | Different from the CUBE subclause, ROLLUP does not generate all possible grouping sets based on the specified columns. It just makes a subset of those. 101 | 102 | PostgreSQL ROLLUP examples 103 | The following query uses the ROLLUP subclause to find the number of products sold by brand (subtotal) and by all brands and segments (total). 104 | 105 | ```sql 106 | SELECT 107 | brand, 108 | segment, 109 | SUM (quantity) 110 | FROM 111 | sales 112 | GROUP BY 113 | ROLLUP (brand, segment) 114 | ORDER BY 115 | brand, 116 | segment; 117 | ``` 118 | 119 | ![rollup-example](../images/rollup-example.png) 120 | 121 | The following statement performs a partial roll-up: 122 | 123 | ``` 124 | SELECT 125 | segment, 126 | brand, 127 | SUM (quantity) 128 | FROM 129 | sales 130 | GROUP BY 131 | segment, 132 | ROLLUP (brand) 133 | ORDER BY 134 | segment, 135 | brand; 136 | ``` 137 | 138 | ![partial-rollup-example](../images/partial-rollup-example.png) 139 | 140 | 141 | ## Excersices 142 | 143 | 1. Retrieve Internet Sales Amount As Per Customer. In other words, we can say show the Detail of amount spent by customers during purchase from Internet. 144 | 145 | 2. View Internet Sales amount detail between year 2005 to 2008 146 | 147 | 3. View Internet Sales by product category and sub-category. 148 | 149 | 4. View Internet Sales and Freight Cost by product category, sub-category and product. 150 | 151 | 5. Retrieve only those products whose names begin with “A” and Internet sales amount <5000 152 | 153 | 6. What is sales amount in all the countries?? 154 | 155 | 7. Retrieve all the products in descending order of their Internet sales amount of year 2007 156 | 157 | 8. Generate a report with Internet Sales sub total, grand total per year and month. 158 | 159 | 9. Generate a report with the amount of "Pedals" and "Tires and Tubes" category of products in the inventory. Also with the amount of in and outs of each of them on the second half of the year 2006. 160 | 161 | 10. Generate a report with the amount of calls, automatic responses and issues raised by the call center operators. On working days during the morning shift, from the 20th working week until the end of the year 2007. -------------------------------------------------------------------------------- /classes/mysql_administration.md: -------------------------------------------------------------------------------- 1 | ## Introduction to user accounts in MySQL 2 | MySQL Create UserIn MySQL, you can specify not only who can connect to the database server but also from which host that the user connects. Therefore, a user account in MySQL consists of a username and a host name separated by the @ character. 3 | 4 | 5 | For example, if the admin user connects to the MySQL database server from localhost, the user account is admin@localhost 6 | 7 | 8 | The admin user only can connect to the MySQL database server from the localhost, not from a remote host such as apache.org. This makes the MySQL database server even more secure. 9 | 10 | In addition, by combining the username and host, it is possible to setup multiple accounts with the same name but can connect from different hosts with the different privileges. 11 | 12 | MySQL stored the user accounts in the user grant table of the mysql database. 13 | 14 | ### Creating user accounts using MySQL CREATE USER statement 15 | MySQL provides the CREATE USER statement that allows you to create a new user account. The syntax of the CREATE USER statement is as follows: 16 | 17 | ```sql 18 | CREATE USER user_account IDENTIFIED BY password; 19 | ``` 20 | 21 | The user_account in the format 'username'@'hostname' is followed by the CREATE USER clause. 22 | 23 | The password is specified in the IDENTIFIED BY clause. The password must be in clear text. MySQL will encrypt the password before saving the user account into the user table. 24 | 25 | For example, to create a new user dbadmin that connects to the MySQL database server from the localhost with the password secret, you use the CREATE USER statement as follows: 26 | 27 | ```sql 28 | CREATE USER dbadmin@localhost 29 | IDENTIFIED BY 'secret'; 30 | ``` 31 | 32 | To view the privileges of a user account, you use the SHOW GRANTS statement as follows: 33 | 34 | ```sql 35 | SHOW GRANTS FOR dbadmin@localhost; 36 | ``` 37 | 38 | To allow a user account to connect from any host, you use the percentage (%) wildcard as shown in the following example: 39 | 40 | ```sql 41 | CREATE USER superadmin@'%' 42 | IDENTIFIED BY 'secret'; 43 | ``` 44 | 45 | The percentage wildcard % has the same effect as it is used in the LIKE operator e.g., to allow mysqladmin user account to connect to the database server from any subdomain. 46 | 47 | ### Change MySQL user password 48 | #### Using UPDATE statement 49 | The first way to change the password is to use the UPDATE statement to update the user table of the mysql database. 50 | 51 | ```sql 52 | -- MYSQL < 5.7.6 53 | USE mysql; 54 | 55 | UPDATE user 56 | SET password = PASSWORD('dolphin') 57 | WHERE user = 'dbadmin' AND 58 | host = 'localhost'; 59 | 60 | FLUSH PRIVILEGES; 61 | ``` 62 | ```sql 63 | -- MYSQL 5.7.6+ 64 | USE mysql; 65 | 66 | UPDATE user 67 | SET authentication_string = PASSWORD('dolphin') 68 | WHERE user = 'dbadmin' AND 69 | host = 'localhost'; 70 | 71 | FLUSH PRIVILEGES; 72 | ``` 73 | 74 | #### Using the SET PASSWORD statement 75 | 76 | ```sql 77 | SET PASSWORD FOR 'dbadmin'@'localhost' = PASSWORD('bigshark'); 78 | ``` 79 | 80 | ### Using ALTER USER statement 81 | 82 | ```sql 83 | ALTER USER dbadmin@localhost IDENTIFIED BY 'littlewhale'; 84 | ``` 85 | 86 | ## MySQL GRANT statement 87 | After creating a new user account, the user doesn’t have any privileges. To grant privileges to a user account, you use the GRANT statement. 88 | 89 | The following illustrates the syntax of the GRANT statement: 90 | 91 | ```sql 92 | GRANT privilege,[privilege],.. ON privilege_level 93 | TO user [IDENTIFIED BY password] 94 | [REQUIRE tsl_option] 95 | [WITH [GRANT_OPTION | resource_option]]; 96 | ``` 97 | 98 | Let’s examine the GRANT statement in greater detail. 99 | 100 | - First, specify one or more privileges after the GRANT keyword. If you grant the user multiple privileges, each privilege is separated by a comma. (see a list of privilege in the table below). 101 | 102 | - Next, specify the privilege_level that determines the level at which the privileges apply. MySQL supports global ( *.*), database ( database.*), table ( database.table) and column levels. If you use column privilege level, you must specify one or a list of comma-separated column after each privilege. 103 | 104 | - Then, place the user that you want to grant privileges. If user already exists, the GRANT statement modifies its privilege. Otherwise, the GRANT statement creates a new user. The optional clauseIDENTIFIED BY allows you set a new password for the user. 105 | 106 | - After that, you specify whether the user has to connect to the database server over a secure connection such as SSL, X059, etc. 107 | 108 | - Finally, the optional WITH GRANT OPTION clause allows you to grant other users or remove from other users the privileges that you possess. In addition, you can use the WITH clause to allocate MySQL database server’s resource e.g., to set how many connections or statements that the user can use per hour. This is very helpful in the shared environments such as MySQL shared hosting. 109 | 110 | Notice that in order to use the GRANT statement, you must have the GRANT OPTION privilege and the privileges that you are granting. If the read_only system variable is enabled, you need to have the SUPER privilege to execute the GRANT statement. 111 | 112 | ### Examples 113 | ```sql 114 | CREATE USER super@localhost IDENTIFIED BY 'dolphin'; 115 | ``` 116 | 117 | ```sql 118 | SHOWS GRANTS FOR super@localhost; 119 | ``` 120 | 121 | ```sql 122 | GRANT ALL ON *.* TO 'super'@'localhost' WITH GRANT OPTION; 123 | ``` 124 | 125 | ### Grant Details 126 | 127 | 128 | | Privilege | Meaning | Global | Database | Table | Column | Procedure | Proxy | 129 | |-------------------------|-----------------------------------------------------------------------------------------------------------------------------------------|--------|----------|-------|--------|-----------|-------| 130 | | ALL [PRIVILEGES] | Grant all privileges at specified access level except GRANT OPTION | | | | | | | 131 | | ALTER | Allow user to use of ALTER TABLE statement | X | X | X | | | | 132 | | ALTER ROUTINE | Allow user to alter or drop stored routine | X | X | | | X | | 133 | | CREATE | Allow user to create database and table | X | X | X | | | | 134 | | CREATE ROUTINE | Allow user to create stored routine | X | X | | | | | 135 | | CREATE TABLESPACE | Allow user to create, alter or drop tablespaces and log file groups | X | | | | | | 136 | | CREATE TEMPORARY TABLES | Allow user to create temporary table by using CREATE TEMPORARY TABLE | X | X | | | | | 137 | | CREATE USER | Allow user to use the CREATE USER, DROP USER, RENAME USER, and REVOKE ALL PRIVILEGES statements. | X | | | | | | 138 | | CREATE VIEW | Allow user to create or modify view. | X | X | X | | | | 139 | | DELETE | Allow user to use DELETE | X | X | X | | | | 140 | | DROP | Allow user to drop database, table and view | X | X | X | | | | 141 | | EVENT | Enable use of events for the Event Scheduler. | X | X | | | | | 142 | | EXECUTE | Allow user to execute stored routines | X | X | X | | | | 143 | | FILE | Allow user to read any file in the database directory. | X | | | | | | 144 | | GRANT OPTION | Allow user to have privileges to grant or revoke privileges from other accounts. | X | X | X | | X | X | 145 | | INDEX | Allow user to create or remove indexes. | X | X | X | | | | 146 | | INSERT | Allow user to use INSERT statement | X | X | X | X | | | 147 | | LOCK TABLES | Allow user to use LOCK TABLES on tables for which you have the SELECT privilege | X | X | | | | | 148 | | PROCESS | Allow user to see all processes with SHOW PROCESSLIST statement. | X | | | | | | 149 | | PROXY | Enable user proxying. | | | | | | | 150 | | REFERENCES | Allow user to create foreign key | X | X | X | X | | | 151 | | RELOAD | Allow user to use FLUSH operations | X | | | | | | 152 | | REPLICATION CLIENT | Allow user to query to see where master or slave servers are | X | | | | | | 153 | | REPLICATION SLAVE | Allow the user to use replicate slaves to read binary log events from the master. | X | | | | | | 154 | | SELECT | Allow user to use SELECT statement | X | X | X | X | | | 155 | | SHOW DATABASES | Allow user to show all databases | X | | | | | | 156 | | SHOW VIEW | Allow user to use SHOW CREATE VIEW statement | X | X | X | | | | 157 | | SHUTDOWN | Allow user to use mysqladmin shutdown command | X | | | | | | 158 | | SUPER | Allow user to use other administrative operations such as CHANGE MASTER TO, KILL, PURGE BINARY LOGS, SET GLOBAL, and mysqladmin command | X | | | | | | 159 | | TRIGGER | Allow user to use TRIGGER operations. | X | X | X | | | | 160 | | UPDATE | Allow user to use UPDATE statement | X | X | X | X | | | 161 | | USAGE | Equivalent to “no privileges” | | | | | | | 162 | 163 | ## Revoke 164 | 165 | Introduction to the MySQL REVOKE Statement 166 | In order to revoke privileges from a user account, you use the MySQL REVOKE statement. MySQL allows you to revoke one or more privileges or all privileges from a user. 167 | 168 | The following illustrates the syntax of revoking specific privileges from a user: 169 | 170 | ```sql 171 | REVOKE privilege_type [(column_list)] 172 | [, priv_type [(column_list)]]... 173 | ON [object_type] privilege_level 174 | FROM user [, user]... 175 | ``` 176 | 177 | Let’s examine the MySQL REVOKE statement in more detail. 178 | 179 | - First, specify a list of privileges that you want to revoke from a user right after the REVOKE keyword. You need to separate privileges by commas. 180 | - Second, specify the privilege level at which privileges is revoked in the ON clause . 181 | - Third, specify the user account that you want to revoke the privileges in the FROM clause. 182 | 183 | #### Examples 184 | 185 | ```sql 186 | -- revoke DELETE from all tables in classicmodels database 187 | REVOKE DELETE ON classicmodels.* FROM myuser; 188 | ``` 189 | 190 | ```sql 191 | -- revoke all the permissions 192 | REVOKE ALL PRIVILEGES, GRANT OPTION FROM myuser; 193 | ``` 194 | ## Exercises 195 | 196 | 1. Create a user **data_analyst** 197 | 2. Grant permissions only to SELECT, UPDATE and DELETE to all sakila tables to it. 198 | 3. Login with this user and try to create a table. Show the result of that operation. 199 | 4. Try to update a title of a film. Write the update script. 200 | 5. With **root** or any admin user revoke the UPDATE permission. Write the command 201 | 6. Login again with **data_analyst** and try again the update done in step 4. Show the result. 202 | -------------------------------------------------------------------------------- /classes/normalization.pptx: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/classes/normalization.pptx -------------------------------------------------------------------------------- /images/1NF.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/1NF.png -------------------------------------------------------------------------------- /images/2NFTable1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/2NFTable1.png -------------------------------------------------------------------------------- /images/2NFTable2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/2NFTable2.png -------------------------------------------------------------------------------- /images/2NFTable3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/2NFTable3.png -------------------------------------------------------------------------------- /images/CompositeKey.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/CompositeKey.png -------------------------------------------------------------------------------- /images/ForeignKeyRelationWithPrimary.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/ForeignKeyRelationWithPrimary.png -------------------------------------------------------------------------------- /images/MySQL-handler-precedence.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/MySQL-handler-precedence.jpg -------------------------------------------------------------------------------- /images/NormalizationTable1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/NormalizationTable1.png -------------------------------------------------------------------------------- /images/Table1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/Table1.png -------------------------------------------------------------------------------- /images/Table2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/Table2.png -------------------------------------------------------------------------------- /images/WhyDataBaseIsImportant.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/WhyDataBaseIsImportant.png -------------------------------------------------------------------------------- /images/cartesian-product.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/cartesian-product.png -------------------------------------------------------------------------------- /images/cube-example.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/cube-example.png -------------------------------------------------------------------------------- /images/database.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/database.png -------------------------------------------------------------------------------- /images/foreign_key_table.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/foreign_key_table.png -------------------------------------------------------------------------------- /images/inner-join-more-tables-explanation-1.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join-more-tables-explanation-1.png -------------------------------------------------------------------------------- /images/inner-join-more-tables-explanation-2.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join-more-tables-explanation-2.png -------------------------------------------------------------------------------- /images/inner-join-more-tables-explanation-3.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join-more-tables-explanation-3.png -------------------------------------------------------------------------------- /images/inner-join-more-tables.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join-more-tables.png -------------------------------------------------------------------------------- /images/inner-join-using-clause.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join-using-clause.png -------------------------------------------------------------------------------- /images/inner-join.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/inner-join.png -------------------------------------------------------------------------------- /images/left-outer-join.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/left-outer-join.png -------------------------------------------------------------------------------- /images/mysql-case-statement.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-case-statement.png -------------------------------------------------------------------------------- /images/mysql-cursor.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-cursor.png -------------------------------------------------------------------------------- /images/mysql-error-handling-duplicate-keys.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-error-handling-duplicate-keys.jpg -------------------------------------------------------------------------------- /images/mysql-error-handling.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-error-handling.jpg -------------------------------------------------------------------------------- /images/mysql-if-statement-flow-chart.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-if-statement-flow-chart.png -------------------------------------------------------------------------------- /images/mysql-resignal.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-resignal.jpg -------------------------------------------------------------------------------- /images/mysql-signal.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-signal.jpg -------------------------------------------------------------------------------- /images/mysql-stored-procedure1.jpg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/mysql-stored-procedure1.jpg -------------------------------------------------------------------------------- /images/natural-join.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/natural-join.png -------------------------------------------------------------------------------- /images/partial-cube-example.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/partial-cube-example.png -------------------------------------------------------------------------------- /images/partial-rollup-example.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/partial-rollup-example.png -------------------------------------------------------------------------------- /images/right-outer-join.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/right-outer-join.png -------------------------------------------------------------------------------- /images/rollup-example.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/rollup-example.png -------------------------------------------------------------------------------- /images/sakila-tables.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/sakila-tables.png -------------------------------------------------------------------------------- /images/star-schema.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/star-schema.png -------------------------------------------------------------------------------- /images/transitive_functional_dependencies.png: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/transitive_functional_dependencies.png -------------------------------------------------------------------------------- /images/what.jpeg: -------------------------------------------------------------------------------- https://raw.githubusercontent.com/alexisfr/itsv-db-2/3d2faf9744fddce2a95dedbc0e44c8d24a08314a/images/what.jpeg -------------------------------------------------------------------------------- /tools.md: -------------------------------------------------------------------------------- 1 | ## IDE 2 | 3 | Multi-platform database tool [DBeaver](http://dbeaver.jkiss.org/) 4 | 5 | 6 | ## Mysql with Sakila DB 7 | #### Prerequisites 8 | - Docker https://docs.docker.com/install/ 9 | 10 | ```bash 11 | mkdir ~/.mysql 12 | docker run --name mysql -e MYSQL_ROOT_PASSWORD=password -d -p 3306:3306 -v ~/.mysql:/var/lib/mysql mysql:5.7 13 | 14 | docker exec -it mysql mysql -uroot -p 15 | 16 | mysql> CREATE USER 'user'@'%' IDENTIFIED BY 'password'; 17 | mysql> GRANT ALL ON *.* TO 'user'@'%'; 18 | mysql> quit 19 | 20 | wget http://downloads.mysql.com/docs/sakila-db.tar.gz 21 | tar -zxvf sakila-db.tar.gz 22 | 23 | docker exec -i mysql mysql -uuser -ppassword < sakila-db/sakila-schema.sql 24 | docker exec -i mysql mysql -uuser -ppassword < sakila-db/sakila-data.sql 25 | ``` --------------------------------------------------------------------------------