Skip to content

Commit

Permalink
MDEV-15178: Filesort::make_sortorder: Assertion `pos->field != __null |
Browse files Browse the repository at this point in the history
(Initial patch by Varun Gupta. Amended and added comments).

When the query has both
1. Aggregate functions that require sorting data by group, and
2. Window functions

we need to use two temporary tables. The first temp.table will hold the
join output.  Then it is passed to filesort(). Reading it in sorted
order allows to compute the aggregate functions.

Then, we need to write their values into the second temp. table. Then,
Window Function computation step can pass that to filesort() and read
them in the order it needs.

Failure to create the second temp. table would cause an assertion
failure: window function could would not find where to get the values
of the aggregate functions.
  • Loading branch information
spetrunia committed Jan 23, 2023
1 parent 00150ff commit f18c2b6
Show file tree
Hide file tree
Showing 6 changed files with 188 additions and 19 deletions.
46 changes: 44 additions & 2 deletions mysql-test/main/win.result
Expand Up @@ -4272,11 +4272,13 @@ GROUP BY
LEFT((SYSDATE()), 'foo')
WITH ROLLUP;
SUM(b) OVER (PARTITION BY a) ROW_NUMBER() OVER (PARTITION BY b)
NULL 1
NULL 1
0 1
0 2
Warnings:
Warning 1292 Truncated incorrect INTEGER value: 'foo'
Warning 1292 Truncated incorrect INTEGER value: 'foo'
Warning 1292 Truncated incorrect DOUBLE value: 'bar'
Warning 1292 Truncated incorrect DOUBLE value: 'bar'
drop table t1;
#
#
Expand Down Expand Up @@ -4335,5 +4337,45 @@ pk a bit_or
DROP TABLE t2;
DROP TABLE t1;
#
# MDEV-15178: Filesort::make_sortorder: Assertion `pos->field != __null |
#
CREATE TABLE t1 (i1 int, a int);
INSERT INTO t1 VALUES (1, 1), (2, 2),(3, 3);
CREATE TABLE t2 (i2 int);
INSERT INTO t2 VALUES (1),(2),(5),(1),(7),(4),(3);
SELECT
a,
RANK() OVER (ORDER BY SUM(DISTINCT i1))
FROM
t1, t2 WHERE t2.i2 = t1.i1
GROUP BY
a;
a RANK() OVER (ORDER BY SUM(DISTINCT i1))
1 1
2 2
3 3
DROP TABLE t1, t2;
#
# MDEV-17014: Crash server using ROW_NUMBER() OVER (PARTITION ..)
#
CREATE TABLE t1 (UID BIGINT);
CREATE TABLE t2 (UID BIGINT);
CREATE TABLE t3 (UID BIGINT);
insert into t1 VALUES (1),(2);
insert into t2 VALUES (1),(2);
insert into t3 VALUES (1),(2);
SELECT
ROW_NUMBER() OVER (PARTITION BY GROUP_CONCAT(TT1.UID))
FROM t1 TT1,
t2 TT2,
t3 TT3
WHERE TT3.UID = TT1.UID AND TT2.UID = TT3.UID
GROUP BY TT1.UID
;
ROW_NUMBER() OVER (PARTITION BY GROUP_CONCAT(TT1.UID))
1
1
DROP TABLE t1, t2, t3;
#
# End of 10.3 tests
#
40 changes: 40 additions & 0 deletions mysql-test/main/win.test
Expand Up @@ -2816,6 +2816,46 @@ DROP TABLE t2;

DROP TABLE t1;

--echo #
--echo # MDEV-15178: Filesort::make_sortorder: Assertion `pos->field != __null |
--echo #

CREATE TABLE t1 (i1 int, a int);
INSERT INTO t1 VALUES (1, 1), (2, 2),(3, 3);

CREATE TABLE t2 (i2 int);
INSERT INTO t2 VALUES (1),(2),(5),(1),(7),(4),(3);

SELECT
a,
RANK() OVER (ORDER BY SUM(DISTINCT i1))
FROM
t1, t2 WHERE t2.i2 = t1.i1
GROUP BY
a;

DROP TABLE t1, t2;

--echo #
--echo # MDEV-17014: Crash server using ROW_NUMBER() OVER (PARTITION ..)
--echo #
CREATE TABLE t1 (UID BIGINT);
CREATE TABLE t2 (UID BIGINT);
CREATE TABLE t3 (UID BIGINT);

insert into t1 VALUES (1),(2);
insert into t2 VALUES (1),(2);
insert into t3 VALUES (1),(2);
SELECT
ROW_NUMBER() OVER (PARTITION BY GROUP_CONCAT(TT1.UID))
FROM t1 TT1,
t2 TT2,
t3 TT3
WHERE TT3.UID = TT1.UID AND TT2.UID = TT3.UID
GROUP BY TT1.UID
;

DROP TABLE t1, t2, t3;

--echo #
--echo # End of 10.3 tests
Expand Down
46 changes: 44 additions & 2 deletions mysql-test/suite/encryption/r/tempfiles_encrypted.result
Expand Up @@ -4278,11 +4278,13 @@ GROUP BY
LEFT((SYSDATE()), 'foo')
WITH ROLLUP;
SUM(b) OVER (PARTITION BY a) ROW_NUMBER() OVER (PARTITION BY b)
NULL 1
NULL 1
0 1
0 2
Warnings:
Warning 1292 Truncated incorrect INTEGER value: 'foo'
Warning 1292 Truncated incorrect INTEGER value: 'foo'
Warning 1292 Truncated incorrect DOUBLE value: 'bar'
Warning 1292 Truncated incorrect DOUBLE value: 'bar'
drop table t1;
#
#
Expand Down Expand Up @@ -4341,6 +4343,46 @@ pk a bit_or
DROP TABLE t2;
DROP TABLE t1;
#
# MDEV-15178: Filesort::make_sortorder: Assertion `pos->field != __null |
#
CREATE TABLE t1 (i1 int, a int);
INSERT INTO t1 VALUES (1, 1), (2, 2),(3, 3);
CREATE TABLE t2 (i2 int);
INSERT INTO t2 VALUES (1),(2),(5),(1),(7),(4),(3);
SELECT
a,
RANK() OVER (ORDER BY SUM(DISTINCT i1))
FROM
t1, t2 WHERE t2.i2 = t1.i1
GROUP BY
a;
a RANK() OVER (ORDER BY SUM(DISTINCT i1))
1 1
2 2
3 3
DROP TABLE t1, t2;
#
# MDEV-17014: Crash server using ROW_NUMBER() OVER (PARTITION ..)
#
CREATE TABLE t1 (UID BIGINT);
CREATE TABLE t2 (UID BIGINT);
CREATE TABLE t3 (UID BIGINT);
insert into t1 VALUES (1),(2);
insert into t2 VALUES (1),(2);
insert into t3 VALUES (1),(2);
SELECT
ROW_NUMBER() OVER (PARTITION BY GROUP_CONCAT(TT1.UID))
FROM t1 TT1,
t2 TT2,
t3 TT3
WHERE TT3.UID = TT1.UID AND TT2.UID = TT3.UID
GROUP BY TT1.UID
;
ROW_NUMBER() OVER (PARTITION BY GROUP_CONCAT(TT1.UID))
1
1
DROP TABLE t1, t2, t3;
#
# End of 10.3 tests
#
#
Expand Down
9 changes: 8 additions & 1 deletion sql/item_sum.h
Expand Up @@ -366,7 +366,14 @@ class Item_sum :public Item_func_or_sum
int8 aggr_level; /* nesting level of the aggregating subquery */
int8 max_arg_level; /* max level of unbound column references */
int8 max_sum_func_level;/* max level of aggregation for embedded functions */
bool quick_group; /* If incremental update of fields */

/*
true (the default value) means this aggregate function can be computed
with TemporaryTableWithPartialSums algorithm (see end_update()).
false means this aggregate function needs OrderedGroupBy algorithm (see
end_write_group()).
*/
bool quick_group;
/*
This list is used by the check for mixing non aggregated fields and
sum functions in the ONLY_FULL_GROUP_BY_MODE. We save all outer fields
Expand Down
6 changes: 6 additions & 0 deletions sql/sql_class.h
Expand Up @@ -5580,6 +5580,12 @@ class TMP_TABLE_PARAM :public Sql_alloc
uint sum_func_count;
uint hidden_field_count;
uint group_parts,group_length,group_null_parts;

/*
If we're doing a GROUP BY operation, shows which one is used:
true TemporaryTableWithPartialSums algorithm (see end_update()).
false OrderedGroupBy algorithm (see end_write_group()).
*/
uint quick_group;
/**
Enabled when we have atleast one outer_sum_func. Needed when used
Expand Down
60 changes: 46 additions & 14 deletions sql/sql_select.cc
Expand Up @@ -3168,15 +3168,26 @@ bool JOIN::make_aggr_tables_info()

/*
If we have different sort & group then we must sort the data by group
and copy it to another tmp table
and copy it to another tmp table.

This code is also used if we are using distinct something
we haven't been able to store in the temporary table yet
like SEC_TO_TIME(SUM(...)).

3. Also, this is used when
- the query has Window functions,
- the GROUP BY operation is done with OrderedGroupBy algorithm.
In this case, the first temptable will contain pre-GROUP-BY data. Force
the creation of the second temporary table. Post-GROUP-BY dataset will be
written there, and then Window Function processing code will be able to
process it.
*/
if ((group_list &&
(!test_if_subpart(group_list, order) || select_distinct)) ||
(select_distinct && tmp_table_param.using_outer_summary_function))
{ /* Must copy to another table */
(select_distinct && tmp_table_param.using_outer_summary_function) ||
(group_list && !tmp_table_param.quick_group && // (3)
select_lex->have_window_funcs())) // (3)
{ /* Must copy to another table */
DBUG_PRINT("info",("Creating group table"));

calc_group_buffer(this, group_list);
Expand Down Expand Up @@ -21207,11 +21218,17 @@ end_send(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)),

/*
@brief
Perform a GROUP BY operation over a stream of rows ordered by their group. The
result is sent into join->result.
Perform OrderedGroupBy operation and write the output into join->result.

@detail
Also applies HAVING, etc.
The input stream is ordered by the GROUP BY expression, so groups come
one after another. We only need to accumulate the aggregate value, when
a GROUP BY group ends, check the HAVING and send the group.

Note that the output comes in the GROUP BY order, which is required by
the MySQL's GROUP BY semantics. No further sorting is needed.

@seealso end_write_group() also implements SortAndGroup
*/

enum_nested_loop_state
Expand Down Expand Up @@ -21399,13 +21416,26 @@ end_write(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)),

/*
@brief
Perform a GROUP BY operation over rows coming in arbitrary order.

This is done by looking up the group in a temp.table and updating group
values.
Perform GROUP BY operation over rows coming in arbitrary order: use
TemporaryTableWithPartialSums algorithm.

@detail
The TemporaryTableWithPartialSums algorithm is:

CREATE TEMPORARY TABLE tmp (
group_by_columns PRIMARY KEY,
partial_sum
);

for each row R in join output {
INSERT INTO tmp (R.group_by_columns, R.sum_value)
ON DUPLICATE KEY UPDATE partial_sum=partial_sum + R.sum_value;
}

@detail
Also applies HAVING, etc.

@seealso end_unique_update()
*/

static enum_nested_loop_state
Expand Down Expand Up @@ -21553,13 +21583,15 @@ end_unique_update(JOIN *join, JOIN_TAB *join_tab __attribute__((unused)),

/*
@brief
Perform a GROUP BY operation over a stream of rows ordered by their group.
Write the result into a temporary table.
Perform OrderedGroupBy operation and write the output into the temporary
table (join_tab->table).

@detail
Also applies HAVING, etc.
The input stream is ordered by the GROUP BY expression, so groups come
one after another. We only need to accumulate the aggregate value, when
a GROUP BY group ends, check the HAVING and write the group.

The rows are written into temptable so e.g. filesort can read them.
@seealso end_send_group() also implements OrderedGroupBy
*/

enum_nested_loop_state
Expand Down

0 comments on commit f18c2b6

Please sign in to comment.