[Commits] e235bb8: ANALYZE FORMAT=JSON: better output and tests

Sergei Petrunia psergey at askmonty.org
Sat Nov 29 02:07:24 EET 2014


revision-id: e235bb864d2b8daae3dc7061249f59fb0127bdc5
parent(s): 0b5d989c894a14ebcb786940fafd025e31523d8b
committer: Sergei Petrunia
branch nick: 10.1-explain-json-r5
timestamp: 2014-11-29 03:07:24 +0300
message:

ANALYZE FORMAT=JSON: better output and tests

- Print r_loops
- Always print r_* members. Print NULL values if no scans took place
- Added testcases.

---
 mysql-test/r/analyze_format_json.result |  177 +++++++++++++++++++++++++++++++
 mysql-test/t/analyze_format_json.test   |   38 +++++++
 sql/my_json_writer.cc                   |    6 ++
 sql/my_json_writer.h                    |    1 +
 sql/sql_explain.cc                      |   44 ++++++--
 sql/sql_explain.h                       |   12 ++-
 6 files changed, 270 insertions(+), 8 deletions(-)

diff --git a/mysql-test/r/analyze_format_json.result b/mysql-test/r/analyze_format_json.result
new file mode 100644
index 0000000..91bdfca
--- /dev/null
+++ b/mysql-test/r/analyze_format_json.result
@@ -0,0 +1,177 @@
+drop table if exists t0,t1,t2,t3;
+create table t0 (a int);
+INSERT INTO t0 VALUES (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+# r_filtered=30%, because 3 rows match: 0,1,2
+analyze format=json select * from t0 where a<3;
+EXPLAIN
+{
+  "query_block": {
+    "select_id": 1,
+    "table": {
+      "table_name": "t0",
+      "access_type": "ALL",
+      "r_loops": 1,
+      "rows": 10,
+      "r_rows": 10,
+      "filtered": 100,
+      "r_filtered": 30,
+      "attached_condition": "(t0.a < 3)"
+    }
+  }
+}
+create table t1 (a int, b int, c int, key(a));
+insert into t1 select A.a*10 + B.a, A.a*10 + B.a, A.a*10 + B.a from t0 A, t0 B;
+analyze
+select * from t0, t1 where t1.a=t0.a and t0.a > 9;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	r_rows	filtered	r_filtered	Extra
+1	SIMPLE	t0	ALL	NULL	NULL	NULL	NULL	10	10	100.00	0.00	Using where
+1	SIMPLE	t1	ref	a	a	5	test.t0.a	1	NULL	100.00	NULL	
+analyze format=json 
+select * from t0, t1 where t1.a=t0.a and t0.a > 9;
+EXPLAIN
+{
+  "query_block": {
+    "select_id": 1,
+    "table": {
+      "table_name": "t0",
+      "access_type": "ALL",
+      "r_loops": 1,
+      "rows": 10,
+      "r_rows": 10,
+      "filtered": 100,
+      "r_filtered": 0,
+      "attached_condition": "((t0.a > 9) and (t0.a is not null))"
+    },
+    "table": {
+      "table_name": "t1",
+      "access_type": "ref",
+      "possible_keys": ["a"],
+      "key": "a",
+      "key_length": "5",
+      "used_key_parts": ["a"],
+      "ref": ["test.t0.a"],
+      "r_loops": 0,
+      "rows": 1,
+      "r_rows": null,
+      "filtered": 100,
+      "r_filtered": null
+    }
+  }
+}
+analyze
+select * from t0, t1 where t1.a=t0.a and t1.b<4;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	r_rows	filtered	r_filtered	Extra
+1	SIMPLE	t0	ALL	NULL	NULL	NULL	NULL	10	10	100.00	100.00	Using where
+1	SIMPLE	t1	ref	a	a	5	test.t0.a	1	1	100.00	40.00	Using where
+analyze format=json
+select * from t0, t1 where t1.a=t0.a and t1.b<4;
+EXPLAIN
+{
+  "query_block": {
+    "select_id": 1,
+    "table": {
+      "table_name": "t0",
+      "access_type": "ALL",
+      "r_loops": 1,
+      "rows": 10,
+      "r_rows": 10,
+      "filtered": 100,
+      "r_filtered": 100,
+      "attached_condition": "(t0.a is not null)"
+    },
+    "table": {
+      "table_name": "t1",
+      "access_type": "ref",
+      "possible_keys": ["a"],
+      "key": "a",
+      "key_length": "5",
+      "used_key_parts": ["a"],
+      "ref": ["test.t0.a"],
+      "r_loops": 10,
+      "rows": 1,
+      "r_rows": 1,
+      "filtered": 100,
+      "r_filtered": 40,
+      "attached_condition": "(t1.b < 4)"
+    }
+  }
+}
+analyze 
+select * from t1 A, t1 B where A.b<2 and B.b>5;
+id	select_type	table	type	possible_keys	key	key_len	ref	rows	r_rows	filtered	r_filtered	Extra
+1	SIMPLE	A	ALL	NULL	NULL	NULL	NULL	100	100	100.00	2.00	Using where
+1	SIMPLE	B	ALL	NULL	NULL	NULL	NULL	100	100	100.00	94.00	Using where; Using join buffer (flat, BNL join)
+analyze format=json
+select * from t1 A, t1 B where A.b<20 and B.b<60;
+EXPLAIN
+{
+  "query_block": {
+    "select_id": 1,
+    "table": {
+      "table_name": "A",
+      "access_type": "ALL",
+      "r_loops": 1,
+      "rows": 100,
+      "r_rows": 100,
+      "filtered": 100,
+      "r_filtered": 20,
+      "attached_condition": "(A.b < 20)"
+    },
+    "block-nl-join": {
+      "table": {
+        "table_name": "B",
+        "access_type": "ALL",
+        "r_loops": 1,
+        "rows": 100,
+        "r_rows": 100,
+        "filtered": 100,
+        "r_filtered": 60
+      },
+      "buffer_type": "flat",
+      "join_type": "BNL",
+      "r_filtered": 100
+    }
+  }
+}
+analyze format=json
+select * from t1 A, t1 B where A.b<20 and B.b<60 and A.c > B.c;
+EXPLAIN
+{
+  "query_block": {
+    "select_id": 1,
+    "table": {
+      "table_name": "A",
+      "access_type": "ALL",
+      "r_loops": 1,
+      "rows": 100,
+      "r_rows": 100,
+      "filtered": 100,
+      "r_filtered": 20,
+      "attached_condition": "(A.b < 20)"
+    },
+    "block-nl-join": {
+      "table": {
+        "table_name": "B",
+        "access_type": "ALL",
+        "r_loops": 1,
+        "rows": 100,
+        "r_rows": 100,
+        "filtered": 100,
+        "r_filtered": 60,
+        "attached_condition": "(B.b < 60)"
+      },
+      "buffer_type": "flat",
+      "join_type": "BNL",
+      "attached_condition": "(A.c > B.c)",
+      "r_filtered": 15.833
+    }
+  }
+}
+select count(*) from t1 A, t1 B where A.b<20 and B.b<60;
+count(*)
+1200
+select count(*) from t1 A, t1 B where A.b<20 and B.b<60 and A.c > B.c;
+count(*)
+190
+drop table t1;
+drop table t0;
diff --git a/mysql-test/t/analyze_format_json.test b/mysql-test/t/analyze_format_json.test
new file mode 100644
index 0000000..f1fe701
--- /dev/null
+++ b/mysql-test/t/analyze_format_json.test
@@ -0,0 +1,38 @@
+#
+#  Tests for "ANALYZE FORMAT=JSON $statement" syntax
+#
+--disable_warnings
+drop table if exists t0,t1,t2,t3;
+--enable_warnings
+
+create table t0 (a int);
+INSERT INTO t0 VALUES (0),(1),(2),(3),(4),(5),(6),(7),(8),(9);
+
+--echo # r_filtered=30%, because 3 rows match: 0,1,2
+analyze format=json select * from t0 where a<3;
+
+create table t1 (a int, b int, c int, key(a));
+insert into t1 select A.a*10 + B.a, A.a*10 + B.a, A.a*10 + B.a from t0 A, t0 B;
+
+analyze
+select * from t0, t1 where t1.a=t0.a and t0.a > 9;
+analyze format=json 
+select * from t0, t1 where t1.a=t0.a and t0.a > 9;
+
+analyze
+select * from t0, t1 where t1.a=t0.a and t1.b<4;
+
+analyze format=json
+select * from t0, t1 where t1.a=t0.a and t1.b<4;
+
+analyze 
+select * from t1 A, t1 B where A.b<2 and B.b>5;
+
+analyze format=json
+select * from t1 A, t1 B where A.b<20 and B.b<60;
+
+analyze format=json
+select * from t1 A, t1 B where A.b<20 and B.b<60 and A.c > B.c;
+
+drop table t1;
+drop table t0;
diff --git a/sql/my_json_writer.cc b/sql/my_json_writer.cc
index 99be150..6f36a1e 100644
--- a/sql/my_json_writer.cc
+++ b/sql/my_json_writer.cc
@@ -131,6 +131,12 @@ void Json_writer::add_bool(bool val)
 }
 
 
+void Json_writer::add_null()
+{
+  add_unquoted_str("null");
+}
+
+
 void Json_writer::add_unquoted_str(const char* str)
 {
   if (fmt_helper.on_add_str(str))
diff --git a/sql/my_json_writer.h b/sql/my_json_writer.h
index 35bd5cb..48e743b 100644
--- a/sql/my_json_writer.h
+++ b/sql/my_json_writer.h
@@ -99,6 +99,7 @@ class Json_writer
   void add_ll(longlong val);
   void add_double(double val);
   void add_bool(bool val);
+  void add_null();
 
 private:
   void add_unquoted_str(const char* val);
diff --git a/sql/sql_explain.cc b/sql/sql_explain.cc
index 4dce48e..7297382 100644
--- a/sql/sql_explain.cc
+++ b/sql/sql_explain.cc
@@ -815,10 +815,14 @@ void Explain_index_use::set_pseudo_key(MEM_ROOT *root, const char* key_name_arg)
 }
 
 
+/*
+  Given r_filtered% from join buffer condition and join condition, produce a
+  combined r_filtered% number. This is needed for tabular EXPLAIN output which
+  has only one cell for r_filtered value.
+*/
+
 double Explain_table_access::get_r_filtered()
 {
-  //psergey-todo: modify this to produce separate filtered% for both parts of
-  //WHERE.
   double r_filtered= tracker.get_filtered_after_where();
   if (bka_type.is_using_jbuf())
     r_filtered *= jbuf_tracker.get_filtered_after_where();
@@ -1156,15 +1160,27 @@ void Explain_table_access::print_explain_json(Explain_query *query,
     writer->end_array();
   }
 
+  /* r_loops (not present in tabular output) */
+  if (is_analyze)
+  {
+    writer->add_member("r_loops").add_ll(tracker.get_loops());
+  }
+  
   /* `rows` */
   if (rows_set)
     writer->add_member("rows").add_ll(rows);
 
   /* `r_rows` */
-  if (is_analyze && tracker.has_scans())
+  if (is_analyze)
   {
-    ha_rows avg_rows= tracker.get_avg_rows();
-    writer->add_member("r_rows").add_ll(avg_rows);
+    writer->add_member("r_rows");
+    if (tracker.has_scans())
+    {
+      ha_rows avg_rows= tracker.get_avg_rows();
+      writer->add_ll(avg_rows);
+    }
+    else
+      writer->add_null();
   }
   
   /* `filtered` */
@@ -1173,7 +1189,13 @@ void Explain_table_access::print_explain_json(Explain_query *query,
 
   /* `r_filtered` */
   if (is_analyze)
-    writer->add_member("r_filtered").add_double(get_r_filtered());
+  {
+    writer->add_member("r_filtered");
+    if (tracker.has_scans())
+      writer->add_double(tracker.get_filtered_after_where()*100.0);
+    else
+      writer->add_null();
+  }
 
   for (int i=0; i < (int)extra_tags.elements(); i++)
   {
@@ -1193,6 +1215,16 @@ void Explain_table_access::print_explain_json(Explain_query *query,
       writer->add_member("attached_condition");
       write_item(writer, where_cond);
     }
+
+    if (is_analyze)
+    {
+      //writer->add_member("r_loops").add_ll(jbuf_tracker.get_loops());
+      writer->add_member("r_filtered");
+      if (jbuf_tracker.has_scans())
+        writer->add_double(jbuf_tracker.get_filtered_after_where()*100.0);
+      else
+        writer->add_null();
+    }
   }
 
   if (derived_select_number)
diff --git a/sql/sql_explain.h b/sql/sql_explain.h
index a6a0aff..5d6b28f 100644
--- a/sql/sql_explain.h
+++ b/sql/sql_explain.h
@@ -22,8 +22,13 @@ class String_list: public List<char>
 };
 
 
+/*
+  A class for collecting read statistics.
+  
+  The idea is that we run several scans. Each scans gets rows, and then filters
+  some of them out.  We count scans, rows, and rows left after filtering.
+*/
 
-/* Data structures for ANALYZE */
 class Table_access_tracker 
 {
 public:
@@ -38,6 +43,7 @@ class Table_access_tracker
   ha_rows r_rows_after_where; /* Rows after applying attached part of WHERE */
 
   bool has_scans() { return (r_scans != 0); }
+  ha_rows get_loops() { return r_scans; }
   ha_rows get_avg_rows()
   {
     return r_scans ? (ha_rows)rint((double) r_rows / r_scans): 0;
@@ -611,7 +617,9 @@ class Explain_table_access : public Sql_alloc
   void print_explain_json(Explain_query *query, Json_writer *writer,
                           bool is_analyze);
 
-  /* ANALYZE members*/
+  /* ANALYZE members */
+
+  /* Tracker for reading the table */
   Table_access_tracker tracker;
   Table_access_tracker jbuf_tracker;
 


More information about the commits mailing list