├── README └── sql ├── README ├── chapter07.sql ├── tablesize.sql ├── chapter06.sql ├── chapter01.sql ├── chapter09.sql ├── chapter05.sql ├── chapter08.sql ├── chapter03.sql ├── chapter02.sql └── chapter04.sql /README: -------------------------------------------------------------------------------- 1 | -------------------------------------------------------------------------------- /sql/README: -------------------------------------------------------------------------------- 1 | env GIT_SSL_NO_VERIFY=true git push 2 | -------------------------------------------------------------------------------- /sql/chapter07.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter07.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | SET PROFILING=1; 12 | SELECT NOW(); 13 | SELECT BENCHMARK(1+1,100000); 14 | SELECT BENCHMARK('1'+'1',100000); 15 | SELECT SLEEP(1); 16 | SELECT SLEEP(2); 17 | SHOW PROFILES; 18 | 19 | # END 20 | -------------------------------------------------------------------------------- /sql/tablesize.sql: -------------------------------------------------------------------------------- 1 | SET @schema = IFNULL(@schema,DATABASE()); 2 | SELECT @schema as table_schema, CURDATE() AS today; 3 | SELECT table_name, 4 | engine,row_format AS format, table_rows, 5 | avg_row_length AS avg_row, 6 | round((data_length+index_length)/1024/1024,2) AS total_mb, 7 | round((data_length)/1024/1024,2) AS data_mb, 8 | round((index_length)/1024/1024,2) AS index_mb 9 | FROM INFORMATION_SCHEMA.tables 10 | WHERE table_schema=@schema 11 | AND table_name = @table 12 | \G 13 | -------------------------------------------------------------------------------- /sql/chapter06.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter06.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | # Named Key Buffers 12 | SET GLOBAL hot.key_buffer_size=1024*1024*64; 13 | CACHE INDEX table1, table2 IN hot; 14 | LOAD INDEX INTO CACHE table1, table2; 15 | 16 | # innodb_buffer_pool_size 17 | SHOW GLOBAL STATUS LIKE 'innodb_buffer%'; 18 | SHOW ENGINE INNODB STATUS; 19 | 20 | # query_cache_size 21 | SET GLOBAL query_cache_type = 1; 22 | SET GLOBAL query_cache_size = 1024 * 1024 * 16; 23 | SET GLOBAL query_cache_type = 0; 24 | SET GLOBAL query_cache_size = 0; 25 | SHOW GLOBAL STATUS LIKE 'Qcache%' 26 | 27 | # max_heap_table_size 28 | SET SESSION max_heap_table_size=1024*1024; 29 | CREATE TABLE t1( 30 | i INT NOT NULL AUTO_INCREMENT PRIMARY KEY, 31 | c VARCHAR(1024)) ENGINE=MEMORY; 32 | INSERT INTO t1(i) VALUES 33 | (NULL),(NULL),(NULL),(NULL),(NULL), 34 | (NULL),(NULL),(NULL),(NULL),(NULL); 35 | INSERT INTO t1(i) SELECT NULL FROM t1 AS a, t1 AS b, t1 AS c; 36 | 37 | # tmp_table_size 38 | SHOW SESSION STATUS LIKE 'create%tables'; 39 | SELECT ...; 40 | SHOW SESSION STATUS LIKE 'create%tables'; 41 | 42 | # END 43 | -------------------------------------------------------------------------------- /sql/chapter01.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter01.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | # 12 | # Pre-requisite table for queries 13 | # 14 | DROP TABLE IF EXISTS inventory; 15 | CREATE TABLE inventory ( 16 | id INT UNSIGNED NOT NULL AUTO_INCREMENT, 17 | supp_id INT UNSIGNED NOT NULL, 18 | item_id INT UNSIGNED NOT NULL, 19 | qty INT SIGNED NOT NULL, 20 | created DATETIME NOT NULL, 21 | PRIMARY KEY (id), 22 | UNIQUE KEY (supp_id, item_id), 23 | KEY created (created) 24 | ) ENGINE=InnoDB; 25 | 26 | # 27 | # Finding a Slow SQL Statement 28 | # 29 | SHOW FULL PROCESSLIST\G 30 | 31 | # 32 | # run and Time Your SQL Statement 33 | # 34 | SELECT * FROM inventory WHERE item_id = 16102176; 35 | 36 | # Generate a Query Execution Plan (QEP) 37 | EXPLAIN SELECT * FROM inventory WHERE item_id = 16102176\G 38 | 39 | # 40 | # What You Should Not do 41 | ALTER TABLE inventory ADD INDEX (item_id); 42 | 43 | # 44 | # Confirm Your Optimization 45 | # 46 | SELECT * FROM inventory WHERE item_id = 16102176; 47 | EXPLAIN SELECT * FROM inventory WHERE item_id = 16102176; 48 | 49 | # 50 | # The Correct Approach 51 | # 52 | SHOW CREATE TABLE inventory\G 53 | SHOW TABLE STATUS LIKE 'inventory'\G 54 | 55 | # END 56 | -------------------------------------------------------------------------------- /sql/chapter09.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter09.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | DROP TABLE IF EXISTS customer; 12 | 13 | DROP TABLE IF EXISTS parent; 14 | DROP TABLE IF EXISTS child; 15 | CREATE TABLE parent ( 16 | id INT UNSIGNED NOT NULL AUTO_INCREMENT, 17 | name VARCHAR(100) NOT NULL, 18 | PRIMARY KEY(id) 19 | ) ENGINE=InnoDB; 20 | 21 | CREATE TABLE child ( 22 | child_id INT UNSIGNED NOT NULL AUTO_INCREMENT, 23 | parent_id INT UNSIGNED NOT NULL, 24 | name VARCHAR(100) NOT NULL, 25 | PRIMARY KEY(child_id), 26 | KEY (parent_id) 27 | ) ENGINE=InnoDB; 28 | 29 | INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10)); 30 | INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10)); 31 | INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10)); 32 | INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10)); 33 | INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10)); 34 | INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent; 35 | INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent; 36 | INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent; 37 | INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent; 38 | INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent; 39 | 40 | INSERT INTO child(child_id,parent_id,name) SELECT NULL,id,name FROM parent WHERE MOD(id,2) = 0 OR MOD(id,3) = 0; 41 | 42 | 43 | EXPLAIN SELECT p.* 44 | FROM parent p 45 | WHERE p.id NOT IN (SELECT c.parent_id FROM child c)\G 46 | 47 | EXPLAIN SELECT p.* 48 | FROM parent p 49 | LEFT JOIN child c ON p.id = c.parent_id 50 | WHERE c.child_id IS NULL\G 51 | 52 | EXPLAIN SELECT p.* 53 | FROM parent p 54 | WHERE NOT EXISTS (SELECT parent_id FROM child c WHERE c.parent_id = p.id)\G 55 | 56 | 57 | 58 | ALTER TABLE parent ADD parent_id INT UNSIGNED NULL; 59 | UPDATE parent SET parent_id=id; 60 | 61 | SELECT p.* 62 | FROM parent p, 63 | child c 64 | WHERE p.parent_id = c.parent_id 65 | AND c.child_id < 10; 66 | 67 | # END 68 | -------------------------------------------------------------------------------- /sql/chapter05.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter05.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | #Covering Index 12 | SELECT artist_id,name,founded FROM artist WHERE founded=1969; 13 | ALTER TABLE artist ADD INDEX (founded); 14 | EXPLAIN SELECT artist_id,name,founded FROM artist WHERE founded=1969\G 15 | ALTER TABLE artist DROP INDEX founded, ADD INDEX founded_name (founded,name); 16 | EXPLAIN SELECT artist_id,name,founded FROM artist WHERE founded=1969\G 17 | EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G 18 | ALTER TABLE artist DROP INDEX founded_name, ADD INDEX founded_type_name(founded,type,name); 19 | EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G 20 | 21 | # Storage Engine Implications 22 | ALTER TABLE artist ENGINE=MyISAM; 23 | EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G 24 | ALTER TABLE artist DROP INDEX founded_type_name, ADD INDEX founded_myisam (founded,type,name,artist_id); 25 | EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G 26 | ALTER TABLE artist DROP INDEX founded_myisam, ENGINE=InnoDB; 27 | 28 | # Partial Index 29 | SET @schema = IFNULL(@schema,DATABASE()); 30 | SELECT @schema as table_schema, CURDATE() AS today; 31 | SELECT table_name, 32 | engine,row_format as format, table_rows, 33 | avg_row_length as avg_row, 34 | round((data_length+index_length)/1024/1024,2) as total_mb, 35 | round((data_length)/1024/1024,2) as data_mb, 36 | round((index_length)/1024/1024,2) as index_mb 37 | FROM information_schema.tables 38 | WHERE table_schema=@schema 39 | AND table_name = @table 40 | \G 41 | ALTER TABLE album DROP INDEX artist_id; 42 | SHOW CREATE TABLE album\G 43 | SET @table='album'; 44 | SOURCE tablesize.sql 45 | ALTER TABLE album ADD INDEX (name); 46 | SOURCE tablesize.sql 47 | ALTER TABLE album DROP INDEX name, ADD INDEX (name(20)); 48 | SOURCE tablesize.sql 49 | 50 | ALTER TABLE artist DROP INDEX name, ADD INDEX name_part (name(20)); 51 | EXPLAIN SELECT artist_id,name,founded FROM artist WHERE name LIKE 'Queen%'\G 52 | 53 | # END 54 | -------------------------------------------------------------------------------- /sql/chapter08.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter08.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | # Combining your DDL 12 | ALTER TABLE test ADD INDEX (username); 13 | ALTER TABLE test DROP INDEX name, ADD INDEX name (last_name,first_name); 14 | ALTER TABLE test ADD COLUMN last_visit DATE NULL; 15 | ALTER TABLE test 16 | ADD INDEX (username), 17 | DROP INDEX name, 18 | ADD INDEX name (last_name,first_name), 19 | ADD COLUMN last_visit DATE NULL; 20 | 21 | #Removing Duplicate Indexes 22 | DROP TABLE IF EXISTS test; 23 | CREATE TABLE test( 24 | id INT UNSIGNED NOT NULL, 25 | first_name VARCHAR(30) NOT NULL, 26 | last_name VARCHAR(30) NOT NULL, 27 | joined DATE NOT NULL, 28 | PRIMARY KEY(id), 29 | INDEX (id) 30 | ); 31 | 32 | DROP TABLE IF EXISTS test; 33 | CREATE TABLE test( 34 | id INT UNSIGNED NOT NULL, 35 | first_name VARCHAR(30) NOT NULL, 36 | last_name VARCHAR(30) NOT NULL, 37 | joined DATE NOT NULL, 38 | PRIMARY KEY(id), 39 | INDEX name1 (last_name), 40 | INDEX name2 (last_name, first_name) 41 | ); 42 | 43 | # Column Types 44 | SET @ip='123.100.0.16'; 45 | SELECT @ip, INET_ATON(@ip) AS str_to_i, INET_NTOA(INET_ATON(@ip)) as i_to_str; 46 | 47 | # MD5 48 | SET @str='somevalue'; 49 | SELECT MD5(@str), LENGTH(MD5(@str)) AS len_md5, LENGTH(UNHEX(MD5(@str))) as len_unhex; 50 | 51 | # Other SQL Optimizations 52 | SHOW PROFILE SOURCE FOR QUERY 7; 53 | 54 | # Removing Repeating SQL Statements 55 | SELECT name FROM firms WHERE id=727; 56 | SELECT name FROM firms WHERE id=758; 57 | SELECT name FROM firms WHERE id=857; 58 | SELECT name FROM firms WHERE id=740; 59 | SELECT name FROM firms WHERE id=849; 60 | SELECT name FROM firms WHERE id=839; 61 | SELECT name FROM firms WHERE id=847; 62 | SELECT name FROM firms WHERE id=867; 63 | SELECT name FROM firms WHERE id=829; 64 | SELECT name FROM firms WHERE id=812; 65 | SELECT name FROM firms WHERE id=868; 66 | SELECT name FROM firms WHERE id=723; 67 | SELECT id, name 68 | FROM firms 69 | WHERE id IN (723, 727, 740, 758, 812, 829, 839, 847, 849, 857, 867, 868); 70 | 71 | SET PROFILING=1; 72 | SELECT ...; 73 | SHOW PROFILES; 74 | 75 | SELECT 'Sum Individual Queries' AS txt,SUM(DURATION) AS total_time FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID BETWEEN 1 AND 12 76 | UNION 77 | SELECT 'Combined Query',SUM(DURATION) FROM INFORMATION_SCHEMA.PROFILING WHERE QUERY_ID = 13; 78 | 79 | 80 | SELECT a.id, a.firm_id, a.title 81 | FROM article a 82 | WHERE a.type=2 83 | AND a.created > '2011-06-01'; 84 | # For loop for all records 85 | SELECT id, name 86 | FROM firm 87 | WHERE id = :firm_id; 88 | SELECT a.id, a.firm_id, f.name, a.title 89 | FROM article a 90 | INNER JOIN firm f ON a.firm_id = f.id 91 | WHERE a.type=2 92 | AND a.created > '2011-06-01'; 93 | 94 | # MySQL Caching 95 | SET GLOBAL query_cache_size=1024*1024*16; 96 | SET GLOBAL query_cache_type=1; 97 | SET PROFILING=1; 98 | SELECT name FROM firms WHERE id=727; 99 | SELECT name FROM firms WHERE id=727; 100 | SHOW PROFILES; 101 | SHOW PROFILE FOR QUERY 1; 102 | SHOW PROFILE FOR QUERY 2; 103 | 104 | # Column Improvement 105 | SELECT fid, val, val 106 | FROM table1 107 | WHERE fid = X; 108 | 109 | SELECT val 110 | FROM table1 111 | WHERE fid = X; 112 | 113 | # Join Improvement 114 | SELECT /* Query 1 */ id FROM table1 115 | WHERE col1 = X 116 | AND col2 = Y; 117 | SELECT /* Query 2 */ table2.val1, table2.val2, table2.val3 118 | FROM table2 INNER JOIN table1 USING (id) 119 | WHERE table2.id = 9 120 | AND table1.col1 = X 121 | AND table1.col2 = Y 122 | AND table2.col1 = Z; 123 | SELECT /* Query 2 */ val1, val2, val3 124 | FROM table2 125 | WHERE table2.id = 9 126 | AND table2.col1 = Z; 127 | 128 | # Rewritin Subqueries 129 | SELECT id, label 130 | FROM code_opts 131 | WHERE code_id = (SELECT id FROM codes WHERE typ='CATEGORIES') 132 | ORDER BY seq; 133 | SELECT o.id, o.label 134 | FROM code_opts o INNER JOIN codes c ON o.code_id = c.id 135 | WHERE c.typ='CATEGORIES' 136 | ORDER BY o.seq; 137 | 138 | # END 139 | -------------------------------------------------------------------------------- /sql/chapter03.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter03.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | # 12 | # Example Tables 13 | # 14 | DROP TABLE IF EXISTS source_words; 15 | CREATE TABLE source_words ( 16 | word VARCHAR(50) NOT NULL, 17 | INDEX (word) 18 | ) ENGINE=MyISAM; 19 | LOAD DATA LOCAL INFILE '/usr/share/dict/words' 20 | INTO TABLE source_words(word); 21 | 22 | CREATE TABLE million_words( 23 | id INT UNSIGNED NOT NULL AUTO_INCREMENT, 24 | word VARCHAR(50) NOT NULL, 25 | PRIMARY KEY (id), 26 | UNIQUE INDEX (word) 27 | ) ENGINE=InnoDB; 28 | 29 | INSERT INTO million_words(word) 30 | SELECT DISTINCT word FROM source_words; 31 | INSERT INTO million_words(word) 32 | SELECT DISTINCT REVERSE(word) FROM source_words 33 | WHERE REVERSE(word) NOT IN (select word from source_words); 34 | SELECT @cnt := COUNT(*) FROM million_words; 35 | SELECT @diff := 1000000 - @cnt; 36 | -- We need to run dynamic SQL to support a variable LIMIT 37 | SET @sql = CONCAT(" 38 | INSERT INTO million_words(word) 39 | SELECT DISTINCT CONCAT(word,'X1Y') FROM source_words LIMIT ",@diff); 40 | PREPARE cmd FROM @sql; 41 | EXECUTE cmd; 42 | SELECT COUNT(*) FROM million_words; 43 | 44 | # 45 | # Data Integrity 46 | # 47 | INSERT INTO million_words(id,word) VALUES(1,'xxxxxxxxx'); 48 | INSERT INTO million_words(word) VALUES('oracle'); 49 | 50 | # 51 | # Optimizing Data Access 52 | # 53 | CREATE TABLE no_index_words LIKE million_words; 54 | ALTER TABLE no_index_words DROP INDEX word; 55 | INSERT INTO no_index_words SELECT * FROM million_words; 56 | SELECT * FROM no_index_words WHERE word='oracle'; 57 | SELECT * FROM million_words WHERE word='oracle'; 58 | 59 | # 60 | # MyISAM B-Tree 61 | # 62 | CREATE TABLE colors ( 63 | name VARCHAR(20) NOT NULL, 64 | items VARCHAR(255) NOT NULL 65 | ) ENGINE=MyISAM; 66 | 67 | INSERT INTO colors(name, items) VALUES 68 | ('RED','Apples,Sun,Blood,...'), 69 | ('ORANGE','Oranges,Sand,...'), 70 | ('YELLOW','...'), 71 | ('GREEN','Kermit,Grass,Leaves,Plants,Emeralds,Frogs,Seaweed,Spinach,Money,Jade,Go Traffic Light'), 72 | ('BLUE','Sky,Water,Blueberries,Earth'), 73 | ('INDIGIO','...'), 74 | ('VIOLET','...'), 75 | ('WHITE','...'), 76 | ('BLACK','Night,Coal,Blackboard,Licorice,Piano Keys,...'); 77 | 78 | ALTER TABLE colors ADD INDEX (name); 79 | 80 | # 81 | # InnoDB B+tree Clustered Primary Key 82 | # 83 | SET @table='million_words'; 84 | SOURCE tablesize.sql 85 | 86 | 87 | CREATE TABLE million_words2 ( 88 | id INT UNSIGNED NOT NULL, 89 | word VARCHAR(50) NOT NULL, 90 | PRIMARY KEY (word), 91 | UNIQUE KEY(id)) 92 | ENGINE=InnoDB; 93 | SELECT word,id FROM million_words ORDER BY id 94 | INTO OUTFILE '/tmp/million_words.tsv'; 95 | LOAD DATA LOCAL INFILE '/tmp/million_words.tsv' 96 | INTO TABLE million_words2(word,id); 97 | SET @table='million_words2'; 98 | SOURCE tablesize.sql 99 | 100 | DROP TABLE IF EXISTS colors_wide; 101 | CREATE TABLE colors_wide ( 102 | name VARCHAR(20) NOT NULL, 103 | items VARCHAR(255) NOT NULL, 104 | filler1 VARCHAR(500) NULL, 105 | PRIMARY KEY (name) 106 | ) ENGINE=InnoDB; 107 | 108 | INSERT INTO colors_wide(name, items) VALUES 109 | ('RED','Apples,Sun,Blood,...'), 110 | ('ORANGE','Oranges,Sand,...'), 111 | ('YELLOW','...'), 112 | ('GREEN','Kermit,Grass,Leaves,Plants,Emeralds,Frogs,Seaweed,Spinach,Money,Jade,Go Traffic Light'), 113 | ('BLUE','Sky,Water,Blueberries,Earth'), 114 | ('INDIGIO','...'), 115 | ('VIOLET','...'), 116 | ('WHITE','...'), 117 | ('BLACK','Night,Coal,Blackboard,Licorice,Piano Keys,...'); 118 | 119 | UPDATE colors_wide SET filler1=REPEAT('x',500), filler2=filler1, filler3=filler1,filler4=filler1,filler5=filler1; 120 | 121 | # 122 | # Memory Hash Index 123 | # 124 | CREATE TABLE memory_words( 125 | id INT UNSIGNED NOT NULL AUTO_INCREMENT, 126 | word VARCHAR(50) NOT NULL, 127 | PRIMARY KEY (id), 128 | UNIQUE KEY (word) 129 | ) ENGINE=MEMORY; 130 | 131 | SET SESSION max_heap_table_size = 1024 *1024 * 100; 132 | INSERT INTO memory_words(id,word) SELECT id,word from million_words; 133 | SELECT COUNT(*) FROM memory_words; 134 | SET PROFILING=1; 135 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'apple'; 136 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'orange'; 137 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'lemon'; 138 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'wordnotfound'; 139 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word LIKE 'apple%'; 140 | SHOW PROFILES; 141 | SET @table='memory_words'; 142 | SOURCE tablesize.sql 143 | 144 | # 145 | # MEMORY B-tree Index 146 | # 147 | SET SESSION max_heap_table_size = 1024 *1024 * 150; 148 | ALTER TABLE memory_words DROP INDEX word,ADD INDEX USING BTREE (word); 149 | SET SESSION profiling_history_size=0; 150 | SET PROFILING=0; 151 | SET PROFILING=1; 152 | SET SESSION profiling_history_size=10; 153 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'apple'; 154 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'orange'; 155 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'lemon'; 156 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word = 'wordnotfound'; 157 | SELECT SQL_NO_CACHE * FROM memory_words WHERE word LIKE 'apple%'; 158 | SET @table='memory_words'; 159 | SOURCE tablesize.sql 160 | 161 | # END 162 | -------------------------------------------------------------------------------- /sql/chapter02.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter02.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | # 12 | # EXPLAIN 13 | # 14 | EXPLAIN SELECT host,user,password FROM mysql.user WHERE user like 'r%'\G 15 | EXPLAIN SELECT host,user,password FROM mysql.user WHERE host='localhost' AND user like 'r%'\G 16 | 17 | # 18 | # EXPLAIN PARTITIONS 19 | # 20 | DROP TABLE IF EXISTS audit_log; 21 | CREATE TABLE audit_log ( 22 | yr YEAR NOT NULL, 23 | msg VARCHAR(100) NOT NULL) 24 | ENGINE=InnoDB 25 | PARTITION BY RANGE (yr) ( 26 | PARTITION p0 VALUES LESS THAN (2010), 27 | PARTITION p1 VALUES LESS THAN (2011), 28 | PARTITION p2 VALUES LESS THAN (2012), 29 | PARTITION p3 VALUES LESS THAN MAXVALUE); 30 | INSERT INTO audit_log(yr,msg) VALUES (2005,'2005'),(2006,'2006'),(2011,'2011'),(2020,'2020'); 31 | EXPLAIN PARTITIONS SELECT * from audit_log WHERE yr in (2011,2012)\G 32 | 33 | # 34 | # EXPLAIN EXTENDED 35 | # 36 | DROP TABLE IF EXISTS test1; 37 | DROP TABLE IF EXISTS test2; 38 | CREATE TABLE test1( 39 | uid VARCHAR(32) NOT NULL, 40 | name VARCHAR(100) NOT NULL, 41 | PRIMARY KEY(uid) 42 | ) ENGINE=InnoDB DEFAULT CHARSET latin1; 43 | CREATE TABLE test2( 44 | uid VARCHAR(32) NOT NULL, 45 | name VARCHAR(100) NOT NULL, 46 | PRIMARY KEY(uid) 47 | ) ENGINE=InnoDB DEFAULT CHARSET utf8; 48 | EXPLAIN EXTENDED select t1.name from test1 t1 INNER JOIN test2 t2 USING(uid)\G 49 | SHOW WARNINGS\G 50 | 51 | 52 | # 53 | # SHOW CREATE TABLE 54 | # 55 | DROP TABLE IF EXISTS wp_options; 56 | CREATE TABLE `wp_options` ( 57 | `option_id` bigint(20) unsigned NOT NULL AUTO_INCREMENT, 58 | `blog_id` int(11) NOT NULL DEFAULT '0', 59 | `option_name` varchar(64) NOT NULL DEFAULT '', 60 | `option_value` longtext NOT NULL, 61 | `autoload` varchar(20) NOT NULL DEFAULT 'yes', 62 | PRIMARY KEY (`option_id`), 63 | UNIQUE KEY `option_name` (`option_name`) 64 | ) ENGINE=MyISAM AUTO_INCREMENT=4138 DEFAULT CHARSET=utf8; 65 | SHOW CREATE TABLE wp_options\G 66 | 67 | # 68 | # SHOW INDEXES 69 | # 70 | DROP TABLE IF EXISTS wp_posts; 71 | CREATE TABLE `wp_posts` ( 72 | `ID` bigint(20) unsigned NOT NULL AUTO_INCREMENT, 73 | `post_author` bigint(20) unsigned NOT NULL DEFAULT '0', 74 | `post_date` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 75 | `post_date_gmt` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 76 | `post_content` longtext NOT NULL, 77 | `post_title` text NOT NULL, 78 | `post_excerpt` text NOT NULL, 79 | `post_status` varchar(20) NOT NULL DEFAULT 'publish', 80 | `comment_status` varchar(20) NOT NULL DEFAULT 'open', 81 | `ping_status` varchar(20) NOT NULL DEFAULT 'open', 82 | `post_password` varchar(20) NOT NULL DEFAULT '', 83 | `post_name` varchar(200) NOT NULL DEFAULT '', 84 | `to_ping` text NOT NULL, 85 | `pinged` text NOT NULL, 86 | `post_modified` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 87 | `post_modified_gmt` datetime NOT NULL DEFAULT '0000-00-00 00:00:00', 88 | `post_content_filtered` text NOT NULL, 89 | `post_parent` bigint(20) unsigned NOT NULL DEFAULT '0', 90 | `guid` varchar(255) NOT NULL DEFAULT '', 91 | `menu_order` int(11) NOT NULL DEFAULT '0', 92 | `post_type` varchar(20) NOT NULL DEFAULT 'post', 93 | `post_mime_type` varchar(100) NOT NULL DEFAULT '', 94 | `comment_count` bigint(20) NOT NULL DEFAULT '0', 95 | PRIMARY KEY (`ID`), 96 | KEY `post_name` (`post_name`), 97 | KEY `type_status_date` (`post_type`,`post_status`,`post_date`,`ID`), 98 | KEY `post_parent` (`post_parent`), 99 | KEY `post_author` (`post_author`) 100 | ) ENGINE=MyISAM AUTO_INCREMENT=3761 DEFAULT CHARSET=utf8; 101 | SHOW INDEXES FROM wp_posts; 102 | SHOW INDEXES FROM wp_posts\G 103 | 104 | # 105 | # SHOW TABLE STATUS 106 | # 107 | SHOW TABLE STATUS LIKE 'wp_posts'\G 108 | ALTER TABLE wp_posts ENGINE=InnoDB; 109 | SELECT COUNT(*) FROM wp_posts; 110 | SHOW TABLE STATUS LIKE 'wp_posts'\G 111 | SHOW TABLE STATUS LIKE 'wp_posts'\G 112 | SHOW TABLE STATUS LIKE 'wp_posts'\G 113 | SELECT COUNT(*) FROM wp_posts; 114 | SET @schema = IFNULL(@schema,DATABASE()); 115 | SET @table='inventory'; 116 | SELECT @schema as table_schema, CURDATE() AS today; 117 | SELECT table_name, 118 | engine,row_format as format, table_rows, avg_row_length as avg_row, 119 | round((data_length+index_length)/1024/1024,2) as total_mb, 120 | round((data_length)/1024/1024,2) as data_mb, 121 | round((index_length)/1024/1024,2) as index_mb 122 | FROM information_schema.tables 123 | WHERE table_schema=@schema 124 | AND table_name = @table 125 | \G 126 | 127 | # 128 | # SHOW STATUS 129 | # 130 | SHOW GLOBAL STATUS LIKE 'Created_tmp_%tables'; 131 | SHOW SESSION STATUS LIKE 'Created_tmp_%tables'; 132 | FLUSH STATUS; 133 | SELECT * FROM mysql.user; 134 | SHOW SESSION STATUS LIKE 'handler_read%'; 135 | 136 | # 137 | # SHOW VARIABLES 138 | # 139 | SHOW SESSION VARIABLES LIKE 'tmp_table_size'; 140 | SELECT 'SESSION' AS scope,variable_name,variable_value 141 | FROM INFORMATION_SCHEMA.SESSION_VARIABLES 142 | WHERE variable_name IN ('tmp_table_size','max_heap_table_size') 143 | UNION 144 | SELECT 'GLOBAL',variable_name,variable_value 145 | FROM INFORMATION_SCHEMA.GLOBAL_VARIABLES 146 | WHERE variable_name IN ('tmp_table_size','max_heap_table_size'); 147 | 148 | # END 149 | -------------------------------------------------------------------------------- /sql/chapter04.sql: -------------------------------------------------------------------------------- 1 | # Effective MySQL: Optimizing SQL Statements by Ronald Bradford 2 | # http://effectivemysql.com/book/optimizing-sql-statements 3 | # 4 | 5 | # 6 | # chapter04.sql 7 | # 8 | CREATE SCHEMA IF NOT EXISTS book; 9 | USE book; 10 | 11 | #Existing Indexes 12 | SELECT artist_id, type, founded FROM artist WHERE name = 'Coldplay'; 13 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name = 'Coldplay'\G 14 | SHOW CREATE TABLE artist\G 15 | 16 | # Restricting rows with an index 17 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G 18 | ALTER TABLE artist ADD INDEX (founded); 19 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G 20 | ALTER TABLE artist ADD INDEX (founded); 21 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G 22 | 23 | # Joing tables with an index 24 | EXPLAIN SELECT ar.name, ar.founded, al.name, al.first_released FROM artist ar INNER JOIN album al USING (artist_id) WHERE ar.name = 'Queen'\G 25 | ALTER TABLE album ADD INDEX (artist_id); 26 | EXPLAIN SELECT ar.name, ar.founded, al.name, al.first_released FROM artist ar INNER JOIN album al USING (artist_id) WHERE ar.name = 'Queen'\G 27 | 28 | # Understanding index cardinality 29 | ALTER TABLE artist ADD INDEX (type); 30 | SET @@session.optimizer_switch='index_merge_intersection=off'; 31 | EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded = 1980 AND type='Band'\G 32 | SHOW INDEXES FROM artist\G 33 | EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded BETWEEN 1980 AND 1989 AND type='Band'\G 34 | EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded BETWEEN 1980 AND 1989 AND type='Combination'\G 35 | 36 | #Using indexes for pattern matching 37 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name LIKE 'Queen%'\G 38 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name LIKE '%Queen%'\G 39 | EXPLAIN SELECT artist_id, type, founded FROM artist WHERE UPPER(name) = UPPER('Billy Joel')\G 40 | 41 | # Selecting a unique row 42 | FLUSH STATUS; 43 | SHOW SESSION STATUS LIKE 'Handler_read_next'; 44 | SELECT name FROM artist WHERE name ='Enya'; 45 | SHOW SESSION STATUS LIKE 'Handler_read_next'; 46 | 47 | ALTER TABLE artist DROP INDEX name,ADD UNIQUE INDEX(name); 48 | 49 | FLUSH STATUS; 50 | SHOW SESSION STATUS LIKE 'Handler_read_next'; 51 | SELECT name FROM artist WHERE name ='Enya'; 52 | SHOW SESSION STATUS LIKE 'Handler_read_next'; 53 | 54 | 55 | # Ordering Results 56 | EXPLAIN SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY founded\G 57 | FLUSH STATUS; 58 | SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY founded\G 59 | SHOW SESSION STATUS LIKE '%sort%'; 60 | EXPLAIN SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY name\G 61 | FLUSH STATUS; 62 | SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY name\G 63 | SHOW SESSION STATUS LIKE '%sort%'; 64 | 65 | # Determining which index to use 66 | ALTER TABLE album ADD INDEX (country_id), ADD INDEX (album_type_id); 67 | SET @@session.optimizer_switch='index_merge_intersection=off'; 68 | EXPLAIN SELECT al.name, al.first_released, al.album_type_id FROM album al WHERE al.country_id=221 AND album_type_id=1\G 69 | EXPLAIN SELECT al.name, al.first_released, al.album_type_id FROM album al WHERE al.country_id=221 AND album_type_id=4\G 70 | SHOW INDEXES FROM album\G 71 | SELECT COUNT(*) FROM album where country_id=221; 72 | SELECT COUNT(*) FROM album where album_type_id=4; 73 | SELECT COUNT(*) FROM album where album_type_id=1; 74 | 75 | # Providing a Better Index 76 | ALTER TABLE album ADD INDEX m1 (country_id, album_type_id); 77 | EXPLAIN SELECT al.name, al.first_released, al.album_type_id FROM album al WHERE al.country_id=221 AND album_type_id=4\G 78 | ALTER TABLE album ADD INDEX m2 (album_type_id,country_id); 79 | EXPLAIN SELECT al.name, al.first_released, al.album_type_id FROM album al WHERE al.country_id=221 AND album_type_id=4\G 80 | SHOW INDEXES FROM album\G 81 | 82 | # Many column indexes 83 | ALTER TABLE artist ADD index (type,gender,country_id); 84 | EXPLAIN SELECT name FROM artist WHERE type= 'Person' AND gender='Male' AND country_id = 13\G 85 | EXPLAIN SELECT name FROM artist WHERE type= 'Person' AND gender='Male'\G 86 | 87 | # Combining WHERE and ORDER BY 88 | ALTER TABLE album ADD INDEX (name); 89 | EXPLAIN SELECT a.name, ar.name, a.first_released FROM album a INNER JOIN artist ar USING (artist_id) WHERE a.name = 'Greatest Hits' ORDER BY a.first_released\G 90 | ALTER TABLE album ADD INDEX name_release (name,first_released); 91 | EXPLAIN SELECT a.name, ar.name, a.first_released FROM album a INNER JOIN artist ar USING (artist_id) WHERE a.name = 'Greatest Hits' ORDER BY a.first_released\G 92 | 93 | # MySQL optimizer features 94 | SET @@session.optimizer_switch='index_merge_intersection=on'; 95 | EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR founded = 1942\G 96 | EXPLAIN SELECT artist_id, name FROM artist WHERE type = 'Band' AND founded = 1942\G 97 | EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR (founded BETWEEN 1942 AND 1950)\G 98 | EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR (type = 'Band' AND founded = 1942)\G 99 | 100 | # Query Hints 101 | EXPLAIN SELECT album.name, artist.name, album.first_released FROM artist INNER JOIN album USING (artist_id) WHERE album.name = 'Greatest Hits'\G 102 | EXPLAIN SELECT STRAIGHT_JOIN album.name, artist.name, album.first_released FROM artist INNER JOIN album USING (artist_id) WHERE album.name = 'Greatest Hits'\G 103 | EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded = 1980 AND type='Band'\G 104 | EXPLAIN SELECT artist_id, name, country_id FROM artist USE INDEX (type) WHERE founded = 1980 AND type='Band'\G 105 | EXPLAIN SELECT artist_id, name, country_id FROM artist IGNORE INDEX (founded) WHERE founded = 1980 AND type='Band'\G 106 | EXPLAIN SELECT artist_id, name, country_id FROM artist IGNORE INDEX (founded,founded_2) USE INDEX (type_2) WHERE founded = 1980 AND type='Band'\G 107 | 108 | # DML Impact 109 | DROP TABLE IF EXISTS t1; 110 | CREATE TABLE t1 LIKE album; 111 | INSERT INTO t1 SELECT * FROM album; 112 | DROP TABLE t1; 113 | CREATE TABLE t1 LIKE album; 114 | #ALTER TABLE t1 DROP INDEX first_released, DROP INDEX album_type_id, DROP INDEX name, DROP INDEX country_id, DROP INDEX m1, DROP INDEX m2; 115 | ALTER TABLE t1 DROP INDEX album_type_id, DROP INDEX country_id, DROP INDEX m1, DROP INDEX m2; 116 | INSERT INTO t1 SELECT * FROM album; 117 | DROP TABLE t1; 118 | 119 | 120 | 121 | # END 122 | --------------------------------------------------------------------------------