Skip to content
Browse files

Remaining chapters

  • Loading branch information...
1 parent a51d01c commit dd8dba26da1fb911042466d21e7fa81f0157f99f @ronaldbradford ronaldbradford committed Oct 4, 2011
Showing with 261 additions and 0 deletions.
  1. +1 −0 sql/README
  2. +121 −0 sql/chapter04.sql
  3. +53 −0 sql/chapter05.sql
  4. +19 −0 sql/chapter07.sql
  5. +67 −0 sql/chapter09.sql
View
1 sql/README
@@ -0,0 +1 @@
+env GIT_SSL_NO_VERIFY=true git push
View
121 sql/chapter04.sql
@@ -0,0 +1,121 @@
+# Effective MySQL: Optimizing SQL Statements by Ronald Bradford
+# http://effectivemysql.com/book/optimizing-sql-statements
+#
+
+#
+# chapter04.sql
+#
+CREATE SCHEMA IF NOT EXISTS book;
+USE book;
+
+#Existing Indexes
+SELECT artist_id, type, founded FROM artist WHERE name = 'Coldplay';
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name = 'Coldplay'\G
+SHOW CREATE TABLE artist\G
+
+# Restricting rows with an index
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G
+ALTER TABLE artist ADD INDEX (founded);
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G
+ALTER TABLE artist ADD INDEX (founded);
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE founded=1942\G
+
+# Joing tables with an index
+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
+ALTER TABLE album ADD INDEX (artist_id);
+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
+
+# Understanding index cardinality
+ALTER TABLE artist ADD INDEX (type);
+SET @@session.optimizer_switch='index_merge_intersection=off';
+EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded = 1980 AND type='Band'\G
+SHOW INDEXES FROM artist\G
+EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded BETWEEN 1980 AND 1989 AND type='Band'\G
+EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded BETWEEN 1980 AND 1989 AND type='Combination'\G
+
+#Using indexes for pattern matching
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name LIKE 'Queen%'\G
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE name LIKE '%Queen%'\G
+EXPLAIN SELECT artist_id, type, founded FROM artist WHERE UPPER(name) = UPPER('Billy Joel')\G
+
+# Selecting a unique row
+FLUSH STATUS;
+SHOW SESSION STATUS LIKE 'Handler_read_next';
+SELECT name FROM artist WHERE name ='Enya';
+SHOW SESSION STATUS LIKE 'Handler_read_next';
+
+ALTER TABLE artist DROP INDEX name,ADD UNIQUE INDEX(name);
+
+FLUSH STATUS;
+SHOW SESSION STATUS LIKE 'Handler_read_next';
+SELECT name FROM artist WHERE name ='Enya';
+SHOW SESSION STATUS LIKE 'Handler_read_next';
+
+
+# Ordering Results
+EXPLAIN SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY founded\G
+FLUSH STATUS;
+SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY founded\G
+SHOW SESSION STATUS LIKE '%sort%';
+EXPLAIN SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY name\G
+FLUSH STATUS;
+SELECT name,founded FROM artist WHERE name like 'AUSTRALIA%' ORDER BY name\G
+SHOW SESSION STATUS LIKE '%sort%';
+
+# Determining which index to use
+ALTER TABLE album ADD INDEX (country_id), ADD INDEX (album_type_id);
+SET @@session.optimizer_switch='index_merge_intersection=off';
+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
+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
+SHOW INDEXES FROM album\G
+SELECT COUNT(*) FROM album where country_id=221;
+SELECT COUNT(*) FROM album where album_type_id=4;
+SELECT COUNT(*) FROM album where album_type_id=1;
+
+# Providing a Better Index
+ALTER TABLE album ADD INDEX m1 (country_id, album_type_id);
+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
+ALTER TABLE album ADD INDEX m2 (album_type_id,country_id);
+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
+SHOW INDEXES FROM album\G
+
+# Many column indexes
+ALTER TABLE artist ADD index (type,gender,country_id);
+EXPLAIN SELECT name FROM artist WHERE type= 'Person' AND gender='Male' AND country_id = 13\G
+EXPLAIN SELECT name FROM artist WHERE type= 'Person' AND gender='Male'\G
+
+# Combining WHERE and ORDER BY
+ALTER TABLE album ADD INDEX (name);
+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
+ALTER TABLE album ADD INDEX name_release (name,first_released);
+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
+
+# MySQL optimizer features
+SET @@session.optimizer_switch='index_merge_intersection=on';
+EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR founded = 1942\G
+EXPLAIN SELECT artist_id, name FROM artist WHERE type = 'Band' AND founded = 1942\G
+EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR (founded BETWEEN 1942 AND 1950)\G
+EXPLAIN SELECT artist_id, name FROM artist WHERE name = 'Queen' OR (type = 'Band' AND founded = 1942)\G
+
+# Query Hints
+EXPLAIN SELECT album.name, artist.name, album.first_released FROM artist INNER JOIN album USING (artist_id) WHERE album.name = 'Greatest Hits'\G
+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
+EXPLAIN SELECT artist_id, name, country_id FROM artist WHERE founded = 1980 AND type='Band'\G
+EXPLAIN SELECT artist_id, name, country_id FROM artist USE INDEX (type) WHERE founded = 1980 AND type='Band'\G
+EXPLAIN SELECT artist_id, name, country_id FROM artist IGNORE INDEX (founded) WHERE founded = 1980 AND type='Band'\G
+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
+
+# DML Impact
+DROP TABLE IF EXISTS t1;
+CREATE TABLE t1 LIKE album;
+INSERT INTO t1 SELECT * FROM album;
+DROP TABLE t1;
+CREATE TABLE t1 LIKE album;
+#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;
+ALTER TABLE t1 DROP INDEX album_type_id, DROP INDEX country_id, DROP INDEX m1, DROP INDEX m2;
+INSERT INTO t1 SELECT * FROM album;
+DROP TABLE t1;
+
+
+
+# END
View
53 sql/chapter05.sql
@@ -0,0 +1,53 @@
+# Effective MySQL: Optimizing SQL Statements by Ronald Bradford
+# http://effectivemysql.com/book/optimizing-sql-statements
+#
+
+#
+# chapter02.sql
+#
+CREATE SCHEMA IF NOT EXISTS book;
+USE book;
+
+#Covering Index
+SELECT artist_id,name,founded FROM artist WHERE founded=1969;
+ALTER TABLE artist ADD INDEX (founded);
+EXPLAIN SELECT artist_id,name,founded FROM artist WHERE founded=1969\G
+ALTER TABLE artist DROP INDEX founded, ADD INDEX founded_name (founded,name);
+EXPLAIN SELECT artist_id,name,founded FROM artist WHERE founded=1969\G
+EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G
+ALTER TABLE artist DROP INDEX founded_name, ADD INDEX founded_type_name(founded,type,name);
+EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G
+
+# Storage Engine Implications
+ALTER TABLE artist ENGINE=MyISAM;
+EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G
+ALTER TABLE artist DROP INDEX founded_type_name, ADD INDEX founded_myisam (founded,type,name,artist_id);
+EXPLAIN SELECT artist_id,name,founded FROM artist> WHERE founded=1969 AND type='Person'\G
+ALTER TABLE artist DROP INDEX founded_myisam, ENGINE=InnoDB;
+
+# Partial Index
+SET @schema = IFNULL(@schema,DATABASE());
+SELECT @schema as table_schema, CURDATE() AS today;
+SELECT table_name,
+ engine,row_format as format, table_rows,
+ avg_row_length as avg_row,
+ round((data_length+index_length)/1024/1024,2) as total_mb,
+ round((data_length)/1024/1024,2) as data_mb,
+ round((index_length)/1024/1024,2) as index_mb
+FROM information_schema.tables
+WHERE table_schema=@schema
+AND table_name = @table
+\G
+ALTER TABLE album DROP INDEX artist_id;
+SHOW CREATE TABLE album\G
+SET @table='album';
+SOURCE tablesize.sql
+ALTER TABLE album ADD INDEX (name);
+SOURCE tablesize.sql
+ALTER TABLE album DROP INDEX name, ADD INDEX (name(20));
+SOURCE tablesize.sql
+
+ALTER TABLE artist DROP INDEX name, ADD INDEX name_part (name(20));
+EXPLAIN SELECT artist_id,name,founded FROM artist WHERE name LIKE 'Queen%'\G
+
+# END
View
19 sql/chapter07.sql
@@ -0,0 +1,19 @@
+# Effective MySQL: Optimizing SQL Statements by Ronald Bradford
+# http://effectivemysql.com/book/optimizing-sql-statements
+#
+
+#
+# chapter07.sql
+#
+CREATE SCHEMA IF NOT EXISTS book;
+USE book;
+
+SET PROFILING=1;
+SELECT NOW();
+SELECT BENCHMARK(1+1,100000);
+SELECT BENCHMARK('1'+'1',100000);
+SELECT SLEEP(1);
+SELECT SLEEP(2);
+SHOW PROFILES;
+
+# END
View
67 sql/chapter09.sql
@@ -0,0 +1,67 @@
+# Effective MySQL: Optimizing SQL Statements by Ronald Bradford
+# http://effectivemysql.com/book/optimizing-sql-statements
+#
+
+#
+# chapter09.sql
+#
+CREATE SCHEMA IF NOT EXISTS book;
+USE book;
+
+DROP TABLE IF EXISTS customer;
+
+DROP TABLE IF EXISTS parent;
+DROP TABLE IF EXISTS child;
+CREATE TABLE parent (
+ id INT UNSIGNED NOT NULL AUTO_INCREMENT,
+ name VARCHAR(100) NOT NULL,
+ PRIMARY KEY(id)
+) ENGINE=InnoDB;
+
+CREATE TABLE child (
+ child_id INT UNSIGNED NOT NULL AUTO_INCREMENT,
+ parent_id INT UNSIGNED NOT NULL,
+ name VARCHAR(100) NOT NULL,
+ PRIMARY KEY(child_id),
+ KEY (parent_id)
+) ENGINE=InnoDB;
+
+INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10));
+INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10));
+INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10));
+INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10));
+INSERT INTO parent(id,name) VALUES(NULL,REPEAT(HEX(LAST_INSERT_ID()),10));
+INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent;
+INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent;
+INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent;
+INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent;
+INSERT INTO parent(id,name) SELECT NULL,REPEAT(HEX(id),10) FROM parent;
+
+INSERT INTO child(child_id,parent_id,name) SELECT NULL,id,name FROM parent WHERE MOD(id,2) = 0 OR MOD(id,3) = 0;
+
+
+EXPLAIN SELECT p.*
+FROM parent p
+WHERE p.id NOT IN (SELECT c.parent_id FROM child c)\G
+
+EXPLAIN SELECT p.*
+FROM parent p
+LEFT JOIN child c ON p.id = c.parent_id
+WHERE c.child_id IS NULL\G
+
+EXPLAIN SELECT p.*
+FROM parent p
+WHERE NOT EXISTS (SELECT parent_id FROM child c WHERE c.parent_id = p.id)\G
+
+
+
+ALTER TABLE parent ADD parent_id INT UNSIGNED NULL;
+UPDATE parent SET parent_id=id;
+
+SELECT p.*
+FROM parent p,
+ child c
+WHERE p.parent_id = c.parent_id
+AND c.child_id < 10;
+
+# END

0 comments on commit dd8dba2

Please sign in to comment.
Something went wrong with that request. Please try again.