Commit 1e623bb9 authored by unknown's avatar unknown

allow merging views with subqueries in WHERE clause (BUG#5504)

mysql-test/r/view.result:
  test of subqueries in merged views
mysql-test/t/view.test:
  test of subqueries in merged views
sql/item_subselect.h:
  new method tu return place of subquery
sql/sql_lex.cc:
  allow merging views with subqueries in WHERE clause
sql/sql_view.cc:
  allow merging views with subqueries in WHERE clause
parent 72ed0fc0
......@@ -1457,3 +1457,42 @@ View Create View
v1 CREATE ALGORITHM=TEMPTABLE VIEW `test`.`v1` AS select `test`.`t1`.`a` AS `a` from `test`.`t1`
drop view v1;
drop table t1;
create table t1 (s1 int);
create table t2 (s1 int);
create view v2 as select * from t2 where s1 in (select s1 from t1);
insert into v2 values (5);
insert into t1 values (5);
select * from v2;
s1
5
update v2 set s1 = 0;
select * from v2;
s1
select * from t2;
s1
0
alter view v2 as select * from t2 where s1 in (select s1 from t1) with check option;
insert into v2 values (5);
update v2 set s1 = 1;
ERROR HY000: CHECK OPTION failed 'test.v2'
insert into t1 values (1);
update v2 set s1 = 1;
select * from v2;
s1
1
select * from t2;
s1
0
1
prepare stmt1 from "select * from v2;";
execute stmt1;
s1
1
insert into t1 values (0);
execute stmt1;
s1
0
1
deallocate prepare stmt1;
drop view v2;
drop table t1, t2;
......@@ -1421,3 +1421,33 @@ alter algorithm=temptable view v1 as select * from t1;
show create view v1;
drop view v1;
drop table t1;
#
# updating view with subquery in the WHERE clause
#
create table t1 (s1 int);
create table t2 (s1 int);
create view v2 as select * from t2 where s1 in (select s1 from t1);
insert into v2 values (5);
insert into t1 values (5);
select * from v2;
update v2 set s1 = 0;
select * from v2;
select * from t2;
# check it with check option
alter view v2 as select * from t2 where s1 in (select s1 from t1) with check option;
insert into v2 values (5);
-- error 1369
update v2 set s1 = 1;
insert into t1 values (1);
update v2 set s1 = 1;
select * from v2;
select * from t2;
# scheck how VIEWs with subqueries work with prepared statements
prepare stmt1 from "select * from v2;";
execute stmt1;
insert into t1 values (0);
execute stmt1;
deallocate prepare stmt1;
drop view v2;
drop table t1, t2;
......@@ -109,6 +109,7 @@ public:
engine_changed= 1;
return eng == 0;
}
enum_parsing_place place() { return parsing_place; }
friend class select_subselect;
friend class Item_in_optimizer;
......
......@@ -1543,8 +1543,9 @@ void st_select_lex::print_limit(THD *thd, String *str)
st_lex::can_be_merged()
DESCRIPTION
We can apply merge algorithm if it is single SELECT view (we do not
count SELECTs of underlying views) and we have not grpouping, ordering,
We can apply merge algorithm if it is single SELECT view with
subqueries only in WHERE clause (we do not count SELECTs of underlying
views, and second level subqueries) and we have not grpouping, ordering,
HAVING clause, aggregate functions, DISTINCT clause, LIMIT clause and
several underlying tables.
......@@ -1558,14 +1559,23 @@ bool st_lex::can_be_merged()
// TODO: do not forget implement case when select_lex.table_list.elements==0
/* find non VIEW subqueries/unions */
uint selects= 0;
for (SELECT_LEX *sl= all_selects_list;
sl && selects <= 1;
sl= sl->next_select_in_list())
if (sl->parent_lex == this)
selects++;
return (selects <= 1 &&
bool selects_allow_merge= select_lex.next_select() == 0;
if (selects_allow_merge)
{
for (SELECT_LEX_UNIT *unit= select_lex.first_inner_unit();
unit;
unit= unit->next_unit())
{
if (unit->first_select()->parent_lex == this &&
(unit->item == 0 || unit->item->place() != IN_WHERE))
{
selects_allow_merge= 0;
break;
}
}
}
return (selects_allow_merge &&
select_lex.order_list.elements == 0 &&
select_lex.group_list.elements == 0 &&
select_lex.having == 0 &&
......
......@@ -753,6 +753,20 @@ mysql_make_view(File_parser *parser, TABLE_LIST *table)
/* Store WHERE clause for post-processing in setup_ancestor */
table->where= lex->select_lex.where;
/*
Add subqueries units to SELECT in which we merging current view.
NOTE: we do not support UNION here, so we take only one select
*/
for (SELECT_LEX_UNIT *unit= lex->select_lex.first_inner_unit();
unit;
unit= unit->next_unit())
{
SELECT_LEX_NODE *save_slave= unit->slave;
unit->include_down(table->select_lex);
unit->slave= save_slave; // fix include_down initialisation
}
/*
This SELECT_LEX will be linked in global SELECT_LEX list
to make it processed by mysql_handle_derived(),
......@@ -923,8 +937,12 @@ bool check_key_in_view(THD *thd, TABLE_LIST *view)
uint i, elements_in_view;
DBUG_ENTER("check_key_in_view");
if (!view->view ||
thd->lex->unit.global_parameters->select_limit == HA_POS_ERROR)
/*
we do not support updatable UNIONs in VIW, so we can check just limit of
LEX::select_lex
*/
if (!view->view || thd->lex->sql_command == SQLCOM_INSERT ||
thd->lex->select_lex.select_limit == HA_POS_ERROR)
DBUG_RETURN(FALSE); /* it is normal table or query without LIMIT */
table= view->table;
trans= view->field_translation;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment