Skip to content

Commit f71b0b3

Browse files
author
Steinar H. Gunderson
committed
WL #12788: Iterator executor analytics queries [7/7, duplicate removal]
Implement final duplicate removal by means of filesort. Normally, deduplication (SELECT DISTINCT) happens by adding a unique index to the final temporary table. However, in the cases where we do aggregation directly into a temporary table, we cannot use such an index, since rows change during query execution and thus cannot be deduplicated on-the-fly. (E.g., consider SELECT DISTINCT COUNT(*) FROM t1 GROUP BY f1.) The old executor solves this by adding a post-pass that actually deletes rows from the temporary table; for small tables, it uses a hash table to deduplicate, but for larger ones, it uses an O(n^2) algorithm based on pairwise comparison, which is extremely slow. Neither fits very well in an iterator design, and thus, we replace this step by filesort, which is consistently O(n log n) with a small constant factor. Filesort needs to be extended with support for deduplicating rows, which is done as part of this work. Note that this removes a determinism-by-accident that was in filesort earlier (if the algorithm decided to sort by row ID, the row ID would be part of the key). This also requires new functionality in the test framework, so that we can test for partially ordered results (--partial_sorted_result). Change-Id: I985f6d1f30630d6e8e20767c67ba8b4382144df6
1 parent 1df7dea commit f71b0b3

39 files changed

+628
-302
lines changed

client/mysqltest.cc

+60-14
Original file line numberDiff line numberDiff line change
@@ -37,7 +37,6 @@
3737
#include <algorithm>
3838
#include <chrono>
3939
#include <cmath> // std::isinf
40-
#include <functional>
4140
#include <limits>
4241
#include <new>
4342
#include <regex>
@@ -211,6 +210,7 @@ static bool testcase_disabled = 0;
211210
static bool display_result_vertically = false, display_result_lower = false,
212211
display_metadata = false, display_result_sorted = false,
213212
display_session_track_info = false;
213+
static int start_sort_column = 0;
214214
static bool disable_query_log = 0, disable_result_log = 0;
215215
static bool disable_connect_log = 1;
216216
static bool disable_warnings = 0;
@@ -572,6 +572,7 @@ enum enum_commands {
572572
Q_QUERY_VERTICAL,
573573
Q_QUERY_HORIZONTAL,
574574
Q_SORTED_RESULT,
575+
Q_PARTIALLY_SORTED_RESULT,
575576
Q_LOWERCASE,
576577
Q_START_TIMER,
577578
Q_END_TIMER,
@@ -638,11 +639,11 @@ const char *command_names[] = {
638639
"disable_async_client", "exec", "execw", "exec_in_background", "delimiter",
639640
"disable_abort_on_error", "enable_abort_on_error", "vertical_results",
640641
"horizontal_results", "query_vertical", "query_horizontal", "sorted_result",
641-
"lowercase_result", "start_timer", "end_timer", "character_set",
642-
"disable_ps_protocol", "enable_ps_protocol", "disable_reconnect",
643-
"enable_reconnect", "if", "disable_testcase", "enable_testcase",
644-
"replace_regex", "replace_numeric_round", "remove_file", "file_exists",
645-
"write_file", "copy_file", "perl", "die",
642+
"partially_sorted_result", "lowercase_result", "start_timer", "end_timer",
643+
"character_set", "disable_ps_protocol", "enable_ps_protocol",
644+
"disable_reconnect", "enable_reconnect", "if", "disable_testcase",
645+
"enable_testcase", "replace_regex", "replace_numeric_round", "remove_file",
646+
"file_exists", "write_file", "copy_file", "perl", "die",
646647

647648
/* Don't execute any more commands, compare result */
648649
"exit", "skip", "chmod", "append_file", "cat_file", "diff_files",
@@ -1110,7 +1111,8 @@ static void mysql_free_result_wrapper(MYSQL_RES *result) {
11101111
void replace_dynstr_append_mem(DYNAMIC_STRING *ds, const char *val, size_t len);
11111112
void replace_dynstr_append(DYNAMIC_STRING *ds, const char *val);
11121113
void replace_dynstr_append_uint(DYNAMIC_STRING *ds, uint val);
1113-
void dynstr_append_sorted(DYNAMIC_STRING *ds, DYNAMIC_STRING *ds_input);
1114+
void dynstr_append_sorted(DYNAMIC_STRING *ds, DYNAMIC_STRING *ds_input,
1115+
int start_sort_column);
11141116

11151117
void revert_properties();
11161118

@@ -2653,7 +2655,7 @@ static void var_query_set(VAR *var, const char *query, const char **query_end) {
26532655
Call the replace_numeric_round function with the specified
26542656
precision. It may be used along with replace_result, so use the
26552657
output from replace_result as the input for replace_numeric_round.
2656-
*/
2658+
*/
26572659
if (glob_replace_numeric_round >= 0) {
26582660
/* Copy the result from replace_result if it was used, into buffer */
26592661
if (ds_temp.length > 0) {
@@ -8881,7 +8883,7 @@ static void run_query(struct st_connection *cn, struct st_command *command,
88818883

88828884
if (display_result_sorted) {
88838885
/* Sort the result set and append it to result */
8884-
dynstr_append_sorted(save_ds, &ds_sorted);
8886+
dynstr_append_sorted(save_ds, &ds_sorted, start_sort_column);
88858887
ds = save_ds;
88868888
dynstr_free(&ds_sorted);
88878889
}
@@ -9714,6 +9716,16 @@ int main(int argc, char **argv) {
97149716
command
97159717
*/
97169718
display_result_sorted = true;
9719+
start_sort_column = 0;
9720+
break;
9721+
case Q_PARTIALLY_SORTED_RESULT:
9722+
/*
9723+
Turn on sorting of result set, will be reset after next
9724+
command
9725+
*/
9726+
display_result_sorted = true;
9727+
start_sort_column = atoi(command->first_argument);
9728+
command->last_argument = command->end;
97179729
break;
97189730
case Q_LOWERCASE:
97199731
/*
@@ -11315,18 +11327,33 @@ void replace_dynstr_append_uint(DYNAMIC_STRING *ds, uint val) {
1131511327
dynstr_append_sorted
1131611328
ds - string where the sorted output will be appended
1131711329
ds_input - string to be sorted
11318-
11330+
start_sort_column - column to start sorting from (0 for sorting
11331+
the entire line); a stable sort will be used
1131911332
*/
1132011333

11321-
class Comp_lines
11322-
: public std::binary_function<const char *, const char *, bool> {
11334+
class Comp_lines {
1132311335
public:
1132411336
bool operator()(const char *a, const char *b) {
1132511337
return std::strcmp(a, b) < 0;
1132611338
}
1132711339
};
1132811340

11329-
void dynstr_append_sorted(DYNAMIC_STRING *ds, DYNAMIC_STRING *ds_input) {
11341+
static size_t length_of_n_first_columns(const char *str,
11342+
int start_sort_column) {
11343+
const char *ptr = str;
11344+
for (int i = 0; i < start_sort_column; ++i) {
11345+
const char *first_tab = strchr(ptr, '\t');
11346+
if (first_tab == nullptr) {
11347+
return strlen(str);
11348+
} else {
11349+
ptr = first_tab + 1;
11350+
}
11351+
}
11352+
return ptr - str;
11353+
}
11354+
11355+
void dynstr_append_sorted(DYNAMIC_STRING *ds, DYNAMIC_STRING *ds_input,
11356+
int start_sort_column) {
1133011357
char *start = ds_input->str;
1133111358
Prealloced_array<const char *, 32> lines(PSI_NOT_INSTRUMENTED);
1133211359
DBUG_ENTER("dynstr_append_sorted");
@@ -11339,21 +11366,40 @@ void dynstr_append_sorted(DYNAMIC_STRING *ds, DYNAMIC_STRING *ds_input) {
1133911366
dynstr_append_mem(ds, ds_input->str, start - ds_input->str);
1134011367

1134111368
/* Insert line(s) in array */
11369+
size_t first_unsorted_row = 0;
1134211370
while (*start) {
1134311371
char *line_end = (char *)start;
1134411372

1134511373
/* Find end of line */
1134611374
while (*line_end && *line_end != '\n') line_end++;
1134711375
*line_end = 0;
1134811376

11377+
if (!lines.empty() && start_sort_column > 0) {
11378+
/*
11379+
If doing partial sorting, and the prefix is different from that of the
11380+
previous line, the group is done. Sort it and start another one.
11381+
*/
11382+
size_t prev_line_prefix_len =
11383+
length_of_n_first_columns(lines.back(), start_sort_column);
11384+
size_t this_line_prefix_len =
11385+
length_of_n_first_columns(start, start_sort_column);
11386+
if (this_line_prefix_len != prev_line_prefix_len ||
11387+
memcmp(lines.back(), start, prev_line_prefix_len) != 0) {
11388+
std::sort(lines.begin() + first_unsorted_row, lines.end(),
11389+
Comp_lines());
11390+
first_unsorted_row = lines.size();
11391+
}
11392+
}
11393+
1134911394
/* Insert pointer to the line in array */
1135011395
if (lines.push_back(start)) die("Out of memory inserting lines to sort");
1135111396

1135211397
start = line_end + 1;
1135311398
}
1135411399

1135511400
/* Sort array */
11356-
std::sort(lines.begin(), lines.end(), Comp_lines());
11401+
std::stable_sort(lines.begin() + first_unsorted_row, lines.end(),
11402+
Comp_lines());
1135711403

1135811404
/* Create new result */
1135911405
for (const char **line = lines.begin(); line != lines.end(); ++line) {

mysql-test/include/bug13581713.inc

+4
Original file line numberDiff line numberDiff line change
@@ -4,8 +4,10 @@ insert into t1 values(100,1,2),(200,1,1),(300,2,1),(400,2,2);
44
analyze table t1;
55

66
eval select distinct b from $source order by c;
7+
--sorted_result
78
eval select distinct min(b) from $source group by a order by min(c);
89
# just to see that if source is a view, it is merged
10+
--sorted_result
911
--replace_column 9 #
1012
eval explain select distinct min(b) from $source group by a order by min(c);
1113

@@ -23,6 +25,7 @@ analyze table t1;
2325
eval select distinct b from $source order by c;
2426

2527
--echo Random order too (same reason):
28+
--sorted_result
2629
eval select distinct min(b) from $source group by a order by min(c);
2730

2831
--source include/restore_sql_mode_after_turn_off_only_full_group_by.inc
@@ -35,6 +38,7 @@ eval select distinct b from $source order by c;
3538
eval select distinct b from $source order by b-1,b+1,c;
3639

3740
--echo and this one too:
41+
--sorted_result
3842
--error ER_AGGREGATE_IN_ORDER_NOT_SELECT
3943
eval select distinct min(b) from $source group by a order by min(c);
4044

mysql-test/include/varchar.inc

+4-4
Original file line numberDiff line numberDiff line change
@@ -92,7 +92,7 @@ explain select * from t1 where v='a';
9292
#
9393
# GROUP BY
9494
# Note that we have a number of keys here that are equivalent under
95-
# PAD collations, e.g. "a" equals "a ", and there's no knowing which one
95+
# NO PAD collations, e.g. "a" equals "a ", and there's no knowing which one
9696
# we get when we just say GROUP BY <field>. Thus, we add TRIM() around it
9797
# to get a deterministic result.
9898
#
@@ -105,9 +105,9 @@ select sql_big_result TRIM(v),count(c) from t1 group by TRIM(v) order by TRIM(v)
105105
select c,count(*) from t1 group by c order by c limit 10;
106106
select c,count(t) from t1 group by c order by c limit 10;
107107
select sql_big_result c,count(t) from t1 group by c limit 10;
108-
select t,count(*) from t1 group by t order by t limit 10;
109-
select t,count(t) from t1 group by t order by t limit 10;
110-
select sql_big_result t,count(t) from t1 group by t order by t limit 10;
108+
select TRIM(t),count(*) from t1 group by TRIM(t) order by TRIM(t) limit 10;
109+
select TRIM(t),count(t) from t1 group by TRIM(t) order by TRIM(t) limit 10;
110+
select sql_big_result TRIM(t),count(t) from t1 group by TRIM(t) order by TRIM(t) limit 10;
111111

112112
#
113113
# Test varchar > 255 bytes

mysql-test/mysql-test-run.dox

+15
Original file line numberDiff line numberDiff line change
@@ -7610,6 +7610,21 @@
76107610
server bugs that result in true problems with result order.
76117611
</li>
76127612

7613+
<li>
7614+
<tt>partially_sorted_result <b>start_column</b></tt>
7615+
7616+
Similarly to <b>sorted_result</b>, but assumes that the first
7617+
<b>start_column</b> columns are already sorted, sorting only
7618+
on the remaining ones. This is useful if you wish to verify
7619+
a partial ordering property, e.g. that <b>SELECT a,b,c ORDER BY
7620+
a</b>. In this case, you could use <b>partially_sorted_result 1</b>
7621+
to sort only on b and c, giving deterministic results without
7622+
masking bugs where sorting on a column would not work correctly.
7623+
7624+
<tt>sorted_result</tt> is functionally equal to
7625+
<tt>partially_sorted_result 0</tt>.
7626+
</li>
7627+
76137628
<li>
76147629
<tt>source <b>file_name</b></tt>
76157630

mysql-test/r/compress.result

+10-10
Original file line numberDiff line numberDiff line change
@@ -596,16 +596,16 @@ companynr fld3 count(*)
596596
SET BIG_TABLES=0;
597597
select distinct fld3,repeat("a",length(fld3)),count(*) from t2 group by companynr,fld3 limit 100,10;
598598
fld3 repeat("a",length(fld3)) count(*)
599-
bivalves aaaaaaaa 1
600-
incurring aaaaaaaaa 1
601-
Adolph aaaaaa 1
602-
pithed aaaaaa 1
603-
emergency aaaaaaaaa 1
604-
Miles aaaaa 1
605-
trimmings aaaaaaaaa 1
606-
tragedies aaaaaaaaa 1
607-
skulking aaaaaaaa 1
608-
flint aaaaa 1
599+
babysitting aaaaaaaaaaa 1
600+
Baird aaaaa 1
601+
balled aaaaaa 1
602+
ballgown aaaaaaaa 1
603+
Baltimorean aaaaaaaaaaa 1
604+
bankruptcies aaaaaaaaaaaa 1
605+
Barry aaaaa 1
606+
batting aaaaaaa 1
607+
beaner aaaaaa 1
608+
beasts aaaaaa 1
609609
select distinct companynr,rtrim(space(512+companynr)) from t3 order by 1,2;
610610
companynr rtrim(space(512+companynr))
611611
37

mysql-test/r/distinct.result

+47-9
Original file line numberDiff line numberDiff line change
@@ -929,6 +929,14 @@ c1 c2 COUNT(*)
929929
2 2 1
930930
3 1 2
931931
4 4 1
932+
EXPLAIN FORMAT=tree SELECT DISTINCT c2 FROM t1 GROUP BY c1 HAVING COUNT(*) > 1;
933+
EXPLAIN
934+
-> Sort with duplicate removal: <temporary>.c2
935+
-> Filter: (count(0) > 1)
936+
-> Table scan on <temporary>
937+
-> Aggregate using temporary table
938+
-> Table scan on t1
939+
932940
SELECT DISTINCT c2 FROM t1 GROUP BY c1 HAVING COUNT(*) > 1;
933941
c2
934942
1
@@ -1096,13 +1104,13 @@ b
10961104
1
10971105
select distinct min(b) from t1 group by a order by min(c);
10981106
min(b)
1099-
2
11001107
1
1108+
2
11011109
explain select distinct min(b) from t1 group by a order by min(c);
11021110
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
11031111
1 SIMPLE t1 NULL ALL NULL NULL NULL # 4 100.00 Using temporary; Using filesort
1104-
Warnings:
11051112
Note 1003 /* select#1 */ select distinct min(`test`.`t1`.`b`) AS `min(b)` from `test`.`t1` group by `test`.`t1`.`a` order by min(`test`.`t1`.`c`)
1113+
Warnings:
11061114
Insert rows in different order:
11071115
delete from t1;
11081116
insert into t1 values(200,1,1),(100,1,2),(400,2,2),(300,2,1);
@@ -1324,14 +1332,14 @@ b
13241332
1
13251333
select distinct min(b) from v1 group by a order by min(c);
13261334
min(b)
1327-
2
13281335
1
1336+
2
13291337
explain select distinct min(b) from v1 group by a order by min(c);
13301338
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
13311339
1 SIMPLE t1 NULL ALL NULL NULL NULL # 4 100.00 Using temporary; Using filesort
13321340
1 SIMPLE t2 NULL ALL NULL NULL NULL # 1 100.00 Using where; Using join buffer (Block Nested Loop)
1333-
Warnings:
13341341
Note 1003 /* select#1 */ select distinct min(`test`.`t1`.`b`) AS `min(b)` from `test`.`t1` left join `test`.`t2` on(true) where true group by `test`.`t1`.`a` order by min(`test`.`t1`.`c`)
1342+
Warnings:
13351343
Insert rows in different order:
13361344
delete from t1;
13371345
insert into t1 values(200,1,1),(100,1,2),(400,2,2),(300,2,1);
@@ -1554,13 +1562,13 @@ b
15541562
2
15551563
select distinct min(b) from v1 group by a order by min(c);
15561564
min(b)
1557-
4
15581565
2
1566+
4
15591567
explain select distinct min(b) from v1 group by a order by min(c);
15601568
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
15611569
1 SIMPLE t1 NULL ALL NULL NULL NULL # 4 100.00 Using temporary; Using filesort
1562-
Warnings:
15631570
Note 1003 /* select#1 */ select distinct min((`test`.`t1`.`b` * 2)) AS `min(b)` from `test`.`t1` group by (`test`.`t1`.`a` * 2) order by min((`test`.`t1`.`c` * 2))
1571+
Warnings:
15641572
Insert rows in different order:
15651573
delete from t1;
15661574
insert into t1 values(200,1,1),(100,1,2),(400,2,2),(300,2,1);
@@ -1782,14 +1790,14 @@ b
17821790
1
17831791
select distinct min(b) from (SELECT t1.* FROM t1 left join t2 on 1) AS derived group by a order by min(c);
17841792
min(b)
1785-
2
17861793
1
1794+
2
17871795
explain select distinct min(b) from (SELECT t1.* FROM t1 left join t2 on 1) AS derived group by a order by min(c);
17881796
id select_type table partitions type possible_keys key key_len ref rows filtered Extra
17891797
1 SIMPLE t1 NULL ALL NULL NULL NULL # 4 100.00 Using temporary; Using filesort
17901798
1 SIMPLE t2 NULL ALL NULL NULL NULL # 1 100.00 Using where; Using join buffer (Block Nested Loop)
1791-
Warnings:
17921799
Note 1003 /* select#1 */ select distinct min(`test`.`t1`.`b`) AS `min(b)` from `test`.`t1` left join `test`.`t2` on(true) where true group by `test`.`t1`.`a` order by min(`test`.`t1`.`c`)
1800+
Warnings:
17931801
Insert rows in different order:
17941802
delete from t1;
17951803
insert into t1 values(200,1,1),(100,1,2),(400,2,2),(300,2,1);
@@ -2106,7 +2114,37 @@ pk
21062114
12
21072115
EXPLAIN FORMAT=tree SELECT /*+JOIN_ORDER(t2,t3,t1) */ DISTINCT t2.pk FROM t1 LEFT JOIN t2 RIGHT OUTER JOIN t3 ON t2.f1 = t3.f3 ON t1.pk = t3.f2 WHERE t3.pk <> t2.pk;
21082116
EXPLAIN
2109-
<not executable by iterator executor>
2117+
-> Limit: 1 row(s)
2118+
-> Table scan on <temporary>
2119+
-> Temporary table
2120+
-> Filter: ((t3.f2 = '3') and (t3.f3 = '4') and (t3.pk <> '12'))
2121+
-> Table scan on t3
21102122

21112123
DROP TABLE t1, t2, t3;
21122124
SET optimizer_switch=@old_optimizer_switch;
2125+
#
2126+
# Test that DISTINCT-by-filesort manages to deduplicate across sort chunks.
2127+
#
2128+
SET @old_sort_buffer_size = @@sort_buffer_size;
2129+
SET @@sort_buffer_size = 32768;
2130+
CREATE TABLE t1 ( f FLOAT );
2131+
INSERT INTO t1 VALUES (0.0);
2132+
INSERT INTO t1 SELECT RAND() FROM t1 AS t1, t1 AS t2;
2133+
INSERT INTO t1 SELECT RAND() FROM t1 AS t1, t1 AS t2;
2134+
INSERT INTO t1 SELECT RAND() FROM t1 AS t1, t1 AS t2;
2135+
INSERT INTO t1 SELECT RAND() FROM t1 AS t1, t1 AS t2;
2136+
INSERT INTO t1 SELECT RAND() FROM t1;
2137+
INSERT INTO t1 SELECT RAND() FROM t1;
2138+
EXPLAIN FORMAT=tree SELECT DISTINCT COUNT(*) AS num FROM t1 GROUP BY f HAVING num=1;
2139+
EXPLAIN
2140+
-> Sort with duplicate removal: <temporary>.num
2141+
-> Filter: (num = 1)
2142+
-> Table scan on <temporary>
2143+
-> Aggregate using temporary table
2144+
-> Table scan on t1
2145+
2146+
SELECT DISTINCT COUNT(*) AS num FROM t1 GROUP BY f HAVING num=1;
2147+
num
2148+
1
2149+
DROP TABLE t1;
2150+
SET @@sort_buffer_size = @old_sort_buffer_size;

mysql-test/r/explain_json_all.result

+1-1
Original file line numberDiff line numberDiff line change
@@ -2584,7 +2584,7 @@ s
25842584
SHOW SESSION STATUS WHERE (Variable_name LIKE 'Sort_%' OR Variable_name LIKE 'Created_%_tables') AND Value > 0;
25852585
Variable_name Value
25862586
Created_tmp_tables 1
2587-
Sort_rows 2
2587+
Sort_rows 3
25882588
Sort_scan 1
25892589
DROP TABLE t1;
25902590
# "buffer_result" node

0 commit comments

Comments
 (0)