From b4883a8044af6d35875dd8300a5d326f5460c729 Mon Sep 17 00:00:00 2001 From: Pius Uzamere Date: Sat, 19 Dec 2009 00:55:11 -0500 Subject: [PATCH] installed query analyzer --- vendor/plugins/query-analyzer/README | 96 ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++ vendor/plugins/query-analyzer/init.rb | 1 + vendor/plugins/query-analyzer/lib/query_analyzer.rb | 54 ++++++++++++++++++++++++++++++++++++++++++++++++++++++ 3 files changed, 151 insertions(+), 0 deletions(-) create mode 100644 vendor/plugins/query-analyzer/README create mode 100644 vendor/plugins/query-analyzer/init.rb create mode 100644 vendor/plugins/query-analyzer/lib/query_analyzer.rb diff --git a/vendor/plugins/query-analyzer/README b/vendor/plugins/query-analyzer/README new file mode 100644 index 0000000..0133f1d --- /dev/null +++ b/vendor/plugins/query-analyzer/README @@ -0,0 +1,96 @@ += Query Analyzer Plugin for MySQL on Rails + +MODIFIED by John Eberly originally take from http://svn.nfectio.us + +The Query Analyzer plugin will expand the usability of your log files +by providing query analysis using the MySQL query execution plan. Each SQL +select query will be 'EXPLAIN'ed and added to the log files right below +the original query. + +Using this plugin and a good understanding of the results, you will be +able to analyze and optimize the queries your application is making. + +Refer to http://www.mysql.org/doc/refman/5.0/en/explain.html for more +information on understanding the results. + += Installation + +script/plugin install git://github.com/jeberly/query-analyzer.git + += Example Use + +Here is a real life usage of the plugin that detected the omission of indexes on +a table. In this case, it was a join table and the keys didn't have indexes (silly me!). +Names have been changed to protect the innocent (and make it fit 80 columns) + +# development.log + +P Load (0.008669) + => SELECT p.* FROM p INNER JOIN d ON p.id = d.p_id WHERE (d.p_id = 2 AND ((d.type = 'P'))) + +Analyzing P Load + +select_type | key_len | type | Extra | id | possible_keys | rows | table | ref | key +---------------------------------------------------------------------------------------------------- +SIMPLE | | ALL | Using where | 1 | | 74 | d | | +SIMPLE | 4 | eq_ref | Using where | 1 | PRIMARY | 1 | p | d.p_id | PRIMARY + + += Analyze the results + +Looking at the results of the execution plan, we can see that the lookup in +the d table is missing an index (possible_keys=null) and performed a full +table scan (type=ALL) to satisfy the WHERE condition. In this case, there was only one +row that matched the condition in the table, but MySQL still had to search all 74 rows +in the table to find it, a key indicator of a missing +or malformed index(es). Once it has pulled all the records to satisfy the WHERE, it then +starts the p table join. This time, it was able to match d.p_id to p.id using +the PRIMARY key on the p table. The type=eq_ref indicates a 1 to 1 match against a primary +or unique column. + +Lets add some indexes to the join table and see if we can cut that full table scan down in the +number of rows it needs to search. + +#> script/generate Migration AddIndexesToD + +# file: 005_add_indexes_to_d +class AddIndexesToD < ActiveRecord::Migration + def self.up + add_index :d, [ :p_id, :type ] + add_index :d, :type + end + + def self.remove + remove_index :d, [ :p_id, :type ] + remove_index :d, :type + end +end + + +Now that we have an index on the foreign_key column and type, lets re-run the query and +see if we got rid of that full table scan. + +# development.log + +P Load (0.009011) + => SELECT p.* FROM p INNER JOIN d ON p.id = d.p_id WHERE (d.p_id = 2 AND ((d.type = 'P'))) + +Analyzing P Load + +select_type | key_len | type | Extra | id | possible_keys | rows | table | ref | key +------------------------------------------------------------------------------------------------------------------------------ +SIMPLE | 255 | ref | Using where | 1 | d_p_id_type_index,d_type_index | 1 | d | const | d_p_id_type_index +SIMPLE | 4 | eq_ref | Using where | 1 | PRIMARY | 1 | p | d.p_id | PRIMARY + +Okay. Now MySQL is using an index satisfy the WHERE condition. Using the index, it was able to +find the single row that matched, preventing the full table scan. + + +Credits: +The extension of the Array class for printing the columnized records was originally +written by Peter Cooper who adapted it from Courtenay from #caboose. + +http://www.rubyinside.com/columnized-text-datasets-in-rails-71.html +http://habtm.com/articles/2006/06/10/pretty-tables-for-ruby-objects + +Released under the MIT license (download your own if you need it) diff --git a/vendor/plugins/query-analyzer/init.rb b/vendor/plugins/query-analyzer/init.rb new file mode 100644 index 0000000..cf28821 --- /dev/null +++ b/vendor/plugins/query-analyzer/init.rb @@ -0,0 +1 @@ +require 'query_analyzer' \ No newline at end of file diff --git a/vendor/plugins/query-analyzer/lib/query_analyzer.rb b/vendor/plugins/query-analyzer/lib/query_analyzer.rb new file mode 100644 index 0000000..17a3807 --- /dev/null +++ b/vendor/plugins/query-analyzer/lib/query_analyzer.rb @@ -0,0 +1,54 @@ +class Array + protected + def qa_columnized_row(fields, sized) + row = [] + fields.each_with_index do |f, i| + row << sprintf("%0-#{sized[i]}s", f.to_s) + end + row.join(' | ') + end + + public + + def qa_columnized + sized = {} + self.each do |row| + row.values.each_with_index do |value, i| + sized[i] = [sized[i].to_i, row.keys[i].length, value.to_s.length].max + end + end + + table = [] + table << qa_columnized_row(self.first.keys, sized) + table << '-' * table.first.length + self.each { |row| table << qa_columnized_row(row.values, sized) } + table.join("\n ") # Spaces added to work with format_log_entry + end +end + + + +module ActiveRecord + module ConnectionAdapters + class MysqlAdapter < AbstractAdapter + private + alias_method :select_without_analyzer, :select + + def select(sql, name = nil) + query_results = select_without_analyzer(sql, name) + + if @logger and @logger.level == Logger::DEBUG + @logger.debug( + ActiveRecord::Base.silence do + explain_results = select_without_analyzer("explain #{sql}", name) + format_log_entry("\033[1;34m############ FIXME - UNOPTIMIZED QUERY for #{name} ############ \033[0m\n", + "#{explain_results.qa_columnized}\n" + ) if explain_results[0]["rows"].to_i > 100 && sql =~ / where[\s(]/i + end + ) if sql =~ /^select/i + end + query_results + end + end + end +end -- libgit2 0.21.2