mirror of
https://github.com/percona/percona-toolkit.git
synced 2025-09-10 05:00:45 +00:00
Add pt-table-usage and update SQLParser.pm from Maatkit.
This commit is contained in:
7320
bin/pt-table-usage
Executable file
7320
bin/pt-table-usage
Executable file
File diff suppressed because it is too large
Load Diff
106
lib/SQLParser.pm
106
lib/SQLParser.pm
@@ -1,4 +1,4 @@
|
||||
# This program is copyright 2010-2011 Percona Inc.
|
||||
# This program is copyright 2010-2012 Percona Inc.
|
||||
# Feedback and improvements are welcome.
|
||||
#
|
||||
# THIS PROGRAM IS PROVIDED "AS IS" AND WITHOUT ANY EXPRESS OR IMPLIED
|
||||
@@ -77,6 +77,21 @@ my $column_ident = qr/(?:
|
||||
(?:$ident_alias)? # optional alias
|
||||
)/xo;
|
||||
|
||||
my $function_ident = qr/
|
||||
\b
|
||||
(
|
||||
\w+ # function name
|
||||
\( # opening parenthesis
|
||||
[^\)]+ # function args, if any
|
||||
\) # closing parenthesis
|
||||
)
|
||||
/x;
|
||||
|
||||
my %ignore_function = (
|
||||
INDEX => 1,
|
||||
KEY => 1,
|
||||
);
|
||||
|
||||
# Sub: new
|
||||
# Create a SQLParser object.
|
||||
#
|
||||
@@ -132,6 +147,7 @@ sub parse {
|
||||
|REPLACE
|
||||
|SELECT
|
||||
|UPDATE
|
||||
|CREATE
|
||||
)/xi;
|
||||
|
||||
# Flatten and clean query.
|
||||
@@ -160,6 +176,11 @@ sub parse {
|
||||
@subqueries = $self->remove_subqueries($query);
|
||||
$query = shift @subqueries;
|
||||
}
|
||||
elsif ( $type eq 'create' && $query =~ m/\s+SELECT/ ) {
|
||||
PTDEBUG && _d('CREATE..SELECT');
|
||||
($subqueries[0]->{query}) = $query =~ m/\s+(SELECT .+)/;
|
||||
$query =~ s/\s+SELECT.+//;
|
||||
}
|
||||
|
||||
# Parse raw text parts from query. The parse_TYPE subs only do half
|
||||
# the work: parsing raw text parts of clauses, tables, functions, etc.
|
||||
@@ -442,6 +463,20 @@ sub parse_update {
|
||||
|
||||
}
|
||||
|
||||
sub parse_create {
|
||||
my ($self, $query) = @_;
|
||||
my ($obj, $name) = $query =~ m/
|
||||
(\S+)\s+
|
||||
(?:IF NOT EXISTS\s+)?
|
||||
(\S+)
|
||||
/xi;
|
||||
return {
|
||||
object => lc $obj,
|
||||
name => $name,
|
||||
unknown => undef,
|
||||
};
|
||||
}
|
||||
|
||||
# Sub: parse_from
|
||||
# Parse a FROM clause, a.k.a. the table references. Does not handle
|
||||
# nested joins. See http://dev.mysql.com/doc/refman/5.1/en/join.html
|
||||
@@ -485,6 +520,14 @@ sub parse_from {
|
||||
return unless $from;
|
||||
PTDEBUG && _d('Parsing FROM', $from);
|
||||
|
||||
# Extract the column list from USING(col, ...) clauses else
|
||||
# the inner commas will be captured by $comma_join.
|
||||
my $using_cols;
|
||||
($from, $using_cols) = $self->remove_using_columns($from);
|
||||
|
||||
my $funcs;
|
||||
($from, $funcs) = $self->remove_functions($from);
|
||||
|
||||
# Table references in a FROM clause are separated either by commas
|
||||
# (comma/theta join, implicit INNER join) or the JOIN keyword (ansi
|
||||
# join). JOIN can be preceded by other keywords like LEFT, RIGHT,
|
||||
@@ -525,16 +568,13 @@ sub parse_from {
|
||||
if ( $join->{condition} eq 'on' ) {
|
||||
# The value for ON can be, as the MySQL manual says, is just
|
||||
# like a WHERE clause.
|
||||
my $where = $self->parse_where($join_condition_value);
|
||||
$join->{where} = $where;
|
||||
$join->{where} = $self->parse_where($join_condition_value, $funcs);
|
||||
}
|
||||
else { # USING
|
||||
# Although calling parse_columns() works, it's overkill.
|
||||
# This is not a columns def as in "SELECT col1, col2", it's
|
||||
# a simple csv list of column names without aliases, etc.
|
||||
$join_condition_value =~ s/^\s*\(//;
|
||||
$join_condition_value =~ s/\)\s*$//;
|
||||
$join->{columns} = $self->_parse_csv($join_condition_value);
|
||||
$join->{columns} = $self->_parse_csv(shift @$using_cols);
|
||||
}
|
||||
}
|
||||
elsif ( $thing =~ m/(?:,|JOIN)/i ) {
|
||||
@@ -694,7 +734,7 @@ sub parse_table_reference {
|
||||
# Invalid predicates, or valid ones that we can't parse, will cause
|
||||
# the sub to die.
|
||||
sub parse_where {
|
||||
my ( $self, $where ) = @_;
|
||||
my ( $self, $where, $functions ) = @_;
|
||||
return unless $where;
|
||||
PTDEBUG && _d("Parsing WHERE", $where);
|
||||
|
||||
@@ -705,7 +745,7 @@ sub parse_where {
|
||||
# not interested in weird stuff like that.
|
||||
my $op_symbol = qr/
|
||||
(?:
|
||||
<=
|
||||
<=(?:>)?
|
||||
|>=
|
||||
|<>
|
||||
|!=
|
||||
@@ -827,6 +867,11 @@ sub parse_where {
|
||||
$val = lc $val;
|
||||
}
|
||||
|
||||
if ( $functions ) {
|
||||
$col = shift @$functions if $col =~ m/__FUNC\d+__/;
|
||||
$val = shift @$functions if $val =~ m/__FUNC\d+__/;
|
||||
}
|
||||
|
||||
push @predicates, {
|
||||
predicate => $conj,
|
||||
left_arg => $col,
|
||||
@@ -1164,6 +1209,44 @@ sub remove_subqueries {
|
||||
return $query, @subqueries;
|
||||
}
|
||||
|
||||
sub remove_using_columns {
|
||||
my ($self, $from) = @_;
|
||||
return unless $from;
|
||||
PTDEBUG && _d('Removing cols from USING clauses');
|
||||
my $using = qr/
|
||||
\bUSING
|
||||
\s*
|
||||
\(
|
||||
([^\)]+)
|
||||
\)
|
||||
/xi;
|
||||
my @cols;
|
||||
$from =~ s/$using/push @cols, $1; "USING ($#cols)"/eg;
|
||||
PTDEBUG && _d('FROM:', $from, Dumper(\@cols));
|
||||
return $from, \@cols;
|
||||
}
|
||||
|
||||
sub replace_function {
|
||||
my ($func, $funcs) = @_;
|
||||
my ($func_name) = $func =~ m/^(\w+)/;
|
||||
if ( !$ignore_function{uc $func_name} ) {
|
||||
my $n = scalar @$funcs;
|
||||
push @$funcs, $func;
|
||||
return "__FUNC${n}__";
|
||||
}
|
||||
return $func;
|
||||
}
|
||||
|
||||
sub remove_functions {
|
||||
my ($self, $clause) = @_;
|
||||
return unless $clause;
|
||||
PTDEBUG && _d('Removing functions from clause:', $clause);
|
||||
my @funcs;
|
||||
$clause =~ s/$function_ident/replace_function($1, \@funcs)/eg;
|
||||
PTDEBUG && _d('Function-stripped clause:', $clause, Dumper(\@funcs));
|
||||
return $clause, \@funcs;
|
||||
}
|
||||
|
||||
# Sub: parse_identifiers
|
||||
# Parse an arrayref of identifiers into their parts. Identifiers can be
|
||||
# column names (optionally qualified), expressions, or constants.
|
||||
@@ -1216,6 +1299,13 @@ sub parse_identifier {
|
||||
return unless $type && $ident;
|
||||
PTDEBUG && _d("Parsing", $type, "identifier:", $ident);
|
||||
|
||||
if ( $ident =~ m/^\w+\(/ ) { # Function like MIN(col)
|
||||
my ($func, $expr) = $ident =~ m/^(\w+)\(([^\)]*)\)/;
|
||||
PTDEBUG && _d('Function', $func, 'arg', $expr);
|
||||
return { col => $ident } unless $expr; # NOW()
|
||||
$ident = $expr; # col from MAX(col)
|
||||
}
|
||||
|
||||
my %ident_struct;
|
||||
my @ident_parts = map { s/`//g; $_; } split /[.]/, $ident;
|
||||
if ( @ident_parts == 3 ) {
|
||||
|
1060
lib/TableUsage.pm
Normal file
1060
lib/TableUsage.pm
Normal file
File diff suppressed because it is too large
Load Diff
817
t/lib/TableUsage.t
Normal file
817
t/lib/TableUsage.t
Normal file
@@ -0,0 +1,817 @@
|
||||
#!/usr/bin/perl
|
||||
|
||||
BEGIN {
|
||||
die "The MAATKIT_WORKING_COPY environment variable is not set. See http://code.google.com/p/maatkit/wiki/Testing"
|
||||
unless $ENV{MAATKIT_WORKING_COPY} && -d $ENV{MAATKIT_WORKING_COPY};
|
||||
unshift @INC, "$ENV{MAATKIT_WORKING_COPY}/common";
|
||||
};
|
||||
|
||||
use strict;
|
||||
use warnings FATAL => 'all';
|
||||
use English qw(-no_match_vars);
|
||||
use Test::More tests => 34;
|
||||
|
||||
use MaatkitTest;
|
||||
use QueryParser;
|
||||
use SQLParser;
|
||||
use TableUsage;
|
||||
use Sandbox;
|
||||
|
||||
my $dp = new DSNParser(opts=>$dsn_opts);
|
||||
my $sb = new Sandbox(basedir => '/tmp', DSNParser => $dp);
|
||||
my $dbh = $sb->get_dbh_for('master');
|
||||
|
||||
use Data::Dumper;
|
||||
$Data::Dumper::Indent = 1;
|
||||
$Data::Dumper::Sortkeys = 1;
|
||||
$Data::Dumper::Quotekeys = 0;
|
||||
|
||||
my $qp = new QueryParser();
|
||||
my $sp = new SQLParser();
|
||||
my $ta = new TableUsage(QueryParser => $qp, SQLParser => $sp);
|
||||
isa_ok($ta, 'TableUsage');
|
||||
|
||||
sub test_get_table_usage {
|
||||
my ( $query, $cats, $desc ) = @_;
|
||||
my $got = $ta->get_table_usage(query=>$query);
|
||||
is_deeply(
|
||||
$got,
|
||||
$cats,
|
||||
$desc,
|
||||
) or print Dumper($got);
|
||||
return;
|
||||
}
|
||||
|
||||
# ############################################################################
|
||||
# Queries parsable by SQLParser: SELECT, INSERT, UPDATE and DELETE
|
||||
# ############################################################################
|
||||
test_get_table_usage(
|
||||
"SELECT * FROM d.t WHERE id>100",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'd.t',
|
||||
},
|
||||
],
|
||||
],
|
||||
"SELECT FROM one table"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"SELECT t1.* FROM d.t1 LEFT JOIN d.t2 USING (id) WHERE d.t2.foo IS NULL",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'd.t1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'd.t1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'd.t2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'd.t2',
|
||||
},
|
||||
],
|
||||
],
|
||||
"SELECT JOIN two tables"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"DELETE FROM d.t WHERE type != 'D' OR type IS NULL",
|
||||
[
|
||||
[
|
||||
{ context => 'DELETE',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'd.t',
|
||||
},
|
||||
],
|
||||
],
|
||||
"DELETE one table"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"INSERT INTO d.t (col1, col2) VALUES ('a', 'b')",
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
],
|
||||
],
|
||||
"INSERT VALUES, no SELECT"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"INSERT INTO d.t SET col1='a', col2='b'",
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
],
|
||||
],
|
||||
"INSERT SET, no SELECT"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"UPDATE d.t SET foo='bar' WHERE foo IS NULL",
|
||||
[
|
||||
[
|
||||
{ context => 'UPDATE',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'd.t',
|
||||
},
|
||||
],
|
||||
],
|
||||
"UPDATE one table"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"SELECT * FROM zn.edp
|
||||
INNER JOIN zn.edp_input_key edpik ON edp.id = edpik.id
|
||||
INNER JOIN `zn`.`key` input_key ON edpik.input_key = input_key.id
|
||||
WHERE edp.id = 296",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'zn.edp',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'zn.edp_input_key',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'zn.key',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.edp',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.edp_input_key',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.key',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'zn.edp',
|
||||
},
|
||||
],
|
||||
],
|
||||
"SELECT with 2 JOIN and WHERE"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"REPLACE INTO db.tblA (dt, ncpc)
|
||||
SELECT dates.dt, scraped.total_r
|
||||
FROM tblB AS dates
|
||||
LEFT JOIN dbF.tblC AS scraped
|
||||
ON dates.dt = scraped.dt AND dates.version = scraped.version",
|
||||
[
|
||||
[
|
||||
{ context => 'REPLACE',
|
||||
table => 'db.tblA',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'tblB',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'dbF.tblC',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'tblB',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'dbF.tblC',
|
||||
},
|
||||
],
|
||||
],
|
||||
"REPLACE SELECT JOIN"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'UPDATE t1 AS a JOIN t2 AS b USING (id) SET a.foo="bar" WHERE b.foo IS NOT NULL',
|
||||
[
|
||||
[
|
||||
{ context => 'UPDATE',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't2',
|
||||
},
|
||||
],
|
||||
],
|
||||
"UPDATE joins 2 tables, writes to 1, filters by 1"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'UPDATE t1 INNER JOIN t2 USING (id) SET t1.foo="bar" WHERE t1.id>100 AND t2.id>200',
|
||||
[
|
||||
[
|
||||
{ context => 'UPDATE',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't2',
|
||||
},
|
||||
],
|
||||
],
|
||||
"UPDATE joins 2 tables, writes to 1, filters by 2"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'UPDATE t1 AS a JOIN t2 AS b USING (id) SET a.foo="bar", b.foo="bat" WHERE a.id=1',
|
||||
[
|
||||
[
|
||||
{ context => 'UPDATE',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't1',
|
||||
},
|
||||
],
|
||||
[
|
||||
{ context => 'UPDATE',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't1',
|
||||
},
|
||||
],
|
||||
],
|
||||
"UPDATE joins 2 tables, writes to 2, filters by 1"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'insert into t1 (a, b, c) select x, y, z from t2 where x is not null',
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 't1',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 't2',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 't2',
|
||||
},
|
||||
],
|
||||
],
|
||||
"INSERT INTO t1 SELECT FROM t2",
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'insert into t (a, b, c) select a.x, a.y, b.z from a, b where a.id=b.id',
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 't',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'b',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'b',
|
||||
},
|
||||
],
|
||||
],
|
||||
"INSERT INTO t SELECT FROM a, b"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
'INSERT INTO bar
|
||||
SELECT edpik.*
|
||||
FROM zn.edp
|
||||
INNER JOIN zn.edp_input_key AS edpik ON edpik.id = edp.id
|
||||
INNER JOIN `zn`.`key` input_key
|
||||
INNER JOIN foo
|
||||
WHERE edp.id = 296
|
||||
AND edpik.input_key = input_key.id',
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 'bar',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'zn.edp_input_key',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.edp',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.edp_input_key',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'zn.key',
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'foo',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'zn.edp',
|
||||
},
|
||||
|
||||
],
|
||||
],
|
||||
"INSERT SELECT with TLIST table"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select country.country, city.city from city join country using (country_id) where country = 'Brazil' and city like 'A%' limit 1",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'country',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'city',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'city',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'country',
|
||||
},
|
||||
],
|
||||
],
|
||||
"Unresolvable tables in WHERE"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select c from t where 1",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 't',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'DUAL',
|
||||
},
|
||||
],
|
||||
],
|
||||
"WHERE <constant>"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select c from t where 1=1",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 't',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'DUAL',
|
||||
},
|
||||
],
|
||||
],
|
||||
"WHERE <constant>=<constant>"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select now()",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'DUAL',
|
||||
},
|
||||
],
|
||||
],
|
||||
"SELECT NOW()"
|
||||
);
|
||||
|
||||
#test_get_table_usage(
|
||||
# "SELECT
|
||||
# automated_process.id id,
|
||||
# class,
|
||||
# automated_process_instance.server,
|
||||
# IF(start IS NULL, 0, 1),
|
||||
# owner
|
||||
# FROM
|
||||
# zn.automated_process_instance
|
||||
# INNER JOIN zn.automated_process ON automated_process=automated_process.id
|
||||
# WHERE
|
||||
# automated_process_instance.id = 5251414",
|
||||
# [
|
||||
# [
|
||||
# { context => 'SELECT',
|
||||
# table => 'zn.automated_process',
|
||||
# },
|
||||
# { context => 'SELECT',
|
||||
# table => 'zn.automated_process_instance',
|
||||
# },
|
||||
# { context => 'JOIN',
|
||||
# table => 'zn.automated_process_instance',
|
||||
# },
|
||||
# { context => 'JOIN',
|
||||
# table => 'zn.automated_process',
|
||||
# },
|
||||
# { context => 'WHERE',
|
||||
# table => 'zn.automated_process_instance',
|
||||
# },
|
||||
# ]
|
||||
# ],
|
||||
# "SELECT explicit INNER JOIN with condition"
|
||||
#);
|
||||
|
||||
# ############################################################################
|
||||
# Queries parsable by QueryParser
|
||||
# ############################################################################
|
||||
test_get_table_usage(
|
||||
"ALTER TABLE tt.ks ADD PRIMARY KEY(`d`,`v`)",
|
||||
[
|
||||
[
|
||||
{ context => 'ALTER',
|
||||
table => 'tt.ks',
|
||||
},
|
||||
],
|
||||
],
|
||||
"ALTER TABLE"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"DROP TABLE foo",
|
||||
[
|
||||
[
|
||||
{ context => 'DROP_TABLE',
|
||||
table => 'foo',
|
||||
},
|
||||
],
|
||||
],
|
||||
"DROP TABLE"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"DROP TABLE IF EXISTS foo",
|
||||
[
|
||||
[
|
||||
{ context => 'DROP_TABLE',
|
||||
table => 'foo',
|
||||
},
|
||||
],
|
||||
],
|
||||
"DROP TABLE IF EXISTS"
|
||||
);
|
||||
|
||||
# #############################################################################
|
||||
# Change DUAL to something else.
|
||||
# #############################################################################
|
||||
$ta = new TableUsage(
|
||||
QueryParser => $qp,
|
||||
SQLParser => $sp,
|
||||
constant_data_value => '<const>',
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"INSERT INTO d.t (col1, col2) VALUES ('a', 'b')",
|
||||
[
|
||||
[
|
||||
{ context => 'INSERT',
|
||||
table => 'd.t',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => '<const>',
|
||||
},
|
||||
],
|
||||
],
|
||||
"Change constant_data_value"
|
||||
);
|
||||
|
||||
# Restore original TableUsage obj for other tests.
|
||||
$ta = new TableUsage(
|
||||
QueryParser => $qp,
|
||||
SQLParser => $sp,
|
||||
);
|
||||
|
||||
|
||||
# ###########################################################################
|
||||
# CREATE
|
||||
# ###########################################################################
|
||||
|
||||
test_get_table_usage(
|
||||
"CREATE TABLE db.tbl (id INT) ENGINE=InnoDB",
|
||||
[
|
||||
[
|
||||
{ context => 'CREATE',
|
||||
table => 'db.tbl',
|
||||
},
|
||||
],
|
||||
],
|
||||
"CREATE TABLE",
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"CREATE TABLE db.tbl SELECT city_id FROM sakila.city WHERE city_id>100",
|
||||
[
|
||||
[
|
||||
{ context => 'CREATE',
|
||||
table => 'db.tbl',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'sakila.city',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.city',
|
||||
},
|
||||
],
|
||||
],
|
||||
"CREATE..SELECT"
|
||||
);
|
||||
|
||||
# ############################################################################
|
||||
# Use Schema instead of EXPLAIN EXTENDED.
|
||||
# ############################################################################
|
||||
use OptionParser;
|
||||
use DSNParser;
|
||||
use Quoter;
|
||||
use TableParser;
|
||||
use FileIterator;
|
||||
use Schema;
|
||||
use SchemaIterator;
|
||||
|
||||
my $o = new OptionParser(description => 'SchemaIterator');
|
||||
$o->get_specs("$trunk/mk-table-checksum/mk-table-checksum");
|
||||
|
||||
my $q = new Quoter;
|
||||
my $tp = new TableParser(Quoter => $q);
|
||||
my $fi = new FileIterator();
|
||||
my $file_itr = $fi->get_file_itr("$trunk/common/t/samples/mysqldump-no-data/dump001.txt");
|
||||
my $schema = new Schema();
|
||||
my $schema_itr = new SchemaIterator(
|
||||
file_itr => $file_itr,
|
||||
OptionParser => $o,
|
||||
Quoter => $q,
|
||||
TableParser => $tp,
|
||||
keep_ddl => 1,
|
||||
Schema => $schema,
|
||||
);
|
||||
# Init schema.
|
||||
1 while ($schema_itr->next_schema_object());
|
||||
|
||||
# Before, this is as correct as we can determine. The WHERE access is missing
|
||||
# because c3 is not qualified and there's multiple tables, so the code can't
|
||||
# figure out to which table it belongs.
|
||||
test_get_table_usage(
|
||||
"SELECT a.c1, c3 FROM a JOIN b ON a.c2=c3 WHERE NOW()<c3",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'b',
|
||||
},
|
||||
],
|
||||
],
|
||||
"Tables without Schema"
|
||||
);
|
||||
|
||||
# After, now we have a db for table b, but not for a because the schema
|
||||
# we loaded has two table a (test.a and test2.a). The WHERE access is
|
||||
# now present.
|
||||
$sp->set_Schema($schema);
|
||||
test_get_table_usage(
|
||||
"SELECT a.c1, c3 FROM a JOIN b ON a.c2=c3 WHERE NOW()<c3",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'test.b',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'a',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'test.b',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'test.b',
|
||||
},
|
||||
],
|
||||
],
|
||||
"Tables with Schema"
|
||||
);
|
||||
|
||||
# Set it back for the next tests.
|
||||
$sp->set_Schema(undef);
|
||||
|
||||
# #############################################################################
|
||||
# Use a dbh for EXPLAIN EXTENDED.
|
||||
# #############################################################################
|
||||
SKIP: {
|
||||
skip 'Cannot connect to sandbox master', 1 unless $dbh;
|
||||
|
||||
|
||||
$ta = new TableUsage(
|
||||
QueryParser => $qp,
|
||||
SQLParser => $sp,
|
||||
dbh => $dbh,
|
||||
);
|
||||
|
||||
# Compare this with the same query/test after USE sakila.
|
||||
test_get_table_usage(
|
||||
"select city_id, country.country_id from city, country where city_id>100 or country='Brazil' limit 1",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'country'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'city'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'country'
|
||||
},
|
||||
]
|
||||
],
|
||||
"Ambiguous tables"
|
||||
);
|
||||
|
||||
is_deeply(
|
||||
$ta->errors(),
|
||||
[ 'NO_DB_SELECTED' ],
|
||||
'NO_DB_SELECTED error'
|
||||
);
|
||||
|
||||
$dbh->do('USE sakila');
|
||||
|
||||
test_get_table_usage(
|
||||
"select city_id, country.country_id from city, country where city_id>100 or country='Brazil' limit 1",
|
||||
[
|
||||
[ { context => 'SELECT',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.country'
|
||||
}
|
||||
],
|
||||
],
|
||||
"Disambiguate WHERE columns"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select city_id, country from city, country where city.city_id>100 or country.country='China' limit 1",
|
||||
[
|
||||
[ { context => 'SELECT',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'TLIST',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.country'
|
||||
}
|
||||
],
|
||||
],
|
||||
"Disambiguate CLIST columns"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"select city.city, country.country from city join country on city=country where city.city_id>100 or country.country='China' limit 1",
|
||||
[
|
||||
[ { context => 'SELECT',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'SELECT',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'sakila.country'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.city'
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.country'
|
||||
}
|
||||
],
|
||||
],
|
||||
"Disambiguate JOIN columns"
|
||||
);
|
||||
|
||||
test_get_table_usage(
|
||||
"SELECT COUNT(*), MAX(country_id), MIN(country_id) FROM sakila.city A JOIN sakila.country B USING (country_id) WHERE B.country = 'Brazil'",
|
||||
[
|
||||
[
|
||||
{ context => 'SELECT',
|
||||
table => 'sakila.city',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'sakila.city',
|
||||
},
|
||||
{ context => 'JOIN',
|
||||
table => 'sakila.country',
|
||||
},
|
||||
{ context => 'WHERE',
|
||||
table => 'sakila.country',
|
||||
},
|
||||
],
|
||||
],
|
||||
"SELECT with multiple CLIST functions"
|
||||
);
|
||||
}
|
||||
|
||||
# #############################################################################
|
||||
# Done.
|
||||
# #############################################################################
|
||||
my $output = '';
|
||||
{
|
||||
local *STDERR;
|
||||
open STDERR, '>', \$output;
|
||||
$ta->_d('Complete test coverage');
|
||||
}
|
||||
like(
|
||||
$output,
|
||||
qr/Complete test coverage/,
|
||||
'_d() works'
|
||||
);
|
||||
exit;
|
138
t/pt-table-usage/basics.t
Normal file
138
t/pt-table-usage/basics.t
Normal file
@@ -0,0 +1,138 @@
|
||||
#!/usr/bin/env perl
|
||||
|
||||
BEGIN {
|
||||
die "The PERCONA_TOOLKIT_BRANCH environment variable is not set.\n"
|
||||
unless $ENV{PERCONA_TOOLKIT_BRANCH} && -d $ENV{PERCONA_TOOLKIT_BRANCH};
|
||||
unshift @INC, "$ENV{PERCONA_TOOLKIT_BRANCH}/lib";
|
||||
};
|
||||
|
||||
use strict;
|
||||
use warnings FATAL => 'all';
|
||||
use English qw(-no_match_vars);
|
||||
use Test::More tests => 10;
|
||||
|
||||
use PerconaTest;
|
||||
require "$trunk/bin/pt-table-usage";
|
||||
|
||||
my @args = qw();
|
||||
my $in = "$trunk/t/pt-table-usage/samples/in";
|
||||
my $out = "t/pt-table-usage/samples/out";
|
||||
my $output = '';
|
||||
|
||||
# ############################################################################
|
||||
# Basic queries that parse without problems.
|
||||
# ############################################################################
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, "$in/slow001.txt") },
|
||||
"$out/slow001.txt",
|
||||
),
|
||||
'Analysis for slow001.txt'
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, "$in/slow002.txt") },
|
||||
"$out/slow002.txt",
|
||||
),
|
||||
'Analysis for slow002.txt (issue 1237)'
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, '--query',
|
||||
'DROP TABLE IF EXISTS t') },
|
||||
"$out/drop-table-if-exists.txt",
|
||||
),
|
||||
'DROP TABLE IF EXISTS'
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, '--query',
|
||||
"create table temp.5 (
|
||||
datetime DATETIME,
|
||||
posted DATETIME,
|
||||
PRIMARY KEY(datetime)
|
||||
)
|
||||
SELECT c FROM t WHERE id=1")
|
||||
},
|
||||
"$out/create001.txt",
|
||||
),
|
||||
'CREATE..SELECT'
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, '--query',
|
||||
"select a.dt,a.hr,a.count
|
||||
from temp.temp6 a left join n.type b using (dt,hr)
|
||||
where b.type is null OR b.type=0")
|
||||
},
|
||||
"$out/query001.txt",
|
||||
),
|
||||
'Multi-column USING'
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, '--query',
|
||||
"SELECT dt.datetime, MAX(re.pd) AS pd FROM d1.t1 t1a INNER JOIN d2.t2 t2a ON CONCAT(t1.a, ' ', t2.a) = t1.datetime INNER JOIN d3.t3 t3a ON t1a.c = t3a.c GROUP BY t1.datetime");
|
||||
},
|
||||
"$out/query002.txt",
|
||||
),
|
||||
'Function in JOIN clause'
|
||||
);
|
||||
|
||||
# ############################################################################
|
||||
# --id-attribute
|
||||
# ############################################################################
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, "$in/slow003.txt",
|
||||
qw(--id-attribute ts)) },
|
||||
"$out/slow003-003.txt",
|
||||
),
|
||||
'Analysis for slow003.txt with --id-attribute'
|
||||
);
|
||||
|
||||
# ############################################################################
|
||||
# --constant-data-value
|
||||
# ############################################################################
|
||||
$output = output(
|
||||
sub { pt_table_usage::main('--query', 'INSERT INTO t VALUES (42)',
|
||||
qw(--constant-data-value <const>)) },
|
||||
);
|
||||
like(
|
||||
$output,
|
||||
qr/SELECT <const>/,
|
||||
"--constant-data-value"
|
||||
);
|
||||
|
||||
$output = output(
|
||||
sub { pt_table_usage::main('--query', 'INSERT INTO t VALUES (42)',
|
||||
qw(--constant-data-value), "") },
|
||||
);
|
||||
like(
|
||||
$output,
|
||||
qr/^SELECT\s+$/m,
|
||||
'--constant-data-value ""'
|
||||
);
|
||||
|
||||
# ############################################################################
|
||||
# Queries with tables that can't be resolved.
|
||||
# ############################################################################
|
||||
|
||||
# The tables in the WHERE can't be resolved so there's no WHERE access listed.
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, "$in/slow003.txt") },
|
||||
"$out/slow003-001.txt",
|
||||
),
|
||||
'Analysis for slow003.txt'
|
||||
);
|
||||
|
||||
# #############################################################################
|
||||
# Done.
|
||||
# #############################################################################
|
||||
exit;
|
41
t/pt-table-usage/create_table_definitions.t
Normal file
41
t/pt-table-usage/create_table_definitions.t
Normal file
@@ -0,0 +1,41 @@
|
||||
#!/usr/bin/env perl
|
||||
|
||||
BEGIN {
|
||||
die "The PERCONA_TOOLKIT_BRANCH environment variable is not set.\n"
|
||||
unless $ENV{PERCONA_TOOLKIT_BRANCH} && -d $ENV{PERCONA_TOOLKIT_BRANCH};
|
||||
unshift @INC, "$ENV{PERCONA_TOOLKIT_BRANCH}/lib";
|
||||
};
|
||||
|
||||
use strict;
|
||||
use warnings FATAL => 'all';
|
||||
use English qw(-no_match_vars);
|
||||
use Test::More tests => 1;
|
||||
|
||||
use PerconaTest;
|
||||
require "$trunk/bin/pt-table-usage";
|
||||
|
||||
my @args = qw();
|
||||
my $in = "$trunk/t/pt-table-usage/samples/in";
|
||||
my $out = "t/pt-table-usage/samples/out";
|
||||
my $output = '';
|
||||
|
||||
# ############################################################################
|
||||
# Test --create-table-definitions
|
||||
# ############################################################################
|
||||
|
||||
# Without --create-table-definitions, the tables wouldn't be db-qualified.
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args,
|
||||
'--query', 'select city from city where city="New York"',
|
||||
'--create-table-definitions',
|
||||
"$trunk/t/lib/samples/mysqldump-no-data/all-dbs.txt") },
|
||||
"$out/create-table-defs-001.txt",
|
||||
),
|
||||
'--create-table-definitions'
|
||||
);
|
||||
|
||||
# #############################################################################
|
||||
# Done.
|
||||
# #############################################################################
|
||||
exit;
|
79
t/pt-table-usage/explain_extended.t
Normal file
79
t/pt-table-usage/explain_extended.t
Normal file
@@ -0,0 +1,79 @@
|
||||
#!/usr/bin/env perl
|
||||
|
||||
BEGIN {
|
||||
die "The PERCONA_TOOLKIT_BRANCH environment variable is not set.\n"
|
||||
unless $ENV{PERCONA_TOOLKIT_BRANCH} && -d $ENV{PERCONA_TOOLKIT_BRANCH};
|
||||
unshift @INC, "$ENV{PERCONA_TOOLKIT_BRANCH}/lib";
|
||||
};
|
||||
|
||||
use strict;
|
||||
use warnings FATAL => 'all';
|
||||
use English qw(-no_match_vars);
|
||||
use Test::More;
|
||||
|
||||
use PerconaTest;
|
||||
use Sandbox;
|
||||
require "$trunk/bin/pt-table-usage";
|
||||
|
||||
my $dp = new DSNParser(opts=>$dsn_opts);
|
||||
my $sb = new Sandbox(basedir => '/tmp', DSNParser => $dp);
|
||||
my $dbh = $sb->get_dbh_for('master');
|
||||
|
||||
if ( !$dbh ) {
|
||||
plan skip_all => 'Cannot connect to sandbox master';
|
||||
}
|
||||
else {
|
||||
plan tests => 3;
|
||||
}
|
||||
|
||||
my $output;
|
||||
my $cnf = '/tmp/12345/my.sandbox.cnf';
|
||||
my @args = ('--explain-extended', "F=$cnf");
|
||||
|
||||
my $in = "$trunk/t/pt-table-usage/samples/in";
|
||||
my $out = "t/pt-table-usage/samples/out";
|
||||
|
||||
$output = output(
|
||||
sub { pt_table_usage::main(@args, "$in/slow003.txt") },
|
||||
);
|
||||
|
||||
like(
|
||||
$output,
|
||||
qr/^ERROR NO_DB_SELECTED/m,
|
||||
"--explain-extended doesn't work without a database"
|
||||
);
|
||||
|
||||
ok(
|
||||
no_diff(
|
||||
sub { pt_table_usage::main(@args, qw(-D sakila), "$in/slow003.txt") },
|
||||
"$out/slow003-002.txt",
|
||||
),
|
||||
'EXPLAIN EXTENDED slow003.txt'
|
||||
);
|
||||
|
||||
$output = output(
|
||||
sub { pt_table_usage::main(@args, qw(-D sakila),
|
||||
'--query', 'select * from foo, bar where id=1') },
|
||||
stderr => 1,
|
||||
);
|
||||
is(
|
||||
$output,
|
||||
"",
|
||||
"No error if table doesn't exist"
|
||||
);
|
||||
|
||||
# This test fails in Maatkit, too. I guess I never finished writing it?
|
||||
#ok(
|
||||
# no_diff(
|
||||
# sub { pt_table_usage::main(@args,
|
||||
# '--query', "select count(*), max(lmp), min(lmp) FROM ca.interval_lmp_rt_5min as A INNER JOIN ca.lmp_rt_5min as B ON A.datetime = B.datetime WHERE A.datetime = '2011-12-01 21:05:00'") },
|
||||
# "t/pt-table-usage/samples/ee.out",
|
||||
# stderr => 1,
|
||||
# ),
|
||||
# "New EXPLAIN EXTENDED"
|
||||
#);
|
||||
|
||||
# #############################################################################
|
||||
# Done.
|
||||
# #############################################################################
|
||||
exit;
|
6
t/pt-table-usage/samples/ee.out
Normal file
6
t/pt-table-usage/samples/ee.out
Normal file
@@ -0,0 +1,6 @@
|
||||
Query_id: 0xDC115301537AEE70.1
|
||||
SELECT ca.lmp_rt_5min
|
||||
JOIN ca.interval_lmp_rt_5min
|
||||
JOIN ca.lmp_rt_5min
|
||||
WHERE ca.interval_lmp_rt_5min
|
||||
|
26
t/pt-table-usage/samples/ee.sql
Normal file
26
t/pt-table-usage/samples/ee.sql
Normal file
@@ -0,0 +1,26 @@
|
||||
drop database if exists ca;
|
||||
create database ca;
|
||||
use ca;
|
||||
CREATE TABLE `interval_lmp_rt_5min` (
|
||||
`datetime` datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
|
||||
`avg` float DEFAULT NULL,
|
||||
`median` float DEFAULT NULL,
|
||||
`reference` float DEFAULT NULL,
|
||||
`interpolated` tinyint(3) unsigned DEFAULT '0',
|
||||
`timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
PRIMARY KEY (`datetime`),
|
||||
KEY `interval_lmp_rt_5min_timestamp_idx` (`timestamp`)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
CREATE TABLE `lmp_rt_5min` (
|
||||
`datetime` datetime NOT NULL DEFAULT '0000-00-00 00:00:00',
|
||||
`handle_node_lmp` mediumint(8) unsigned NOT NULL DEFAULT '0',
|
||||
`lmp` float DEFAULT NULL,
|
||||
`congestion` float DEFAULT NULL,
|
||||
`loss` float DEFAULT NULL,
|
||||
`timestamp` timestamp NOT NULL DEFAULT CURRENT_TIMESTAMP,
|
||||
`interpolated` tinyint(1) DEFAULT NULL,
|
||||
PRIMARY KEY (`datetime`,`handle_node_lmp`),
|
||||
KEY `lmp_rt_5min_handle_node_lmp_idxfk` (`handle_node_lmp`),
|
||||
KEY `lmp_rt_5min_timestamp_idx` (`timestamp`)
|
||||
) ENGINE=InnoDB;
|
24
t/pt-table-usage/samples/in/slow001.txt
Normal file
24
t/pt-table-usage/samples/in/slow001.txt
Normal file
@@ -0,0 +1,24 @@
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 1
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
select * from t;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 2
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
select * from t1, t2 as x, t3 y, z;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 3
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
insert into t values (1, 2, 3);
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 4
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
delete from t where id < 1000;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 5
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
select * from a as t1, b as t2 where t1.id=t2.id;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 6
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
replace into t set foo='bar';
|
20
t/pt-table-usage/samples/in/slow002.txt
Normal file
20
t/pt-table-usage/samples/in/slow002.txt
Normal file
@@ -0,0 +1,20 @@
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 1
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
UPDATE t1 AS a JOIN t2 AS b USING (id) SET a.foo="bar" WHERE b.foo IS NOT NULL;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 2
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
UPDATE t1 AS a JOIN t2 AS b USING (id) SET a.foo="bar", b.foo="bat" WHERE a.id=1;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 3
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
UPDATE t1 INNER JOIN t2 USING (id) SET t1.foo="bar" WHERE t2.id=1;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 4
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
insert into t1 (a, b, c) select x, y, z from t2 where x is not null;
|
||||
# Time: 071218 11:48:27
|
||||
# Thread_id: 10 Query_id: 5
|
||||
# Query_time: 0.000012 Lock_time: 0.000000 Rows_sent: 0 Rows_examined: 0
|
||||
insert into t (a, b, c) select a.x, a.y, b.z from a, b where a.id=b.id;
|
3
t/pt-table-usage/samples/in/slow003.txt
Normal file
3
t/pt-table-usage/samples/in/slow003.txt
Normal file
@@ -0,0 +1,3 @@
|
||||
# Time: 110422 11:28:00
|
||||
# Query_time: 0.000300 Lock_time: 0.000000 Rows_sent: 1 Rows_examined: 1
|
||||
select country.country, city.city from city join country using (country_id) where country = 'Brazil' and city like 'A%' limit 1;
|
4
t/pt-table-usage/samples/out/create-table-defs-001.txt
Normal file
4
t/pt-table-usage/samples/out/create-table-defs-001.txt
Normal file
@@ -0,0 +1,4 @@
|
||||
Query_id: 0x1E0BF7001F0D58BB.1
|
||||
SELECT sakila.city
|
||||
WHERE sakila.city
|
||||
|
5
t/pt-table-usage/samples/out/create001.txt
Normal file
5
t/pt-table-usage/samples/out/create001.txt
Normal file
@@ -0,0 +1,5 @@
|
||||
Query_id: 0x9840C99F532C2E3F.1
|
||||
CREATE temp.5
|
||||
SELECT t
|
||||
WHERE t
|
||||
|
3
t/pt-table-usage/samples/out/drop-table-if-exists.txt
Normal file
3
t/pt-table-usage/samples/out/drop-table-if-exists.txt
Normal file
@@ -0,0 +1,3 @@
|
||||
Query_id: 0xAED187CD505CBD92.1
|
||||
DROP_TABLE t
|
||||
|
6
t/pt-table-usage/samples/out/query001.txt
Normal file
6
t/pt-table-usage/samples/out/query001.txt
Normal file
@@ -0,0 +1,6 @@
|
||||
Query_id: 0xF318E3D2483D370E.1
|
||||
SELECT temp.temp6
|
||||
JOIN temp.temp6
|
||||
JOIN n.type
|
||||
WHERE n.type
|
||||
|
5
t/pt-table-usage/samples/out/query002.txt
Normal file
5
t/pt-table-usage/samples/out/query002.txt
Normal file
@@ -0,0 +1,5 @@
|
||||
Query_id: 0xF573BD7AD8CDDD7D.1
|
||||
JOIN d1.t1
|
||||
JOIN d2.t2
|
||||
JOIN d3.t3
|
||||
|
31
t/pt-table-usage/samples/out/slow001.txt
Normal file
31
t/pt-table-usage/samples/out/slow001.txt
Normal file
@@ -0,0 +1,31 @@
|
||||
Query_id: 0xF28708D8F2920792.1
|
||||
SELECT t
|
||||
|
||||
Query_id: 0x09CB59D3450EF6E8.1
|
||||
SELECT t1
|
||||
SELECT t2
|
||||
SELECT t3
|
||||
SELECT z
|
||||
TLIST t1
|
||||
TLIST t2
|
||||
TLIST t3
|
||||
TLIST z
|
||||
|
||||
Query_id: 0xCF687AF9F2D5E248.1
|
||||
INSERT t
|
||||
SELECT DUAL
|
||||
|
||||
Query_id: 0xF1FBC364588DC469.1
|
||||
DELETE t
|
||||
WHERE t
|
||||
|
||||
Query_id: 0x8745D03011B0E1CE.1
|
||||
SELECT a
|
||||
SELECT b
|
||||
JOIN a
|
||||
JOIN b
|
||||
|
||||
Query_id: 0xEB871CD2B5729EA1.1
|
||||
REPLACE t
|
||||
SELECT DUAL
|
||||
|
40
t/pt-table-usage/samples/out/slow002.txt
Normal file
40
t/pt-table-usage/samples/out/slow002.txt
Normal file
@@ -0,0 +1,40 @@
|
||||
Query_id: 0x6B1671EA6890F103.1
|
||||
UPDATE t1
|
||||
SELECT DUAL
|
||||
JOIN t1
|
||||
JOIN t2
|
||||
WHERE t2
|
||||
|
||||
Query_id: 0x1CD27577D202A339.1
|
||||
UPDATE t1
|
||||
SELECT DUAL
|
||||
JOIN t1
|
||||
JOIN t2
|
||||
WHERE t1
|
||||
|
||||
Query_id: 0x1CD27577D202A339.2
|
||||
UPDATE t2
|
||||
SELECT DUAL
|
||||
JOIN t1
|
||||
JOIN t2
|
||||
WHERE t1
|
||||
|
||||
Query_id: 0xF4BEDD52BF14F91B.1
|
||||
UPDATE t1
|
||||
SELECT DUAL
|
||||
JOIN t1
|
||||
JOIN t2
|
||||
WHERE t2
|
||||
|
||||
Query_id: 0x1E62B5AB0DD828BF.1
|
||||
INSERT t1
|
||||
SELECT t2
|
||||
WHERE t2
|
||||
|
||||
Query_id: 0xE25F88EDB02EA4A3.1
|
||||
INSERT t
|
||||
SELECT a
|
||||
SELECT b
|
||||
JOIN a
|
||||
JOIN b
|
||||
|
6
t/pt-table-usage/samples/out/slow003-001.txt
Normal file
6
t/pt-table-usage/samples/out/slow003-001.txt
Normal file
@@ -0,0 +1,6 @@
|
||||
Query_id: 0x7C6C08E1FA6D7E73.1
|
||||
SELECT country
|
||||
SELECT city
|
||||
JOIN city
|
||||
JOIN country
|
||||
|
8
t/pt-table-usage/samples/out/slow003-002.txt
Normal file
8
t/pt-table-usage/samples/out/slow003-002.txt
Normal file
@@ -0,0 +1,8 @@
|
||||
Query_id: 0x7C6C08E1FA6D7E73.1
|
||||
SELECT sakila.country
|
||||
SELECT sakila.city
|
||||
JOIN sakila.city
|
||||
JOIN sakila.country
|
||||
WHERE sakila.city
|
||||
WHERE sakila.country
|
||||
|
6
t/pt-table-usage/samples/out/slow003-003.txt
Normal file
6
t/pt-table-usage/samples/out/slow003-003.txt
Normal file
@@ -0,0 +1,6 @@
|
||||
Query_id: 110422 11:28:00.1
|
||||
SELECT country
|
||||
SELECT city
|
||||
JOIN city
|
||||
JOIN country
|
||||
|
Reference in New Issue
Block a user