Skip to content

Commit

Permalink
MDEV-3944: Allow derived tables in VIEWS
Browse files Browse the repository at this point in the history
  • Loading branch information
sanja-byelkin committed May 28, 2016
1 parent 1f89ea8 commit 7166069
Show file tree
Hide file tree
Showing 15 changed files with 450 additions and 57 deletions.
15 changes: 6 additions & 9 deletions mysql-test/r/cte_nonrecursive.result
Original file line number Diff line number Diff line change
Expand Up @@ -543,9 +543,8 @@ c a
explain
select * from v1;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 32
2 DERIVED t2 ALL NULL NULL NULL NULL 4
2 DERIVED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 SIMPLE t2 ALL NULL NULL NULL NULL 4
1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
# with claused in the specification of a materialized view
create view v2 as
with t as (select a, count(*) from t1 where b >= 'c' group by a)
Expand All @@ -560,9 +559,8 @@ c a count(*)
explain
select * from v2;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 8
2 DERIVED t2 ALL NULL NULL NULL NULL 4 Using where
2 DERIVED <derived3> ref key0 key0 5 test.t2.c 2
1 PRIMARY t2 ALL NULL NULL NULL NULL 4 Using where
1 PRIMARY <derived3> ref key0 key0 5 test.t2.c 2
3 SUBQUERY t1 ALL NULL NULL NULL NULL 8 Using where; Using temporary; Using filesort
# with clause in the specification of a view that whose definition
# table alias for a with table
Expand Down Expand Up @@ -593,9 +591,8 @@ c d
explain
select * from v4;
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY <derived2> ALL NULL NULL NULL NULL 64
2 DERIVED t1 ALL NULL NULL NULL NULL 8 Using where
2 DERIVED t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where
1 SIMPLE t1 ALL NULL NULL NULL NULL 8 Using where; Using join buffer (flat, BNL join)
drop view v1,v2,v3,v4;
# currently any views containing with clause are not updatable
create view v1(a) as
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/r/sp-error.result
Original file line number Diff line number Diff line change
Expand Up @@ -1235,8 +1235,8 @@ ERROR 42000: You have an error in your SQL syntax; check the manual that corresp
CREATE PROCEDURE bug20953()
CREATE VIEW v AS SELECT i FROM t1 PROCEDURE ANALYSE();
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'PROCEDURE ANALYSE()' at line 2
CREATE PROCEDURE bug20953() CREATE VIEW v AS SELECT 1 FROM (SELECT 1) AS d1;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
CREATE PROCEDURE bug20953() CREATE VIEW v AS SELECT 1 FROM (SELECT 1) AS d1 into @w;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'into @w' at line 1
CREATE PROCEDURE bug20953(i INT) CREATE VIEW v AS SELECT i;
ERROR HY000: View's SELECT contains a variable or parameter
CREATE PROCEDURE bug20953()
Expand Down
254 changes: 243 additions & 11 deletions mysql-test/r/view.result
Original file line number Diff line number Diff line change
Expand Up @@ -930,7 +930,7 @@ create table t1 (a int);
create view v1 as select a from t1 procedure analyse();
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'procedure analyse()' at line 1
create view v1 as select 1 from (select 1) as d1;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
drop view v1;
drop table t1;
create table t1 (s1 int, primary key (s1));
create view v1 as select * from t1;
Expand Down Expand Up @@ -1494,7 +1494,7 @@ a
create view v2 (a,b) as select t1.b as a, t2.a as b from t1, t2;
set updatable_views_with_limit=NO;
update v2 set a= 10 where a=200 limit 1;
ERROR HY000: The target table t1 of the UPDATE is not updatable
ERROR HY000: The target table v2 of the UPDATE is not updatable
set updatable_views_with_limit=DEFAULT;
select * from v3;
a b
Expand Down Expand Up @@ -3209,15 +3209,11 @@ code COUNT(DISTINCT country)
DROP VIEW v1;
DROP TABLE t1;
DROP VIEW IF EXISTS v1;
SELECT * FROM (SELECT 1) AS t;
1
1
CREATE VIEW v1 AS SELECT * FROM (SELECT 1) AS t;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
SELECT * FROM (SELECT 1) AS t into @w;
CREATE VIEW v1 AS SELECT * FROM (SELECT 1) AS t into @w;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MariaDB server version for the right syntax to use near 'into @w' at line 1
# Previously the following would fail.
SELECT * FROM (SELECT 1) AS t;
1
1
SELECT * FROM (SELECT 1) AS t into @w;
drop view if exists view_24532_a;
drop view if exists view_24532_b;
drop table if exists table_24532;
Expand Down Expand Up @@ -4100,7 +4096,7 @@ ERROR HY000: The target table v1 of the INSERT is not insertable-into
DELETE from v1;
ERROR HY000: The target table v1 of the DELETE is not updatable
UPDATE v3 SET b= 10;
ERROR HY000: The target table v2 of the UPDATE is not updatable
ERROR HY000: The target table v3 of the UPDATE is not updatable
REPLACE v3 SET b= 10;
ERROR HY000: The target table v3 of the INSERT is not insertable-into
INSERT into v3(b) values (20);
Expand Down Expand Up @@ -5953,5 +5949,241 @@ t3 CREATE TABLE `t3` (
DROP VIEW v1;
DROP TABLE t1,t2,t3;
#
# MDEV-3944: Allow derived tables in VIEWS
#
create table t1 (s1 int);
insert into t1 values (1),(2),(3);
CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM t1 WHERE s1>1) AS x;
CREATE VIEW v2 AS SELECT * FROM (SELECT s1 FROM t1 WHERE s1<3) AS x;
select * from v1;
s1
2
3
select * from v2;
s1
1
2
select * from v1 natural join v2;
s1
2
select * from v1 natural join t1;
s1
2
3
select * from v1 natural join (SELECT s1 FROM t1 WHERE s1<3) as x;
s1
2
select * from v1 left join v2 on (v1.s1=v2.s1);
s1 s1
2 2
3 NULL
select * from v1 left join t1 on (v1.s1=t1.s1);
s1 s1
2 2
3 3
select * from t1 left join v2 on (t1.s1=v2.s1);
s1 s1
1 1
2 2
3 NULL
select * from v1 left join (SELECT s1 FROM t1 WHERE s1<3) as x on (v1.s1=x.s1);
s1 s1
2 2
3 NULL
select * from (SELECT s1 FROM t1 WHERE s1>1) AS x left join v2 on (x.s1=v2.s1);
s1 s1
2 2
3 NULL
drop view v1,v2;
CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
< 100) as xx WHERE s1>1) AS x;
CREATE VIEW v2 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
> -100) as xx WHERE s1<3) AS x;
insert into t1 values (200),(-200);
select * from t1;
s1
-200
1
2
200
3
select * from v1;
s1
2
3
select * from v2;
s1
1
2
select * from v1 natural join v2;
s1
2
select * from v1 natural join t1;
s1
2
3
select * from v1 natural join (SELECT s1 FROM t1 WHERE s1<3) as x;
s1
2
select * from v1 left join v2 on (v1.s1=v2.s1);
s1 s1
2 2
3 NULL
select * from v1 left join t1 on (v1.s1=t1.s1);
s1 s1
2 2
3 3
select * from t1 left join v2 on (t1.s1=v2.s1);
s1 s1
-200 NULL
1 1
2 2
200 NULL
3 NULL
select * from v1 left join (SELECT s1 FROM t1 WHERE s1<3) as x on (v1.s1=x.s1);
s1 s1
2 2
3 NULL
select * from (SELECT s1 FROM t1 WHERE s1>1) AS x left join v2 on (x.s1=v2.s1);
s1 s1
2 2
200 NULL
3 NULL
drop view v1,v2;
CREATE algorithm=temptable VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
< 100) as xx WHERE s1>1) AS x;
CREATE algorithm=temptable VIEW v2 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
> -100) as xx WHERE s1<3) AS x;
select * from t1;
s1
-200
1
2
200
3
select * from v1;
s1
2
3
select * from v2;
s1
1
2
select * from v1 natural join v2;
s1
2
select * from v1 natural join t1;
s1
2
3
select * from v1 natural join (SELECT s1 FROM t1 WHERE s1<3) as x;
s1
2
select * from v1 left join v2 on (v1.s1=v2.s1);
s1 s1
2 2
3 NULL
select * from v1 left join t1 on (v1.s1=t1.s1);
s1 s1
2 2
3 3
select * from t1 left join v2 on (t1.s1=v2.s1);
s1 s1
-200 NULL
1 1
2 2
200 NULL
3 NULL
select * from v1 left join (SELECT s1 FROM t1 WHERE s1<3) as x on (v1.s1=x.s1);
s1 s1
2 2
3 NULL
select * from (SELECT s1 FROM t1 WHERE s1>1) AS x left join v2 on (x.s1=v2.s1);
s1 s1
2 2
200 NULL
3 NULL
drop view v1,v2;
CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
< 100) as xx WHERE s1>1) AS x;
insert into v1 values (-300);
ERROR HY000: The target table v1 of the INSERT is not insertable-into
update v1 set s1=s1+1;
ERROR HY000: The target table v1 of the UPDATE is not updatable
drop view v1;
CREATE VIEW v1 AS SELECT s1,s2 FROM (SELECT s1 as s2 FROM t1 WHERE s1 <
100) x, t1 WHERE t1.s1=x.s2;
select * from v1;
s1 s2
1 1
2 2
3 3
-200 -200
insert into v1 (s1) values (-300);
update v1 set s1=s1+1;
select * from v1;
s1 s2
2 2
3 3
4 4
-199 -199
-299 -299
select * from t1;
s1
2
3
4
200
-199
-299
insert into v1(s2) values (-300);
ERROR HY000: The target table v1 of the INSERT is not insertable-into
update v1 set s2=s2+1;
ERROR HY000: The target table v1 of the UPDATE is not updatable
drop view v1;
CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM t1 WHERE s1
< 100) AS x;
insert into v1 values (-300);
ERROR HY000: The target table v1 of the INSERT is not insertable-into
update v1 set s1=s1+1;
ERROR HY000: The target table v1 of the UPDATE is not updatable
drop view v1;
CREATE VIEW v1 AS SELECT * FROM (SELECT s1 FROM (SELECT s1 FROM t1 WHERE s1
< 100) as xx WHERE s1>1) AS x;
insert into v1 values (-300);
ERROR HY000: The target table v1 of the INSERT is not insertable-into
update v1 set s1=s1+1;
ERROR HY000: The target table v1 of the UPDATE is not updatable
create view v2 as select * from v1;
insert into v2 values (-300);
ERROR HY000: The target table v2 of the INSERT is not insertable-into
update v2 set s1=s1+1;
ERROR HY000: The target table v2 of the UPDATE is not updatable
drop view v1, v2;
drop table t1;
#
# MDEV-9671:Wrong result upon select from a view with a FROM subquery
#
CREATE TABLE t1 (i INT);
INSERT INTO t1 VALUES (3),(2);
CREATE TABLE t2 (j INT);
INSERT INTO t2 VALUES (8),(3),(3);
CREATE TABLE t3 (k INT);
INSERT INTO t3 VALUES (1),(8);
CREATE VIEW v1 AS SELECT * FROM t1 LEFT JOIN ( SELECT t2.* FROM t2 INNER JOIN t3 ON ( k = j ) ) AS alias1 ON ( i = j );
show create view v1;
View Create View character_set_client collation_connection
v1 CREATE ALGORITHM=UNDEFINED DEFINER=`root`@`localhost` SQL SECURITY DEFINER VIEW `v1` AS select `test`.`t1`.`i` AS `i`,`alias1`.`j` AS `j` from (`test`.`t1` left join (select `test`.`t2`.`j` AS `j` from (`test`.`t2` join `test`.`t3` on((`test`.`t3`.`k` = `test`.`t2`.`j`)))) `alias1` on((`test`.`t1`.`i` = `alias1`.`j`))) latin1 latin1_swedish_ci
SELECT * FROM t1 LEFT JOIN ( SELECT t2.* FROM t2 INNER JOIN t3 ON ( k = j ) ) AS alias1 ON ( i = j );
i j
3 NULL
2 NULL
SELECT * FROM v1;
i j
3 NULL
2 NULL
DROP VIEW v1;
DROP TABLE t1, t2, t3;
#
# End of 10.2 tests
#
4 changes: 2 additions & 2 deletions mysql-test/suite/funcs_1/r/innodb_views.result
Original file line number Diff line number Diff line change
Expand Up @@ -3503,7 +3503,7 @@ Select @x;
0
CREATE or REPLACE VIEW v1 AS Select 1
FROM (SELECT 1 FROM t1) my_table;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
DROP VIEW v1;
CREATE VIEW v1 AS SELECT f1 FROM t1;
CREATE TRIGGER tr1 BEFORE INSERT ON t1 FOR EACH ROW SET @a:=1 ;
SET @a:=0 ;
Expand Down Expand Up @@ -7535,7 +7535,7 @@ Testcase 3.3.1.39
Drop view if exists test.v1 ;
CREATE VIEW test.v1
AS Select f59 from (Select * FROM tb2 limit 20) tx ;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
DROP VIEW test.v1;
SELECT * FROM test.v1 order by f59 ;
ERROR 42S02: Table 'test.v1' doesn't exist
Drop view if exists test.v1 ;
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/suite/funcs_1/r/memory_views.result
Original file line number Diff line number Diff line change
Expand Up @@ -3504,7 +3504,7 @@ Select @x;
0
CREATE or REPLACE VIEW v1 AS Select 1
FROM (SELECT 1 FROM t1) my_table;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
DROP VIEW v1;
CREATE VIEW v1 AS SELECT f1 FROM t1;
CREATE TRIGGER tr1 BEFORE INSERT ON t1 FOR EACH ROW SET @a:=1 ;
SET @a:=0 ;
Expand Down Expand Up @@ -7536,7 +7536,7 @@ Testcase 3.3.1.39
Drop view if exists test.v1 ;
CREATE VIEW test.v1
AS Select f59 from (Select * FROM tb2 limit 20) tx ;
ERROR HY000: View's SELECT contains a subquery in the FROM clause
DROP VIEW test.v1;
SELECT * FROM test.v1 order by f59 ;
ERROR 42S02: Table 'test.v1' doesn't exist
Drop view if exists test.v1 ;
Expand Down
4 changes: 2 additions & 2 deletions mysql-test/suite/funcs_1/views/views_master.inc
Original file line number Diff line number Diff line change
Expand Up @@ -271,9 +271,9 @@ CREATE or REPLACE VIEW v1 AS Select 1 INTO @x;
Select @x;

# Subquery in the FROM clause is illegal
--error ER_VIEW_SELECT_DERIVED
CREATE or REPLACE VIEW v1 AS Select 1
FROM (SELECT 1 FROM t1) my_table;
DROP VIEW v1;

# Triggers cannot be associated with VIEWs
CREATE VIEW v1 AS SELECT f1 FROM t1;
Expand Down Expand Up @@ -1557,9 +1557,9 @@ let $message= Testcase 3.3.1.39 ;
--disable_warnings
Drop view if exists test.v1 ;
--enable_warnings
--error ER_VIEW_SELECT_DERIVED
CREATE VIEW test.v1
AS Select f59 from (Select * FROM tb2 limit 20) tx ;
DROP VIEW test.v1;
--error ER_NO_SUCH_TABLE
SELECT * FROM test.v1 order by f59 ;
--disable_warnings
Expand Down
Loading

0 comments on commit 7166069

Please sign in to comment.