Commit b4883a8044af6d35875dd8300a5d326f5460c729
1 parent
b7ded5be
Exists in
master
and in
1 other branch
installed query analyzer
Showing
3 changed files
with
151 additions
and
0 deletions
Show diff stats
@@ -0,0 +1,96 @@ | @@ -0,0 +1,96 @@ | ||
1 | += Query Analyzer Plugin for MySQL on Rails | ||
2 | + | ||
3 | +MODIFIED by John Eberly originally take from http://svn.nfectio.us | ||
4 | + | ||
5 | +The Query Analyzer plugin will expand the usability of your log files | ||
6 | +by providing query analysis using the MySQL query execution plan. Each SQL | ||
7 | +select query will be 'EXPLAIN'ed and added to the log files right below | ||
8 | +the original query. | ||
9 | + | ||
10 | +Using this plugin and a good understanding of the results, you will be | ||
11 | +able to analyze and optimize the queries your application is making. | ||
12 | + | ||
13 | +Refer to http://www.mysql.org/doc/refman/5.0/en/explain.html for more | ||
14 | +information on understanding the results. | ||
15 | + | ||
16 | += Installation | ||
17 | + | ||
18 | +script/plugin install git://github.com/jeberly/query-analyzer.git | ||
19 | + | ||
20 | += Example Use | ||
21 | + | ||
22 | +Here is a real life usage of the plugin that detected the omission of indexes on | ||
23 | +a table. In this case, it was a join table and the keys didn't have indexes (silly me!). | ||
24 | +Names have been changed to protect the innocent (and make it fit 80 columns) | ||
25 | + | ||
26 | +# development.log | ||
27 | + | ||
28 | +P Load (0.008669) | ||
29 | + => SELECT p.* FROM p INNER JOIN d ON p.id = d.p_id WHERE (d.p_id = 2 AND ((d.type = 'P'))) | ||
30 | + | ||
31 | +Analyzing P Load | ||
32 | + | ||
33 | +select_type | key_len | type | Extra | id | possible_keys | rows | table | ref | key | ||
34 | +---------------------------------------------------------------------------------------------------- | ||
35 | +SIMPLE | | ALL | Using where | 1 | | 74 | d | | | ||
36 | +SIMPLE | 4 | eq_ref | Using where | 1 | PRIMARY | 1 | p | d.p_id | PRIMARY | ||
37 | + | ||
38 | + | ||
39 | += Analyze the results | ||
40 | + | ||
41 | +Looking at the results of the execution plan, we can see that the lookup in | ||
42 | +the d table is missing an index (possible_keys=null) and performed a full | ||
43 | +table scan (type=ALL) to satisfy the WHERE condition. In this case, there was only one | ||
44 | +row that matched the condition in the table, but MySQL still had to search all 74 rows | ||
45 | +in the table to find it, a key indicator of a missing | ||
46 | +or malformed index(es). Once it has pulled all the records to satisfy the WHERE, it then | ||
47 | +starts the p table join. This time, it was able to match d.p_id to p.id using | ||
48 | +the PRIMARY key on the p table. The type=eq_ref indicates a 1 to 1 match against a primary | ||
49 | +or unique column. | ||
50 | + | ||
51 | +Lets add some indexes to the join table and see if we can cut that full table scan down in the | ||
52 | +number of rows it needs to search. | ||
53 | + | ||
54 | +#> script/generate Migration AddIndexesToD | ||
55 | + | ||
56 | +# file: 005_add_indexes_to_d | ||
57 | +class AddIndexesToD < ActiveRecord::Migration | ||
58 | + def self.up | ||
59 | + add_index :d, [ :p_id, :type ] | ||
60 | + add_index :d, :type | ||
61 | + end | ||
62 | + | ||
63 | + def self.remove | ||
64 | + remove_index :d, [ :p_id, :type ] | ||
65 | + remove_index :d, :type | ||
66 | + end | ||
67 | +end | ||
68 | + | ||
69 | + | ||
70 | +Now that we have an index on the foreign_key column and type, lets re-run the query and | ||
71 | +see if we got rid of that full table scan. | ||
72 | + | ||
73 | +# development.log | ||
74 | + | ||
75 | +P Load (0.009011) | ||
76 | + => SELECT p.* FROM p INNER JOIN d ON p.id = d.p_id WHERE (d.p_id = 2 AND ((d.type = 'P'))) | ||
77 | + | ||
78 | +Analyzing P Load | ||
79 | + | ||
80 | +select_type | key_len | type | Extra | id | possible_keys | rows | table | ref | key | ||
81 | +------------------------------------------------------------------------------------------------------------------------------ | ||
82 | +SIMPLE | 255 | ref | Using where | 1 | d_p_id_type_index,d_type_index | 1 | d | const | d_p_id_type_index | ||
83 | +SIMPLE | 4 | eq_ref | Using where | 1 | PRIMARY | 1 | p | d.p_id | PRIMARY | ||
84 | + | ||
85 | +Okay. Now MySQL is using an index satisfy the WHERE condition. Using the index, it was able to | ||
86 | +find the single row that matched, preventing the full table scan. | ||
87 | + | ||
88 | + | ||
89 | +Credits: | ||
90 | +The extension of the Array class for printing the columnized records was originally | ||
91 | +written by Peter Cooper who adapted it from Courtenay from #caboose. | ||
92 | + | ||
93 | +http://www.rubyinside.com/columnized-text-datasets-in-rails-71.html | ||
94 | +http://habtm.com/articles/2006/06/10/pretty-tables-for-ruby-objects | ||
95 | + | ||
96 | +Released under the MIT license (download your own if you need it) |
@@ -0,0 +1,54 @@ | @@ -0,0 +1,54 @@ | ||
1 | +class Array | ||
2 | + protected | ||
3 | + def qa_columnized_row(fields, sized) | ||
4 | + row = [] | ||
5 | + fields.each_with_index do |f, i| | ||
6 | + row << sprintf("%0-#{sized[i]}s", f.to_s) | ||
7 | + end | ||
8 | + row.join(' | ') | ||
9 | + end | ||
10 | + | ||
11 | + public | ||
12 | + | ||
13 | + def qa_columnized | ||
14 | + sized = {} | ||
15 | + self.each do |row| | ||
16 | + row.values.each_with_index do |value, i| | ||
17 | + sized[i] = [sized[i].to_i, row.keys[i].length, value.to_s.length].max | ||
18 | + end | ||
19 | + end | ||
20 | + | ||
21 | + table = [] | ||
22 | + table << qa_columnized_row(self.first.keys, sized) | ||
23 | + table << '-' * table.first.length | ||
24 | + self.each { |row| table << qa_columnized_row(row.values, sized) } | ||
25 | + table.join("\n ") # Spaces added to work with format_log_entry | ||
26 | + end | ||
27 | +end | ||
28 | + | ||
29 | + | ||
30 | + | ||
31 | +module ActiveRecord | ||
32 | + module ConnectionAdapters | ||
33 | + class MysqlAdapter < AbstractAdapter | ||
34 | + private | ||
35 | + alias_method :select_without_analyzer, :select | ||
36 | + | ||
37 | + def select(sql, name = nil) | ||
38 | + query_results = select_without_analyzer(sql, name) | ||
39 | + | ||
40 | + if @logger and @logger.level == Logger::DEBUG | ||
41 | + @logger.debug( | ||
42 | + ActiveRecord::Base.silence do | ||
43 | + explain_results = select_without_analyzer("explain #{sql}", name) | ||
44 | + format_log_entry("\033[1;34m############ FIXME - UNOPTIMIZED QUERY for #{name} ############ \033[0m\n", | ||
45 | + "#{explain_results.qa_columnized}\n" | ||
46 | + ) if explain_results[0]["rows"].to_i > 100 && sql =~ / where[\s(]/i | ||
47 | + end | ||
48 | + ) if sql =~ /^select/i | ||
49 | + end | ||
50 | + query_results | ||
51 | + end | ||
52 | + end | ||
53 | + end | ||
54 | +end |