Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
M
MariaDB
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
nexedi
MariaDB
Commits
44b9e416
Commit
44b9e416
authored
Nov 17, 2023
by
Marko Mäkelä
Browse files
Options
Browse Files
Download
Plain Diff
Merge 10.5 into 10.6
parents
5a1f821b
9a545eb6
Changes
7
Hide whitespace changes
Inline
Side-by-side
Showing
7 changed files
with
521 additions
and
1 deletion
+521
-1
mysql-test/main/cte_nonrecursive.result
mysql-test/main/cte_nonrecursive.result
+260
-0
mysql-test/main/cte_nonrecursive.test
mysql-test/main/cte_nonrecursive.test
+158
-0
sql/sql_cte.cc
sql/sql_cte.cc
+1
-1
sql/sql_derived.cc
sql/sql_derived.cc
+7
-0
sql/sql_lex.cc
sql/sql_lex.cc
+67
-0
sql/sql_lex.h
sql/sql_lex.h
+8
-0
sql/sql_select.cc
sql/sql_select.cc
+20
-0
No files found.
mysql-test/main/cte_nonrecursive.result
View file @
44b9e416
...
...
@@ -2339,4 +2339,264 @@ set sql_mode="oracle";
with data as (select 1 as id)
select id into @myid from data;
set sql_mode= @save_sql_mode;
#
# MDEV-31995 Bogus error executing PS for query using CTE with renaming of columns
#
create table t1 (a int, b int);
insert into t1 values (1,1),(1,2),(1,3),(2,1),(2,2);
create table t2 (a int, b int);
insert into t2 values (3,1),(3,2),(3,3),(4,1),(4,2);
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 group by col1)
select * from cte;
c1 c2
1 6
2 3
prepare st from "with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 group by col1)
select * from cte";
execute st;
c1 c2
1 6
2 3
execute st;
c1 c2
1 6
2 3
drop prepare st;
create procedure sp() with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 group by col1)
select * from cte;
call sp();
c1 c2
1 6
2 3
call sp();
c1 c2
1 6
2 3
drop procedure sp;
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 order by col1)
select * from cte;
c1 c2
1 9
prepare st from "with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 order by col1)
select * from cte";
execute st;
c1 c2
1 9
execute st;
c1 c2
1 9
drop prepare st;
create procedure sp() with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 order by col1)
select * from cte;
call sp();
c1 c2
1 9
call sp();
c1 c2
1 9
drop procedure sp;
with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 where a > 1 group by col1
union select a as col3, sum(b) as col4 from t2 where b > 2 group by col3),
cte2 (c3, c4) as
(select a as col5, sum(b) as col6 from t1 where a <= 1 group by col5
union select a as col7, sum(b) as col8 from t2 where b <= 2 group by col7)
select * from cte where c1=1 union select * from cte2 where c3=3;
c1 c2
3 3
prepare st from "with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 where a > 1 group by col1
union select a as col3, sum(b) as col4 from t2 where b > 2 group by col3),
cte2 (c3, c4) as
(select a as col5, sum(b) as col6 from t1 where a <= 1 group by col5
union select a as col7, sum(b) as col8 from t2 where b <= 2 group by col7)
select * from cte where c1=1 union select * from cte2 where c3=3";
execute st;
c1 c2
3 3
execute st;
c1 c2
3 3
drop prepare st;
create procedure sp() with cte (c1,c2) as
(select a as col1, sum(b) as col2 from t1 where a > 1 group by col1
union select a as col3, sum(b) as col4 from t2 where b > 2 group by col3),
cte2 (c3, c4) as
(select a as col5, sum(b) as col6 from t1 where a <= 1 group by col5
union select a as col7, sum(b) as col8 from t2 where b <= 2 group by col7)
select * from cte where c1=1 union select * from cte2 where c3=3;
call sp();
c1 c2
3 3
call sp();
c1 c2
3 3
drop procedure sp;
with cte (c1,c2) as (select * from t1)
select cte.c1+1 as col1 , cte.c2 as col2 from cte where cte.c1 > 1
union
select cte.c1 as col3, cte.c2+1 as col4 from cte where cte.c1 < 0;
col1 col2
3 1
3 2
prepare st from "with cte (c1,c2) as (select * from t1)
select cte.c1+1 as col1 , cte.c2 as col2 from cte where cte.c1 > 1
union
select cte.c1 as col3, cte.c2+1 as col4 from cte where cte.c1 < 0";
execute st;
col1 col2
3 1
3 2
execute st;
col1 col2
3 1
3 2
save this to the end to test errors >drop prepare st;
create procedure sp() with cte (c1,c2) as (select * from t1)
select cte.c1+1 as col1 , cte.c2 as col2 from cte where cte.c1 > 1
union
select cte.c1 as col3, cte.c2+1 as col4 from cte where cte.c1 < 0;
call sp();
col1 col2
3 1
3 2
call sp();
col1 col2
3 1
3 2
drop procedure sp;
insert into t1 select * from t2;
with cte (c1, c2)
as (select a, sum(b) from t1 where b > 1 group by a having sum(b) < 5)
select * from cte where c1 < 4 and c2 > 1;
c1 c2
2 2
# Check pushdown conditions in JSON output
explain format=json with cte (c1, c2)
as (select a, sum(b) from t1 where b > 1 group by a having sum(b) < 5)
select * from cte where c1 < 4 and c2 > 1;
EXPLAIN
{
"query_block": {
"select_id": 1,
"table": {
"table_name": "<derived2>",
"access_type": "ALL",
"rows": 10,
"filtered": 100,
"attached_condition": "cte.c1 < 4 and cte.c2 > 1",
"materialized": {
"query_block": {
"select_id": 2,
"having_condition": "sum(t1.b) < 5 and c2 > 1",
"filesort": {
"sort_key": "t1.a",
"temporary_table": {
"table": {
"table_name": "t1",
"access_type": "ALL",
"rows": 10,
"filtered": 100,
"attached_condition": "t1.b > 1 and t1.a < 4"
}
}
}
}
}
}
}
}
alter table t1 add column c int;
execute st;
ERROR HY000: WITH column list and SELECT field list have different column counts
drop prepare st;
drop table t1,t2;
Test out recursive CTEs
create table distances (src char(1), dest char(1), distance int);
create table city_population (city char(1), population int);
INSERT INTO `distances` VALUES ('A','A',0),('B','A',593),('C','A',800),
('D','A',221),('E','A',707),('F','A',869),('G','A',225),('H','A',519),
('A','B',919),('B','B',0),('C','B',440),('D','B',79),('E','B',79),
('F','B',154),('G','B',537),('H','B',220),('A','C',491),('B','C',794),
('C','C',0),('D','C',100),('E','C',350),('F','C',748),('G','C',712),
('H','C',315),('A','D',440),('B','D',256),('C','D',958),('D','D',0),
('E','D',255),('F','D',161),('G','D',63),('H','D',831),('A','E',968),
('B','E',345),('C','E',823),('D','E',81),('E','E',0),('F','E',436),
('G','E',373),('H','E',558),('A','F',670),('B','F',677),('C','F',375),
('D','F',843),('E','F',90),('F','F',0),('G','F',328),('H','F',881),
('A','G',422),('B','G',467),('C','G',67),('D','G',936),('E','G',480),
('F','G',592),('G','G',0),('H','G',819),('A','H',537),('B','H',229),
('C','H',534),('D','H',984),('E','H',319),('F','H',643),('G','H',257),
('H','H',0);
insert into city_population values ('A', 5000), ('B', 6000), ('C', 100000),
('D', 80000), ('E', 7000), ('F', 1000), ('G', 100), ('H', -80000);
#find the biggest city within 300 kellikams of 'E'
with recursive travel (src, path, dest, distance, population) as (
select city, cast('' as varchar(10)), city,
0, population
from city_population where city='E'
union all
select src.src, concat(src.path, dst.dest), dst.dest,
src.distance + dst.distance, dstc.population
from travel src
join distances dst on src.dest != dst.dest
join city_population dstc on dst.dest = dstc.city
where dst.src = src.dest and src.distance + dst.distance < 300
and length(path) < 10
)
select * from travel where dest != 'E' order by population desc, distance
limit 1;
src path dest distance population
E FD D 251 80000
prepare st from "with recursive travel (src, path, dest, distance, population) as (
select city, cast('' as varchar(10)), city,
0, population
from city_population where city='E'
union all
select src.src, concat(src.path, dst.dest), dst.dest,
src.distance + dst.distance, dstc.population
from travel src
join distances dst on src.dest != dst.dest
join city_population dstc on dst.dest = dstc.city
where dst.src = src.dest and src.distance + dst.distance < 300
and length(path) < 10
)
select * from travel where dest != 'E' order by population desc, distance
limit 1";
execute st;
src path dest distance population
E FD D 251 80000
execute st;
src path dest distance population
E FD D 251 80000
drop prepare st;
create procedure sp() with recursive travel (src, path, dest, distance, population) as (
select city, cast('' as varchar(10)), city,
0, population
from city_population where city='E'
union all
select src.src, concat(src.path, dst.dest), dst.dest,
src.distance + dst.distance, dstc.population
from travel src
join distances dst on src.dest != dst.dest
join city_population dstc on dst.dest = dstc.city
where dst.src = src.dest and src.distance + dst.distance < 300
and length(path) < 10
)
select * from travel where dest != 'E' order by population desc, distance
limit 1;
call sp();
src path dest distance population
E FD D 251 80000
call sp();
src path dest distance population
E FD D 251 80000
drop procedure sp;
drop table distances, city_population;
# End of 10.4 tests
mysql-test/main/cte_nonrecursive.test
View file @
44b9e416
...
...
@@ -1796,4 +1796,162 @@ with data as (select 1 as id)
select
id
into
@
myid
from
data
;
set
sql_mode
=
@
save_sql_mode
;
--
echo
#
--
echo
# MDEV-31995 Bogus error executing PS for query using CTE with renaming of columns
--
echo
#
create
table
t1
(
a
int
,
b
int
);
insert
into
t1
values
(
1
,
1
),(
1
,
2
),(
1
,
3
),(
2
,
1
),(
2
,
2
);
create
table
t2
(
a
int
,
b
int
);
insert
into
t2
values
(
3
,
1
),(
3
,
2
),(
3
,
3
),(
4
,
1
),(
4
,
2
);
let
$q
=
with
cte
(
c1
,
c2
)
as
(
select
a
as
col1
,
sum
(
b
)
as
col2
from
t1
group
by
col1
)
select
*
from
cte
;
eval
$q
;
eval
prepare
st
from
"
$q
"
;
execute
st
;
execute
st
;
drop
prepare
st
;
eval
create
procedure
sp
()
$q
;
call
sp
();
call
sp
();
drop
procedure
sp
;
let
$q
=
with
cte
(
c1
,
c2
)
as
(
select
a
as
col1
,
sum
(
b
)
as
col2
from
t1
order
by
col1
)
select
*
from
cte
;
eval
$q
;
eval
prepare
st
from
"
$q
"
;
execute
st
;
execute
st
;
drop
prepare
st
;
eval
create
procedure
sp
()
$q
;
call
sp
();
call
sp
();
drop
procedure
sp
;
let
$q
=
with
cte
(
c1
,
c2
)
as
(
select
a
as
col1
,
sum
(
b
)
as
col2
from
t1
where
a
>
1
group
by
col1
union
select
a
as
col3
,
sum
(
b
)
as
col4
from
t2
where
b
>
2
group
by
col3
),
cte2
(
c3
,
c4
)
as
(
select
a
as
col5
,
sum
(
b
)
as
col6
from
t1
where
a
<=
1
group
by
col5
union
select
a
as
col7
,
sum
(
b
)
as
col8
from
t2
where
b
<=
2
group
by
col7
)
select
*
from
cte
where
c1
=
1
union
select
*
from
cte2
where
c3
=
3
;
eval
$q
;
eval
prepare
st
from
"
$q
"
;
execute
st
;
execute
st
;
drop
prepare
st
;
eval
create
procedure
sp
()
$q
;
call
sp
();
call
sp
();
drop
procedure
sp
;
let
$q
=
with
cte
(
c1
,
c2
)
as
(
select
*
from
t1
)
select
cte
.
c1
+
1
as
col1
,
cte
.
c2
as
col2
from
cte
where
cte
.
c1
>
1
union
select
cte
.
c1
as
col3
,
cte
.
c2
+
1
as
col4
from
cte
where
cte
.
c1
<
0
;
eval
$q
;
eval
prepare
st
from
"
$q
"
;
execute
st
;
execute
st
;
--
echo
save
this
to
the
end
to
test
errors
>
drop
prepare
st
;
eval
create
procedure
sp
()
$q
;
call
sp
();
call
sp
();
drop
procedure
sp
;
insert
into
t1
select
*
from
t2
;
let
$q
=
with
cte
(
c1
,
c2
)
as
(
select
a
,
sum
(
b
)
from
t1
where
b
>
1
group
by
a
having
sum
(
b
)
<
5
)
select
*
from
cte
where
c1
<
4
and
c2
>
1
;
eval
$q
;
--
echo
# Check pushdown conditions in JSON output
--
source
include
/
analyze
-
format
.
inc
eval
explain
format
=
json
$q
;
alter
table
t1
add
column
c
int
;
--
error
ER_WITH_COL_WRONG_LIST
execute
st
;
drop
prepare
st
;
drop
table
t1
,
t2
;
--
echo
Test
out
recursive
CTEs
create
table
distances
(
src
char
(
1
),
dest
char
(
1
),
distance
int
);
create
table
city_population
(
city
char
(
1
),
population
int
);
INSERT
INTO
`distances`
VALUES
(
'A'
,
'A'
,
0
),(
'B'
,
'A'
,
593
),(
'C'
,
'A'
,
800
),
(
'D'
,
'A'
,
221
),(
'E'
,
'A'
,
707
),(
'F'
,
'A'
,
869
),(
'G'
,
'A'
,
225
),(
'H'
,
'A'
,
519
),
(
'A'
,
'B'
,
919
),(
'B'
,
'B'
,
0
),(
'C'
,
'B'
,
440
),(
'D'
,
'B'
,
79
),(
'E'
,
'B'
,
79
),
(
'F'
,
'B'
,
154
),(
'G'
,
'B'
,
537
),(
'H'
,
'B'
,
220
),(
'A'
,
'C'
,
491
),(
'B'
,
'C'
,
794
),
(
'C'
,
'C'
,
0
),(
'D'
,
'C'
,
100
),(
'E'
,
'C'
,
350
),(
'F'
,
'C'
,
748
),(
'G'
,
'C'
,
712
),
(
'H'
,
'C'
,
315
),(
'A'
,
'D'
,
440
),(
'B'
,
'D'
,
256
),(
'C'
,
'D'
,
958
),(
'D'
,
'D'
,
0
),
(
'E'
,
'D'
,
255
),(
'F'
,
'D'
,
161
),(
'G'
,
'D'
,
63
),(
'H'
,
'D'
,
831
),(
'A'
,
'E'
,
968
),
(
'B'
,
'E'
,
345
),(
'C'
,
'E'
,
823
),(
'D'
,
'E'
,
81
),(
'E'
,
'E'
,
0
),(
'F'
,
'E'
,
436
),
(
'G'
,
'E'
,
373
),(
'H'
,
'E'
,
558
),(
'A'
,
'F'
,
670
),(
'B'
,
'F'
,
677
),(
'C'
,
'F'
,
375
),
(
'D'
,
'F'
,
843
),(
'E'
,
'F'
,
90
),(
'F'
,
'F'
,
0
),(
'G'
,
'F'
,
328
),(
'H'
,
'F'
,
881
),
(
'A'
,
'G'
,
422
),(
'B'
,
'G'
,
467
),(
'C'
,
'G'
,
67
),(
'D'
,
'G'
,
936
),(
'E'
,
'G'
,
480
),
(
'F'
,
'G'
,
592
),(
'G'
,
'G'
,
0
),(
'H'
,
'G'
,
819
),(
'A'
,
'H'
,
537
),(
'B'
,
'H'
,
229
),
(
'C'
,
'H'
,
534
),(
'D'
,
'H'
,
984
),(
'E'
,
'H'
,
319
),(
'F'
,
'H'
,
643
),(
'G'
,
'H'
,
257
),
(
'H'
,
'H'
,
0
);
insert
into
city_population
values
(
'A'
,
5000
),
(
'B'
,
6000
),
(
'C'
,
100000
),
(
'D'
,
80000
),
(
'E'
,
7000
),
(
'F'
,
1000
),
(
'G'
,
100
),
(
'H'
,
-
80000
);
--
echo
#find the biggest city within 300 kellikams of 'E'
let
$q
=
with
recursive
travel
(
src
,
path
,
dest
,
distance
,
population
)
as
(
select
city
,
cast
(
''
as
varchar
(
10
)),
city
,
0
,
population
from
city_population
where
city
=
'E'
union
all
select
src
.
src
,
concat
(
src
.
path
,
dst
.
dest
),
dst
.
dest
,
src
.
distance
+
dst
.
distance
,
dstc
.
population
from
travel
src
join
distances
dst
on
src
.
dest
!=
dst
.
dest
join
city_population
dstc
on
dst
.
dest
=
dstc
.
city
where
dst
.
src
=
src
.
dest
and
src
.
distance
+
dst
.
distance
<
300
and
length
(
path
)
<
10
)
select
*
from
travel
where
dest
!=
'E'
order
by
population
desc
,
distance
limit
1
;
eval
$q
;
eval
prepare
st
from
"
$q
"
;
execute
st
;
execute
st
;
drop
prepare
st
;
eval
create
procedure
sp
()
$q
;
call
sp
();
call
sp
();
drop
procedure
sp
;
drop
table
distances
,
city_population
;
--
echo
# End of 10.4 tests
sql/sql_cte.cc
View file @
44b9e416
...
...
@@ -1199,7 +1199,7 @@ With_element::process_columns_of_derived_unit(THD *thd,
/* Rename the columns of the first select in the unit */
while
((
item
=
it
++
,
name
=
nm
++
))
{
item
->
set_name
(
thd
,
*
name
);
lex_string_set
(
&
item
->
name
,
name
->
str
);
item
->
base_flags
|=
item_base_t
::
IS_EXPLICIT_NAME
;
}
...
...
sql/sql_derived.cc
View file @
44b9e416
...
...
@@ -1350,6 +1350,13 @@ bool mysql_derived_reinit(THD *thd, LEX *lex, TABLE_LIST *derived)
(
derived
->
alias
.
str
?
derived
->
alias
.
str
:
"<NULL>"
),
derived
->
get_unit
()));
st_select_lex_unit
*
unit
=
derived
->
get_unit
();
st_select_lex
*
sl
=
unit
->
first_select
();
// reset item names to that saved after wildcard expansion in JOIN::prepare
do
{
sl
->
restore_item_list_names
();
}
while
((
sl
=
sl
->
next_select
()));
derived
->
merged_for_insert
=
FALSE
;
unit
->
unclean
();
...
...
sql/sql_lex.cc
View file @
44b9e416
...
...
@@ -2986,6 +2986,7 @@ void st_select_lex::init_query()
tvc
=
0
;
versioned_tables
=
0
;
pushdown_select
=
0
;
orig_names_of_item_list_elems
=
0
;
}
void
st_select_lex
::
init_select
()
...
...
@@ -3037,6 +3038,7 @@ void st_select_lex::init_select()
versioned_tables
=
0
;
is_tvc_wrapper
=
false
;
nest_flags
=
0
;
orig_names_of_item_list_elems
=
0
;
}
/*
...
...
@@ -11180,6 +11182,71 @@ Item *st_select_lex::pushdown_from_having_into_where(THD *thd, Item *having)
}
/**
@brief
Save the original names of items from the item list.
@retval
true - if an error occurs
false - otherwise
*/
bool
st_select_lex
::
save_item_list_names
(
THD
*
thd
)
{
if
(
orig_names_of_item_list_elems
)
return
false
;
Query_arena
*
arena
,
backup
;
arena
=
thd
->
activate_stmt_arena_if_needed
(
&
backup
);
if
(
unlikely
(
!
(
orig_names_of_item_list_elems
=
new
(
thd
->
mem_root
)
List
<
Lex_ident_sys
>
)))
return
true
;
List_iterator_fast
<
Item
>
li
(
item_list
);
Item
*
item
;
while
((
item
=
li
++
))
{
if
(
unlikely
(
orig_names_of_item_list_elems
->
push_back
(
new
Lex_ident_sys
(
item
->
name
.
str
,
item
->
name
.
length
))))
{
if
(
arena
)
thd
->
restore_active_arena
(
arena
,
&
backup
);
orig_names_of_item_list_elems
=
0
;
return
true
;
}
}
if
(
arena
)
thd
->
restore_active_arena
(
arena
,
&
backup
);
return
false
;
}
/**
@brief
Restore the name of each item in the item_list of this st_select_lex
from orig_names_of_item_list_elems.
*/
void
st_select_lex
::
restore_item_list_names
()
{
if
(
!
orig_names_of_item_list_elems
)
return
;
DBUG_ASSERT
(
item_list
.
elements
==
orig_names_of_item_list_elems
->
elements
);
List_iterator_fast
<
Lex_ident_sys
>
it
(
*
orig_names_of_item_list_elems
);
Lex_ident_sys
*
new_name
;
List_iterator_fast
<
Item
>
li
(
item_list
);
Item
*
item
;
while
((
item
=
li
++
)
&&
(
new_name
=
it
++
))
lex_string_set
(
&
item
->
name
,
new_name
->
str
);
}
bool
LEX
::
stmt_install_plugin
(
const
DDL_options_st
&
opt
,
const
Lex_ident_sys_st
&
name
,
const
LEX_CSTRING
&
soname
)
...
...
sql/sql_lex.h
View file @
44b9e416
...
...
@@ -1217,6 +1217,11 @@ class st_select_lex: public st_select_lex_node
List
<
Field_pair
>
grouping_tmp_fields
;
List
<
udf_func
>
udf_list
;
/* udf function calls stack */
List
<
Index_hint
>
*
index_hints
;
/* list of USE/FORCE/IGNORE INDEX */
/*
This list is used to restore the names of items
from item_list after each execution of the statement.
*/
List
<
Lex_ident_sys
>
*
orig_names_of_item_list_elems
;
List
<
List_item
>
save_many_values
;
List
<
Item
>
*
save_insert_list
;
...
...
@@ -1434,6 +1439,9 @@ class st_select_lex: public st_select_lex_node
bool
straight_fl
);
TABLE_LIST
*
convert_right_join
();
List
<
Item
>*
get_item_list
();
bool
save_item_list_names
(
THD
*
thd
);
void
restore_item_list_names
();
ulong
get_table_join_options
();
void
set_lock_for_tables
(
thr_lock_type
lock_type
,
bool
for_update
,
bool
skip_locks
);
...
...
sql/sql_select.cc
View file @
44b9e416
...
...
@@ -1430,6 +1430,26 @@ JOIN::prepare(TABLE_LIST *tables_init, COND *conds_init, uint og_num,
if
(
setup_wild
(
thd
,
tables_list
,
fields_list
,
&
all_fields
,
select_lex
,
false
))
DBUG_RETURN
(
-
1
);
/*
If the select_lex is immediately contained within a derived table
AND this derived table is a CTE
WITH supplied column names
AND we have the correct number of elements in both lists
(mismatches found in mysql_derived_prepare/rename_columns_of_derived_unit)
THEN NOW is the time to take a copy of these item_names for
later restoration if required.
*/
TABLE_LIST
*
derived
=
select_lex
->
master_unit
()
->
derived
;
if
(
derived
&&
derived
->
with
&&
derived
->
with
->
column_list
.
elements
&&
(
derived
->
with
->
column_list
.
elements
==
select_lex
->
item_list
.
elements
))
{
if
(
select_lex
->
save_item_list_names
(
thd
))
DBUG_RETURN
(
-
1
);
}
if
(
thd
->
lex
->
current_select
->
first_cond_optimization
)
{
if
(
conds
&&
!
thd
->
lex
->
current_select
->
merged_into
)
...
...
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment