Commit f7a75b99 authored by Igor Babaev's avatar Igor Babaev

The main commit of Andrey Zhakov's patch introducing vurtual(computed) columns.

The original patch has been ameliorated by Sanja and Igor.
parent 8ea19fa7
...@@ -67,7 +67,8 @@ enum enum_server_command ...@@ -67,7 +67,8 @@ enum enum_server_command
COM_END COM_END
}; };
/* sql type stored in .frm files for virtual fields */
#define MYSQL_TYPE_VIRTUAL 245
/* /*
Length of random string sent by server on handshake; this is also length of Length of random string sent by server on handshake; this is also length of
obfuscated password, recieved from client obfuscated password, recieved from client
......
This diff is collapsed.
################################################################################
# inc/vcol_cleanup.inc #
# #
# Purpose: #
# Removal of the objects created by the t/<test_name>.test #
# scripts. #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-08-31 #
# Change Author: #
# Change Date: #
# Change: #
################################################################################
--disable_warnings
--disable_query_log
DROP VIEW IF EXISTS v1,v2;
DROP TABLE IF EXISTS t1,t2,t3;
DROP PROCEDURE IF EXISTS p1;
DROP FUNCTION IF EXISTS f1;
DROP TRIGGER IF EXISTS trg1;
DROP TRIGGER IF EXISTS trg2;
--enable_query_log
--enable_warnings
################################################################################
# inc/vcol_column_def_options.inc #
# #
# Purpose: #
# Testing different optional parameters specified when defining #
# a virtual column. #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-02 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--echo #
--echo # Section 1. Wrong column definition options
--echo # - NOT NULL
--echo # - NULL
--echo # - DEFAULT <value>
--echo # - AUTO_INCREMENT
--echo # - [PRIMARY] KEY
--echo # NOT NULL
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) not null);
create table t1 (a int);
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) not null;
drop table t1;
--echo # NULL
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) null);
create table t1 (a int);
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) null;
drop table t1;
--echo # DEFAULT
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) default 0);
create table t1 (a int);
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) default 0;
drop table t1;
--echo # AUTO_INCREMENT
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) AUTO_INCREMENT);
create table t1 (a int);
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) AUTO_INCREMENT;
drop table t1;
--echo # [PRIMARY] KEY
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) key);
--error ER_PARSE_ERROR
create table t1 (a int, b int as (a+1) primary key);
create table t1 (a int);
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) key;
--error ER_PARSE_ERROR
alter table t1 add column b int as (a+1) primary key;
drop table t1;
--echo # Section 2. Other column definition options
--echo # - COMMENT
--echo # - REFERENCES (only syntax testing here)
--echo # - STORED (only systax testing here)
create table t1 (a int, b int as (a % 2) comment 'my comment');
show create table t1;
describe t1;
drop table t1;
create table t1 (a int, b int as (a % 2));
alter table t1 modify b int as (a % 2) comment 'my comment';
show create table t1;
describe t1;
insert into t1 (a) values (1);
select * from t1;
insert into t1 values (2,default);
select a,b from t1;
create table t2 like t1;
show create table t2;
describe t2;
insert into t2 (a) values (1);
select * from t2;
insert into t2 values (2,default);
select a,b from t2;
drop table t2;
drop table t1;
create table t1 (a int, b int as (a % 2) persistent);
show create table t1;
describe t1;
insert into t1 (a) values (1);
select * from t1;
insert into t1 values (2,default);
select a,b from t1;
drop table t1;
create table t2 (a int);
create table t1 (a int, b int as (a % 2) persistent references t2(a));
show create table t1;
drop table t1;
create table t1 (a int, b int as (a % 2));
--error ER_PARSE_ERROR
alter table t1 modify b int as (a % 2) persistent references t2(a);
show create table t1;
drop table t1;
################################################################################
# inc/vcol_dependencies_on_vcol.inc #
# #
# Purpose: #
# Testing scenarios when columns depend on virtual columns, i.e. such as #
# - a virtual column is based on a virtual column #
# - a "real" column on which a virtual one is renamed/dropped #
# - a virtual column involved in partitioning is renamed/dropped #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-02 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--echo # Can't define a virtual column on another virtual column
--error ER_VCOL_BASED_ON_VCOL
create table t1 (a int, b int as (a+1), c int as (b+1));
create table t1 (a int, b int as (a+1));
--error ER_VCOL_BASED_ON_VCOL
alter table t1 add column c int as (b+1);
drop table t1;
--echo # Can't rename or drop a column used in the function of a virtual column
create table t1 (a int, b int as (a+1));
--echo # On renaming/dropping a column on which a virtual field is
--echo # defined the following error is displayed:
--echo # "Unknown column 'a' in 'virtual column function'"
--error ER_BAD_FIELD_ERROR
alter table t1 drop column a;
--error ER_BAD_FIELD_ERROR
alter table t1 change a c int;
drop table t1;
--echo # Can't rename or drop a virtual column used by the paritition function
create table t1 (a int, b int as (a+1)) partition by hash(b);
--error ER_BAD_FIELD_ERROR
alter table t1 drop b;
--error ER_BAD_FIELD_ERROR
alter table t1 change b c int as (a+1);
################################################################################
# inc/vcol_handler.inc #
# #
# Purpose: #
# Testing HANDLER. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
create table t1 (a int,
b int as (-a),
c int as (-a) persistent,
d char(1),
index (a),
index (c));
insert into t1 (a,d) values (4,'a'), (2,'b'), (1,'c'), (3,'d');
select * from t1;
--echo # HANDLER tbl_name OPEN
handler t1 open;
--echo # HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...)
handler t1 read a > (2);
--echo # HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read a > (2) where d='c';
--echo # HANDLER tbl_name READ vcol_index_name = (value1,value2,...)
handler t1 read c = (-2);
--echo # HANDLER tbl_name READ vcol_index_name = (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read c = (-2) where d='c';
--echo # HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read a > (2) where b=-3 && c=-3;
--echo # HANDLER tbl_name READ vcol_index_name <= (value1,value2,...)
handler t1 read c <= (-2);
--echo # HANDLER tbl_name READ vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read c <= (-2) where b=-3;
--echo # HANDLER tbl_name READ vcol_index_name FIRST
handler t1 read c first;
--echo # HANDLER tbl_name READ vcol_index_name NEXT
handler t1 read c next;
--echo # HANDLER tbl_name READ vcol_index_name PREV
handler t1 read c prev;
--echo # HANDLER tbl_name READ vcol_index_name LAST
handler t1 read c last;
--echo # HANDLER tbl_name READ FIRST where non-vcol=expr
handler t1 read FIRST where a >= 2;
--echo # HANDLER tbl_name READ FIRST where vcol=expr
handler t1 read FIRST where b >= -2;
--echo # HANDLER tbl_name READ NEXT where non-vcol=expr
handler t1 read NEXT where d='c';
--echo # HANDLER tbl_name READ NEXT where vcol=expr
handler t1 read NEXT where b<=-4;
--echo # HANDLER tbl_name CLOSE
handler t1 close;
drop table t1;
################################################################################
# inc/vcol_init_vars.pre #
# #
# Purpose: #
# Initialize variables used in t/<name> test cases. #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-08-31 #
# Change Author: #
# Change Date: #
# Change: #
################################################################################
let $skip_full_text_check = 0;
let $skip_spatial_index_check = 0;
################################################################################
# inc/vcol_ins_upd.inc #
# #
# Purpose: #
# Testing DDL operations such as INSERT, UPDATE, REPLACE and DELETE. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
let $create1 = create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
let $create2 = create table t1 (a int unique,
b int as (-a),
c int as (-a) persistent);
let $create3 = create table t1 (a int,
b int as (-a),
c int as (-a) persistent unique);
let $create4 = create table t1 (a int,
b int as (-a),
c int as (-a) persistent unique,
d varchar(16));
eval $create1;
set sql_warnings = 1;
--echo #
--echo # *** INSERT ***
--echo #
--echo # INSERT INTO tbl_name VALUES... DEFAULT is specified against vcols
insert into t1 values (1,default,default);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name VALUES... NULL is specified against vcols
insert into t1 values (1,null,null);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name VALUES... a non-NULL value is specified against vcols
insert into t1 values (1,2,3);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name (<non_vcol_list>) VALUES...
insert into t1 (a) values (1), (2);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name (<normal+vcols>) VALUES... DEFAULT is specified
--echo # against vcols
insert into t1 (a,b) values (1,default), (2,default);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name (<normal+vcols>) VALUES... NULL is specified against vcols
insert into t1 (a,b) values (1,null), (2,null);
select * from t1;
delete from t1;
select * from t1;
--echo # INSERT INTO tbl_name (<normal+vcols>) VALUES... a non-NULL value is specified
--echo # against vcols
insert into t1 (a,b) values (1,3), (2,4);
select * from t1;
delete from t1;
select * from t1;
drop table t1;
--echo # Table with UNIQUE non-vcol field. INSERT INTO tbl_name VALUES... ON DUPLICATE
--echo # KEY UPDATE <non_vcol>=expr, <vcol>=expr
eval $create2;
insert into t1 values (1,default,default);
insert into t1 values (1,default,default)
on duplicate key update a=2, b=default;
select a,b,c from t1;
delete from t1 where b in (1,2);
select * from t1;
drop table t1;
--echo # Table with UNIQUE vcol field. INSERT INTO tbl_name VALUES... ON DUPLICATE
--echo # KEY UPDATE <non_vcol>=expr, <vcol>=expr
eval $create3;
insert into t1 values (1,default,default);
insert into t1 values (1,default,default)
on duplicate key update a=2, b=default;
select a,b,c from t1;
--echo # CREATE new_table ... LIKE old_table
--echo # INSERT INTO new_table SELECT * from old_table
create table t2 like t1;
insert into t2 select * from t1;
select * from t1;
drop table t2;
--echo # CREATE new_table ... LIKE old_table INSERT INTO new_table (<non-vcols>, <vcols>)
--echo # SELECT <non-vcols>, <vcols> from old_table
insert into t1 values (1,default,default);
select * from t1;
create table t2 like t1;
insert into t2 (a,b) select a,b from t1;
select * from t2;
drop table t2;
drop table t1;
--echo #
--echo # *** UPDATE ***
--echo #
--echo # UPDATE tbl_name SET non-vcol=expr WHERE non-vcol=expr
eval $create1;
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set a=3 where a=2;
select * from t1;
delete from t1;
select * from t1;
--echo # UPDATE tbl_name SET vcol=expr WHERE non-vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set c=3 where a=2;
select * from t1;
delete from t1;
select * from t1;
--echo # UPDATE tbl_name SET non-vcol=expr WHERE vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set a=3 where b=-2;
select * from t1;
delete from t1;
select * from t1;
--echo # UPDATE tbl_name SET vcol=expr WHERE vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set c=3 where b=-2;
select * from t1;
delete from t1;
select * from t1;
drop table t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr WHERE vcol=const
eval $create3;
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set a=3 where c=-2;
select * from t1;
delete from t1;
select * from t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr WHERE vcol=between const1 and const2
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set a=3 where c between -3 and -2;
select * from t1;
delete from t1;
select * from t1;
--echo # No INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr WHERE vcol=between const1 and const2
insert into t1 (a) values (1), (2);
select * from t1;
update t1 set a=3 where b between -3 and -2;
select * from t1;
delete from t1;
select * from t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr
--echo # WHERE vcol=between const1 and const2 ORDER BY vcol
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
update t1 set a=6 where c between -1 and 0
order by c;
select * from t1;
delete from t1 where c between -6 and 0;
select * from t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr
--echo # WHERE vcol=between const1 and const2 ORDER BY vcol LIMIT 2
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
update t1 set a=6 where c between -1 and 0
order by c limit 2;
select * from t1;
delete from t1 where c between -2 and 0 order by c;
select * from t1;
delete from t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr
--echo # WHERE indexed vcol=between const1 and const2 and non-indexed vcol=const3
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
update t1 set a=6 where (c between -2 and 0) and (b=-1);
select * from t1;
delete from t1;
--echo # INDEX created on vcol
--echo # UPDATE tbl_name SET non-vcol=expr
--echo # WHERE indexed vcol=between const1 and const2 and non-indexed vcol=const3
--echo # ORDER BY indexed vcol
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
update t1 set a=6 where (c between -2 and 0) and (b=-1) order by c;
select * from t1;
delete from t1;
drop table t1;
let $innodb_engine = `SELECT @@session.storage_engine='innodb'`;
if ($innodb_engine)
{
--echo #
--echo # Verify ON UPDATE/DELETE actions of FOREIGN KEYs
create table t2 (a int primary key, name varchar(10));
create table t1 (a int primary key, b int as (a % 10) persistent);
insert into t2 values (1, 'value1'), (2,'value2'), (3,'value3');
insert into t1 (a) values (1),(2),(3);
select * from t1;
select * from t2;
select t1.a, t1.b, t2.name from t1,t2 where t1.b=t2.a;
--echo # - ON UPDATE RESTRICT
alter table t1 add foreign key (b) references t2(a) on update restrict;
--error ER_NO_REFERENCED_ROW_2
insert into t1 (a) values (4);
--error ER_ROW_IS_REFERENCED_2
update t2 set a=4 where a=3;
select t1.a, t1.b, t2.name from t1,t2 where t1.b=t2.a;
alter table t1 drop foreign key t1_ibfk_1;
--echo # - ON DELETE RESTRICT
alter table t1 add foreign key (b) references t2(a) on delete restrict;
--error ER_ROW_IS_REFERENCED_2
delete from t2 where a=3;
select t1.a, t1.b, t2.name from t1,t2 where t1.b=t2.a;
select t1.a, t1.b, t2.name from t1 left outer join t2 on (t1.b=t2.a);
alter table t1 drop foreign key t1_ibfk_1;
--echo # - ON DELETE CASCADE
alter table t1 add foreign key (b) references t2(a) on delete cascade;
delete from t2 where a=3;
select t1.a, t1.b, t2.name from t1,t2 where t1.b=t2.a;
select t1.a, t1.b, t2.name from t1 left outer join t2 on (t1.b=t2.a);
alter table t1 drop foreign key t1_ibfk_1;
drop table t1;
drop table t2;
}
--echo #
--echo # *** REPLACE ***
--echo #
--echo # UNIQUE INDEX on vcol
--echo # REPLACE tbl_name (non-vcols) VALUES (non-vcols);
eval $create4;
insert into t1 (a,d) values (1,'a'), (2,'b');
select * from t1;
replace t1 (a,d) values (1,'c');
select * from t1;
delete from t1;
select * from t1;
# *** DELETE
# All required tests for DELETE are performed as part of the above testing
# for INSERT, UPDATE and REPLACE.
set sql_warnings = 0;
drop table t1;
################################################################################
# inc/vcol_keys.inc #
# #
# Purpose: #
# Testing keys, indexes defined upon virtual columns. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-02 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--echo # - UNIQUE KEY
--echo # - INDEX
--echo # - FULLTEXT INDEX
--echo # - SPATIAL INDEX (not supported)
--echo # - FOREIGN INDEX (partially supported)
--echo # - CHECK (allowed but not used)
--echo # UNIQUE
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
create table t1 (a int, b int as (a*2) unique);
create table t1 (a int, b int as (a*2) persistent unique);
show create table t1;
describe t1;
drop table t1;
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
create table t1 (a int, b int as (a*2), unique key (b));
create table t1 (a int, b int as (a*2) persistent, unique (b));
show create table t1;
describe t1;
drop table t1;
create table t1 (a int, b int as (a*2));
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
alter table t1 add unique key (b);
drop table t1;
create table t1 (a int, b int as (a*2) persistent);
alter table t1 add unique key (b);
drop table t1;
--echo # Testing data manipulation operations involving UNIQUE keys
--echo # on virtual columns can be found in:
--echo # - vcol_ins_upd.inc
--echo # - vcol_select.inc
--echo #
--echo # INDEX
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
create table t1 (a int, b int as (a*2), index (b));
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
create table t1 (a int, b int as (a*2), index (a,b));
create table t1 (a int, b int as (a*2) persistent, index (b));
show create table t1;
describe t1;
drop table t1;
create table t1 (a int, b int as (a*2) persistent, index (a,b));
show create table t1;
describe t1;
drop table t1;
create table t1 (a int, b int as (a*2));
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
alter table t1 add index (b);
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
alter table t1 add index (a,b);
drop table t1;
create table t1 (a int, b int as (a*2) persistent);
alter table t1 add index (b);
drop table t1;
create table t1 (a int, b int as (a*2) persistent);
alter table t1 add index (a,b);
create table t2 like t1;
drop table t2;
drop table t1;
--echo # Testing data manipulation operations involving INDEX
--echo # on virtual columns can be found in:
--echo # - vcol_select.inc
--echo #
--echo # TODO: FULLTEXT INDEX
--echo # SPATIAL INDEX
if (!$skip_spatial_index_check)
{
--echo # Error "All parts of a SPATIAL index must be NOT NULL"
--error ER_SPATIAL_CANT_HAVE_NULL
create table t1 (a int, b int as (a+1) persistent, spatial index (b));
create table t1 (a int, b int as (a+1) persistent);
--error ER_SPATIAL_CANT_HAVE_NULL
alter table t1 add spatial index (b);
drop table t1;
}
--echo # FOREIGN KEY
--echo # Rejected FK options.
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
create table t1 (a int, b int as (a+1) persistent,
foreign key (b) references t2(a) on update set null);
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
create table t1 (a int, b int as (a+1) persistent,
foreign key (b) references t2(a) on update cascade);
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
create table t1 (a int, b int as (a+1) persistent,
foreign key (b) references t2(a) on delete set null);
create table t1 (a int, b int as (a+1) persistent);
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
alter table t1 add foreign key (b) references t2(a) on update set null;
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
alter table t1 add foreign key (b) references t2(a) on update cascade;
--error ER_WRONG_FK_OPTION_FOR_VIRTUAL_COLUMN
alter table t1 add foreign key (b) references t2(a) on delete set null;
drop table t1;
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
create table t1 (a int, b int as (a+1),
foreign key (b) references t2(a));
create table t1 (a int, b int as (a+1));
--error ER_KEY_BASED_ON_GENERATED_VIRTUAL_COLUMN
alter table t1 add foreign key (b) references t2(a);
drop table t1;
--echo # Allowed FK options.
create table t2 (a int primary key, b char(5));
create table t1 (a int, b int as (a % 10) persistent,
foreign key (b) references t2(a) on update restrict);
drop table t1;
create table t1 (a int, b int as (a % 10) persistent,
foreign key (b) references t2(a) on update no action);
drop table t1;
create table t1 (a int, b int as (a % 10) persistent,
foreign key (b) references t2(a) on delete restrict);
drop table t1;
create table t1 (a int, b int as (a % 10) persistent,
foreign key (b) references t2(a) on delete cascade);
drop table t1;
create table t1 (a int, b int as (a % 10) persistent,
foreign key (b) references t2(a) on delete no action);
drop table t1;
--echo
--echo # Testing data manipulation operations involving FOREIGN KEY
--echo # on virtual columns can be found in:
--echo # - vcol_ins_upd.inc
--echo # - vcol_select.inc
--echo #
--echo # TODO: CHECK
################################################################################
# inc/vcol_non_stored_columns.inc #
# #
# Purpose: #
# Ensure that MySQL behaviour is consistent irrelevant of #
# - the place of a non-stored column among other columns, #
# - the total number of non-stored fields. #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--echo # Case 1. All non-stored columns.
--echo # This scenario is currently impossible due to the fact that virtual columns
--echo # with a constant expression are not allowed.
--echo # Case 2. CREATE
--echo # - Column1: "real"
--echo # - Column 2: virtual non-stored
create table t1 (a int, b int as (-a));
insert into t1 values (1,default);
select * from t1;
insert into t1 values (2,default);
select * from t1;
drop table t1;
--echo # Case 3. CREATE
--echo # - Column1: "real"
--echo # - Column 2: virtual stored
create table t1 (a int, b int as (-a) persistent);
insert into t1 values (1,default);
select * from t1;
insert into t1 values (2,default);
select * from t1;
drop table t1;
--echo # Case 4. CREATE
--echo # - Column1: virtual non-stored
--echo # - Column2: "real"
create table t1 (a int as (-b), b int);
insert into t1 values (default,1);
select * from t1;
insert into t1 values (default,2);
select * from t1;
drop table t1;
--echo # Case 5. CREATE
--echo # - Column1: virtual stored
--echo # - Column2: "real"
create table t1 (a int as (-b) persistent, b int);
insert into t1 values (default,1);
select * from t1;
insert into t1 values (default,2);
select * from t1;
drop table t1;
--echo # Case 6. CREATE
--echo # - Column1: "real"
--echo # - Column2: virtual non-stored
--echo # - Column3: virtual stored
create table t1 (a int, b int as (-a), c int as (-a) persistent);
insert into t1 values (1,default,default);
select * from t1;
insert into t1 values (2,default,default);
select * from t1;
drop table t1;
--echo # Case 7. ALTER. Modify virtual stored -> virtual non-stored
create table t1 (a int, b int as (a % 2) persistent);
--error ER_UNSUPPORTED_ACTION_ON_VIRTUAL_COLUMN
alter table t1 modify b int as (a % 2);
show create table t1;
drop table t1;
--echo # Case 8. ALTER. Modify virtual non-stored -> virtual stored
create table t1 (a int, b int as (a % 2));
--error ER_UNSUPPORTED_ACTION_ON_VIRTUAL_COLUMN
alter table t1 modify b int as (a % 2) persistent;
show create table t1;
drop table t1;
--echo # Case 9. CREATE LIKE
--echo # - Column1: "real"
--echo # - Column2: virtual non-stored
--echo # - Column3: virtual stored
create table t1 (a int, b int as (-a), c int as (-a) persistent);
create table t2 like t1;
insert into t2 values (1,default,default);
select * from t2;
insert into t2 values (2,default,default);
select * from t2;
drop table t2;
drop table t1;
--echo # Case 10. ALTER. Dropping a virtual non-stored column.
--echo # - Column1: virtual non-stored
--echo # - Column2: "real"
create table t1 (a int as (-b), b int, c varchar(5));
insert into t1 values (default,1,'v1');
insert into t1 values (default,2,'v2');
select * from t1;
alter table t1 drop column a;
select * from t1;
show create table t1;
drop table t1;
--echo # Case 11. ALTER. Dropping a virtual stored column.
--echo # - Column1: virtual stored
--echo # - Column2: "real"
create table t1 (a int as (-b) persistent, b int, c char(5));
insert into t1 values (default,1,'v1');
insert into t1 values (default,2,'v2');
select * from t1;
alter table t1 drop column a;
select * from t1;
show create table t1;
drop table t1;
--echo # Case 12. ALTER. Adding a new virtual non-stored column.
create table t1 (a int, b datetime);
insert into t1 values (1,'2008-09-04');
insert into t1 values (2,'2008-09-05');
select * from t1;
alter table t1 add column c int as (dayofyear(b)) after a;
select * from t1;
show create table t1;
drop table t1;
--echo # Case 13. ALTER. Adding a new virtual stored column.
create table t1 (a int, b datetime);
insert into t1 values (1,'2008-09-04');
insert into t1 values (2,'2008-09-05');
select * from t1;
alter table t1 add column c int as (dayofyear(b)) persistent after a;
select * from t1;
show create table t1;
drop table t1;
--echo # Case 14. ALTER. Changing the expression of a virtual stored column.
create table t1 (a int, b datetime, c int as (week(b)) persistent);
insert into t1 values (1,'2008-09-04',default);
insert into t1 values (2,'2008-09-05',default);
select * from t1;
alter table t1 change column c c int as (week(b,1)) persistent;
select * from t1;
show create table t1;
drop table t1;
--echo # Case 15. ALTER. Changing the expression of a virtual non-stored column.
create table t1 (a int, b datetime, c int as (week(b)));
insert into t1 values (1,'2008-09-04',default);
insert into t1 values (2,'2008-09-05',default);
select * from t1;
alter table t1 change column c c int as (week(b,1));
select * from t1;
show create table t1;
drop table t1;
################################################################################
# inc/vcol_partition.inc #
# #
# Purpose: #
# Testing partitioning tables with virtual columns. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--source include/have_partition.inc
--disable_warnings
drop table if exists t1;
--enable_warnings
--echo # Case 1. Partitioning by RANGE based on a non-stored virtual column.
CREATE TABLE t1 (
a DATE NOT NULL,
b int as (year(a))
)
PARTITION BY RANGE( b ) (
PARTITION p0 VALUES LESS THAN (2006),
PARTITION p2 VALUES LESS THAN (2008)
);
insert into t1 values ('2006-01-01',default);
insert into t1 values ('2007-01-01',default);
insert into t1 values ('2005-01-01',default);
select * from t1;
# Specifically for MyISAM, check that data is written into correct
# $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD files
let $myisam_engine = `select @@session.storage_engine='myisam'`;
if ($myisam_engine)
{
--echo # Check how data is physically partitioned.
--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
--exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
}
--echo # Modify the expression of virtual column b
ALTER TABLE t1 modify b int as (year(a)-1);
select * from t1;
if ($myisam_engine)
{
--echo # Check how data is physically partitioned.
--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
--exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
}
drop table t1;
--echo # Case 2. Partitioning by LIST based on a stored virtual column.
CREATE TABLE t1 (a int, b int as (a % 3 ) persistent)
PARTITION BY LIST (a+1)
(PARTITION p1 VALUES IN (1), PARTITION p2 VALUES IN (2));
insert into t1 values (1,default);
if ($myisam_engine)
{
--echo # Check how data is physically partitioned.
--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
--exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
}
select * from t1;
#
# NOTE: The following tests are currently failing due to a
# [suspected] bug in the existing partition functionality.
# Here is what was observed when using mysqld compiled prior
# to adding the virtual column functionality.
# mysql> create table t1 (a int) partition by list (a)
# (partition p1 values in (1), partition p2 values in (2));
# Query OK, 0 rows affected (0.00 sec)
#
# mysql> insert into t1 values (1), (1), (2);
# Query OK, 3 rows affected (0.00 sec)
# Records: 3 Duplicates: 0 Warnings: 0
#
# mysql> select * from t1;
# +------+
# | a |
# +------+
# | 1 |
# | 1 |
# | 2 |
# +------+
# 3 rows in set (0.00 sec)
#
# mysql> alter table t1 reorganize partition p1 into
# (partition p1 values in (3));
# Query OK, 2 rows affected (3.90 sec)
# Records: 2 Duplicates: 2 Warnings: 0
#
# mysql> select * from t1;
# +------+
# | a |
# +------+
# | 2 | <- Two row have been lost!!!
# +------+
# 1 row in set (0.00 sec)
#
#alter table t1 change b b int as ((a % 3)+1) persistent;
#--error ER_NO_PARTITION_FOR_GIVEN_VALUE
#alter table t1 change b b int as (a % 2) persistent;
#if ($myisam_engine)
#{
# --echo # Check how data is physically partitioned.
# --replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
# --exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
#}
select * from t1;
drop table t1;
--echo # Case 3. Partitioning by HASH based on a non-stored virtual column.
CREATE TABLE t1 (
a DATE NOT NULL,
b int as (year(a))
)
PARTITION BY HASH( b % 3 ) PARTITIONS 3;
insert into t1 values ('2005-01-01',default);
insert into t1 values ('2006-01-01',default);
select * from t1;
if ($myisam_engine)
{
--echo # Check how data is physically partitioned.
--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
--exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
}
--echo # Modify the expression of virtual column b
ALTER TABLE t1 modify b int as (year(a)-1);
select * from t1;
if ($myisam_engine)
{
--echo # Check how data is physically partitioned.
--replace_result $MYSQLTEST_VARDIR MYSQLTEST_VARDIR
--exec du -b $MYSQLTEST_VARDIR/mysqld.1/data/test/t1*p?.MYD
}
drop table t1;
################################################################################
# inc/vcol_select.inc #
# #
# Purpose: #
# Testing different SELECTs. #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-18 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
# Table t1 is used below to test:
# - Join type of ALL (sequential scan of the entire table)
# - Join type of Index
# - Join type of Range
# - Join type of Ref_or_null
create table t1 (a int,
b int as (-a),
c int as (-a) persistent,
index (c));
insert into t1 (a) values (2), (1), (1), (3), (NULL);
# Table t2 is used below to test:
# - Join type of system and const
create table t2 like t1;
insert into t2 (a) values (1);
# Table t3 is used below to test
# - Join type of Eq_ref with a unique virtual column
# - Join type of Const
create table t3 (a int primary key,
b int as (-a),
c int as (-a) persistent unique);
insert into t3 (a) values (2),(1),(3);
--echo # select_type=SIMPLE, type=system
let $s = select * from t2;
eval $s;
eval explain $s;
let $s = select * from t2 where c=-1;
eval $s;
eval explain $s;
--echo # select_type=SIMPLE, type=ALL
let $s = select * from t1 where b=-1;
eval $s;
eval explain $s;
--echo # select_type=SIMPLE, type=const
let $s = select * from t3 where a=1;
eval $s;
eval explain $s;
--echo # select_type=SIMPLE, type=range
let $s = select * from t3 where c>=-1;
eval $s;
eval explain $s;
--echo # select_type=SIMPLE, type=ref
let $s = select * from t1,t3 where t1.c=t3.c and t3.c=-1;
eval $s;
eval explain $s;
--echo # select_type=PRIMARY, type=index,ALL
let $s = select * from t1 where b in (select c from t3);
eval $s;
eval explain $s;
--echo # select_type=PRIMARY, type=range,ref
let $s = select * from t1 where c in (select c from t3 where c between -2 and -1);
eval $s;
eval explain $s;
--echo # select_type=UNION, type=system
--echo # select_type=UNION RESULT, type=<union1,2>
let $s = select * from t1 union select * from t2;
eval $s;
eval explain $s;
--echo # select_type=DERIVED, type=system
let $s = select * from (select a,b,c from t1) as t11;
eval $s;
eval explain $s;
--echo ###
--echo ### Using aggregate functions with/without DISTINCT
--echo ###
--echo # SELECT COUNT(*) FROM tbl_name
let $s = select count(*) from t1;
eval $s;
eval explain $s;
--echo # SELECT COUNT(DISTINCT <non-vcol>) FROM tbl_name
let $s = select count(distinct a) from t1;
eval $s;
eval explain $s;
--echo # SELECT COUNT(DISTINCT <non-stored vcol>) FROM tbl_name
let $s = select count(distinct b) from t1;
eval $s;
eval explain $s;
--echo # SELECT COUNT(DISTINCT <stored vcol>) FROM tbl_name
let $s = select count(distinct c) from t1;
eval $s;
eval explain $s;
--echo ###
--echo ### filesort & range-based utils
--echo ###
--echo # SELECT * FROM tbl_name WHERE <vcol expr>
let $s = select * from t3 where c >= -2;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <non-vcol expr>
let $s = select * from t3 where a between 1 and 2;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <non-indexed vcol expr>
let $s = select * from t3 where b between -2 and -1;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <indexed vcol expr>
let $s = select * from t3 where c between -2 and -1;
eval $s;
eval explain $s;
#### Remove for MyISAM due to a bug
#### when all the three records are returned (a=1,2,3)
#### instead of just two (a=1,2).
#### This bug is presumably in base SQL routines as the same happens
#### with this table:
#### create table t4 (a int primary key, b int, c int unique);
let $myisam_engine = `SELECT @@session.storage_engine='myisam'`;
if (!$myisam_engine)
{
--echo # SELECT * FROM tbl_name WHERE <non-vcol expr> ORDER BY <non-indexed vcol>
let $s = select * from t3 where a between 1 and 2 order by b;
eval $s;
eval explain $s;
}
--echo # SELECT * FROM tbl_name WHERE <non-vcol expr> ORDER BY <indexed vcol>
let $s = select * from t3 where a between 1 and 2 order by c;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <non-vcol>
let $s = select * from t3 where b between -2 and -1 order by a;
eval $s;
eval explain $s;
#### Remove for MyISAM due to a bug
#### when all the three records are returned (a=1,2,3)
#### instead of just two (a=1,2).
#### This bug is presumably in base SQL routines as the same happens
#### with this table:
#### create table t4 (a int primary key, b int, c int unique);
let $innodb_engine = `SELECT @@session.storage_engine='innodb'`;
if (!$innodb_engine)
{
--echo # SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <non-vcol>
let $s = select * from t3 where c between -2 and -1 order by a;
eval $s;
eval explain $s;
}
--echo # SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <non-indexed vcol>
let $s = select * from t3 where b between -2 and -1 order by b;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <non-indexed vcol>
let $s = select * from t3 where c between -2 and -1 order by b;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <non-indexed vcol expr> ORDER BY <indexed vcol>
let $s = select * from t3 where b between -2 and -1 order by c;
eval $s;
eval explain $s;
--echo # SELECT * FROM tbl_name WHERE <indexed vcol expr> ORDER BY <indexed vcol>
let $s = select * from t3 where c between -2 and -1 order by c;
eval $s;
eval explain $s;
--echo # SELECT sum(<non-indexed vcol>) FROM tbl_name GROUP BY <non-indexed vcol>
let $s = select sum(b) from t1 group by b;
eval $s;
eval explain $s;
--echo # SELECT sum(<indexed vcol>) FROM tbl_name GROUP BY <indexed vcol>
let $s = select sum(c) from t1 group by c;
eval $s;
eval explain $s;
--echo # SELECT sum(<non-indexed vcol>) FROM tbl_name GROUP BY <indexed vcol>
let $s = select sum(b) from t1 group by c;
eval $s;
eval explain $s;
--echo # SELECT sum(<indexed vcol>) FROM tbl_name GROUP BY <non-indexed vcol>
let $s = select sum(c) from t1 group by b;
eval $s;
eval explain $s;
################################################################################
# inc/vcol_supported_sql_funcs.inc #
# #
# Purpose: #
# Tests frame for allowed sql functions #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-08-31 #
# Change Author: #
# Change Date: #
# Change: #
################################################################################
--enable_warnings
set sql_warnings = 1;
eval create table t1 ($cols);
show create table t1;
if ($rows)
{
eval insert into t1 values ($values1);
dec $rows;
}
if ($rows)
{
eval insert into t1 values ($values2);
dec $rows;
}
if ($rows)
{
eval insert into t1 values ($values3);
dec $rows;
}
if ($rows)
{
eval insert into t1 values ($values4);
dec $rows;
}
select * from t1;
drop table t1;
set sql_warnings = 0;
This diff is collapsed.
################################################################################
# inc/vcol_trigger_sp.inc #
# #
# Purpose: #
# Testing triggers, stored procedures and functions #
# defined on tables with virtual columns. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
create table t1 (a int,
b int as (a/10),
c int as (a/10) persistent);
create table t2 (a timestamp);
delimiter |;
create trigger trg1 before insert on t1 for each row
begin
if (new.b < 10) then
set new.a:= 100;
set new.b:= 9;
set new.c:= 9;
end if;
if (new.c > 50) then
set new.a:= 500;
end if;
end|
create trigger trg2 after insert on t1 for each row
begin
if (new.b >= 60) then
insert into t2 values (now());
end if;
end|
create function f1()
returns int
begin
declare sum1 int default '0';
declare cur1 cursor for select sum(b) from t1;
open cur1;
fetch cur1 into sum1;
close cur1;
return sum1;
end|
delimiter ;|
set sql_warnings = 1;
insert into t1 (a) values (200);
select * from t1;
select * from t2;
insert into t1 (a) values (10);
select * from t1;
select * from t2;
insert into t1 (a) values (600);
select * from t1;
--replace_column 1 <timestamp>
select * from t2;
select f1();
set sql_warnings = 0;
drop trigger trg1;
drop trigger trg2;
drop table t2;
delimiter |;
create procedure p1()
begin
declare i int default '0';
create table t2 like t1;
insert into t2 (a) values (100), (200);
begin
declare cur1 cursor for select sum(c) from t2;
open cur1;
fetch cur1 into i;
close cur1;
if (i=30) then
insert into t1 values (300,default,default);
end if;
end;
end|
delimiter ;|
delete from t1;
call p1();
select * from t2;
select * from t1;
drop table t1,t2;
drop procedure p1;
################################################################################
# inc/vcol_unsupported_storage_engines.inc #
# #
# Purpose: #
# Ensure that defining a virtual column for an unsupported table type #
# results in a graceful error. #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-02 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
--error ER_UNSUPPORTED_ACTION_ON_VIRTUAL_COLUMN
create table t1 (a int, b int as (a+1));
create table t1 (a int);
--error ER_UNSUPPORTED_ACTION_ON_VIRTUAL_COLUMN
alter table t1 add column b int as (a+1);
drop table t1;
################################################################################
# inc/vcol_view.inc #
# #
# Purpose: #
# Testing views defined on tables with virtual columns. #
# #
# #
# #
#------------------------------------------------------------------------------#
# Original Author: Andrey Zhakov #
# Original Date: 2008-09-04 #
# Change Author: Oleksandr Byelkin (Monty program Ab)
# Date: 2009-03-24
# Change: Syntax changed
################################################################################
create table t1 (a int not null,
b int as (-a),
c int as (-a) persistent);
insert into t1 (a) values (1), (1), (2), (2), (3);
# simple view
create view v1 (d,e) as select abs(b), abs(c) from t1;
select d,e from v1;
select is_updatable from information_schema.views where table_name='v1';
# view with different algorithms (explain output differs)
explain extended select d,e from v1;
create algorithm=temptable view v2 (d,e) as select abs(b), abs(c) from t1;
show create view v2;
select d,e from v2;
explain extended select d,e from v2;
# VIEW on VIEW test
create view v3 (d,e) as select d*2, e*2 from v1;
select * from v3;
explain extended select * from v3;
drop view v1,v2,v3;
drop table t1;
#
# DISTINCT option for VIEW
#
create table t1 (a int not null,
b int as (-a),
c int as (-a) persistent);
insert into t1 (a) values (1), (2), (3), (1), (2), (3);
create view v1 as select distinct b from t1;
select * from v1;
explain select * from v1;
select * from t1;
drop view v1;
create view v1 as select distinct c from t1;
select * from v1;
explain select * from v1;
select * from t1;
drop view v1;
drop table t1;
#
# LIMIT clause test
#
create table t1 (a int not null,
b int as (-a),
c int as (-a) persistent);
insert into t1 (a) values (1), (2), (3), (4);
create view v1 as select b+1 from t1 order by 1 desc limit 2;
select * from v1;
explain select * from v1;
drop view v1;
create view v1 as select c+1 from t1 order by 1 desc limit 2;
select * from v1;
explain select * from v1;
drop view v1;
drop table t1;
#
# simple view + simple update, insert and delete
#
create table t1 (a int,
b int,
c int as (-a),
d int as (-a) persistent,
primary key(a));
insert into t1 (a,b) values (10,2), (20,3), (30,4), (40,5), (50,10);
create view v1 (a,e,f,g) as select a, b+1,c+1,d+1 from t1;
# updatable field of updateable view
update v1 set a=a+e;
select * from v1;
select * from t1;
delete from v1;
select * from v1;
select * from t1;
--error ER_NON_INSERTABLE_TABLE
insert into v1 (a,e) values (60,15);
drop table t1;
drop view v1;
#
# outer join based on VIEW with WHERE clause
#
create table t1 (a int,
b int as (-a),
c int as (-a) persistent,
primary key(a));
insert into t1 (a) values (1), (2), (3);
create view v1 (x,y,z) as select a,b,c from t1 where b < -1;
select t1.a, v1.x, v1.y, v1.z from t1 left join v1 on (t1.b= v1.y);
drop view v1;
create view v1 (x,y,z) as select a,b,c from t1 where c < -1;
select t1.a, v1.x, v1.y, v1.z from t1 left join v1 on (t1.c= v1.z);
drop view v1;
drop table t1;
#
# VIEW built over UNION
#
create table t1 (a1 int,
b1 int as (-a1),
c1 int as (-a1) persistent);
create table t2 (a2 int,
b2 int as (-a2),
c2 int as (-a2) persistent);
insert into t1 (a1) values (1), (2);
insert into t2 (a2) values (2), (3);
create view v1 as select * from t1,t2 union all select * from t1,t2;
select * from v1;
drop view v1;
drop table t1, t2;
#
# Showing VIEW with VIEWs in subquery
#
create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
create table t2 like t1;
create view v1 as select a,b,c from t1;
create view v2 as select a,b,c from t2 where b in (select b from v1);
show create view v2;
drop view v2, v1;
drop table t1, t2;
#
# TODO: VIEW with full text
#
#CREATE TABLE t1 (c1 int not null auto_increment primary key, c2 varchar(20), fulltext(c2));
#insert into t1 (c2) VALUES ('real Beer'),('Water'),('Kossu'),('Coca-Cola'),('Vodka'),('Wine'),('almost real Beer');
#select * from t1 WHERE match (c2) against ('Beer');
#CREATE VIEW v1 AS SELECT * from t1 WHERE match (c2) against ('Beer');
#select * from v1;
#drop view v1;
#drop table t1;
#
# distinct in temporary table with a VIEW
#
create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
insert into t1 (a) values (1),(1),(2),(2),(3),(3);
create view v1 as select b from t1;
select distinct b from v1;
select distinct b from v1 limit 2;
select distinct b from t1 limit 2;
prepare stmt1 from "select distinct b from v1 limit 2";
execute stmt1;
execute stmt1;
deallocate prepare stmt1;
drop view v1;
create view v1 as select c from t1;
select distinct c from v1;
select distinct c from v1 limit 2;
select distinct c from t1 limit 2;
prepare stmt1 from "select distinct c from v1 limit 2";
execute stmt1;
execute stmt1;
deallocate prepare stmt1;
drop view v1;
drop table t1;
#
# WITH CHECK OPTION insert/update test
#
create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
create view v1 as select * from t1 where b > -2 && c >-2 with check option;
# simple insert
insert into v1 (a) values (1);
-- error 1369
insert into v1 (a) values (3);
# simple insert with ignore
insert ignore into v1 (a) values (2),(3),(0);
select * from t1;
drop view v1;
drop table t1;
SET @@session.storage_engine = 'InnoDB';
stop slave;
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9;
reset master;
reset slave;
drop table if exists t1,t2,t3,t4,t5,t6,t7,t8,t9;
start slave;
create table t1 (a int, b int as (a+1));
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a+1) VIRTUAL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
insert into t1 values (1,default);
insert into t1 values (2,default);
select * from t1;
a b
1 2
2 3
select * from t1;
a b
1 2
2 3
drop table t1;
SET @@session.storage_engine = 'archive';
create table t1 (a int, b int as (a+1));
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
create table t1 (a int);
alter table t1 add column b int as (a+1);
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
drop table t1;
SET @@session.storage_engine = 'blackhole';
create table t1 (a int, b int as (a+1));
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
create table t1 (a int);
alter table t1 add column b int as (a+1);
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
drop table t1;
This diff is collapsed.
This diff is collapsed.
SET @@session.storage_engine = 'InnoDB';
#
# Section 1. Wrong column definition options
# - NOT NULL
# - NULL
# - DEFAULT <value>
# - AUTO_INCREMENT
# - [PRIMARY] KEY
# NOT NULL
create table t1 (a int, b int as (a+1) not null);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'not null)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) not null;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'not null' at line 1
drop table t1;
# NULL
create table t1 (a int, b int as (a+1) null);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'null)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) null;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'null' at line 1
drop table t1;
# DEFAULT
create table t1 (a int, b int as (a+1) default 0);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'default 0)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) default 0;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'default 0' at line 1
drop table t1;
# AUTO_INCREMENT
create table t1 (a int, b int as (a+1) AUTO_INCREMENT);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'AUTO_INCREMENT)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) AUTO_INCREMENT;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'AUTO_INCREMENT' at line 1
drop table t1;
# [PRIMARY] KEY
create table t1 (a int, b int as (a+1) key);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'key)' at line 1
create table t1 (a int, b int as (a+1) primary key);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'primary key)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) key;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'key' at line 1
alter table t1 add column b int as (a+1) primary key;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'primary key' at line 1
drop table t1;
# Section 2. Other column definition options
# - COMMENT
# - REFERENCES (only syntax testing here)
# - STORED (only systax testing here)
create table t1 (a int, b int as (a % 2) comment 'my comment');
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=InnoDB DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
drop table t1;
create table t1 (a int, b int as (a % 2));
alter table t1 modify b int as (a % 2) comment 'my comment';
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=InnoDB DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t1 (a) values (1);
select * from t1;
a b
1 1
insert into t1 values (2,default);
select a,b from t1;
a b
1 1
2 0
create table t2 like t1;
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=InnoDB DEFAULT CHARSET=latin1
describe t2;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t2 (a) values (1);
select * from t2;
a b
1 1
insert into t2 values (2,default);
select a,b from t2;
a b
1 1
2 0
drop table t2;
drop table t1;
create table t1 (a int, b int as (a % 2) persistent);
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) PERSISTENT
) ENGINE=InnoDB DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t1 (a) values (1);
select * from t1;
a b
1 1
insert into t1 values (2,default);
select a,b from t1;
a b
1 1
2 0
drop table t1;
create table t2 (a int);
create table t1 (a int, b int as (a % 2) persistent references t2(a));
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) PERSISTENT
) ENGINE=InnoDB DEFAULT CHARSET=latin1
drop table t1;
create table t1 (a int, b int as (a % 2));
alter table t1 modify b int as (a % 2) persistent references t2(a);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'references t2(a)' at line 1
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL
) ENGINE=InnoDB DEFAULT CHARSET=latin1
drop table t1;
SET @@session.storage_engine = 'MyISAM';
#
# Section 1. Wrong column definition options
# - NOT NULL
# - NULL
# - DEFAULT <value>
# - AUTO_INCREMENT
# - [PRIMARY] KEY
# NOT NULL
create table t1 (a int, b int as (a+1) not null);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'not null)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) not null;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'not null' at line 1
drop table t1;
# NULL
create table t1 (a int, b int as (a+1) null);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'null)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) null;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'null' at line 1
drop table t1;
# DEFAULT
create table t1 (a int, b int as (a+1) default 0);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'default 0)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) default 0;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'default 0' at line 1
drop table t1;
# AUTO_INCREMENT
create table t1 (a int, b int as (a+1) AUTO_INCREMENT);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'AUTO_INCREMENT)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) AUTO_INCREMENT;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'AUTO_INCREMENT' at line 1
drop table t1;
# [PRIMARY] KEY
create table t1 (a int, b int as (a+1) key);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'key)' at line 1
create table t1 (a int, b int as (a+1) primary key);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'primary key)' at line 1
create table t1 (a int);
alter table t1 add column b int as (a+1) key;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'key' at line 1
alter table t1 add column b int as (a+1) primary key;
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'primary key' at line 1
drop table t1;
# Section 2. Other column definition options
# - COMMENT
# - REFERENCES (only syntax testing here)
# - STORED (only systax testing here)
create table t1 (a int, b int as (a % 2) comment 'my comment');
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=MyISAM DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
drop table t1;
create table t1 (a int, b int as (a % 2));
alter table t1 modify b int as (a % 2) comment 'my comment';
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=MyISAM DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t1 (a) values (1);
select * from t1;
a b
1 1
insert into t1 values (2,default);
select a,b from t1;
a b
1 1
2 0
create table t2 like t1;
show create table t2;
Table Create Table
t2 CREATE TABLE `t2` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL COMMENT 'my comment'
) ENGINE=MyISAM DEFAULT CHARSET=latin1
describe t2;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t2 (a) values (1);
select * from t2;
a b
1 1
insert into t2 values (2,default);
select a,b from t2;
a b
1 1
2 0
drop table t2;
drop table t1;
create table t1 (a int, b int as (a % 2) persistent);
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) PERSISTENT
) ENGINE=MyISAM DEFAULT CHARSET=latin1
describe t1;
Field Type Null Key Default Extra
a int(11) YES NULL
b int(11) YES NULL VIRTUAL
insert into t1 (a) values (1);
select * from t1;
a b
1 1
insert into t1 values (2,default);
select a,b from t1;
a b
1 1
2 0
drop table t1;
create table t2 (a int);
create table t1 (a int, b int as (a % 2) persistent references t2(a));
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) PERSISTENT
) ENGINE=MyISAM DEFAULT CHARSET=latin1
drop table t1;
create table t1 (a int, b int as (a % 2));
alter table t1 modify b int as (a % 2) persistent references t2(a);
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near 'references t2(a)' at line 1
show create table t1;
Table Create Table
t1 CREATE TABLE `t1` (
`a` int(11) DEFAULT NULL,
`b` int(11) AS (a % 2) VIRTUAL
) ENGINE=MyISAM DEFAULT CHARSET=latin1
drop table t1;
SET @@session.storage_engine = 'CSV';
create table t1 (a int, b int as (a+1));
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
create table t1 (a int not null);
alter table t1 add column b int as (a+1);
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
drop table t1;
SET @@session.storage_engine = 'InnoDB';
create table t1 (a int,
b int as (-a),
c int as (-a) persistent,
d char(1),
index (a),
index (c));
insert into t1 (a,d) values (4,'a'), (2,'b'), (1,'c'), (3,'d');
select * from t1;
a b c d
4 -4 -4 a
2 -2 -2 b
1 -1 -1 c
3 -3 -3 d
# HANDLER tbl_name OPEN
handler t1 open;
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...)
handler t1 read a > (2);
a b c d
3 -3 -3 d
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read a > (2) where d='c';
a b c d
# HANDLER tbl_name READ vcol_index_name = (value1,value2,...)
handler t1 read c = (-2);
a b c d
2 -2 -2 b
# HANDLER tbl_name READ vcol_index_name = (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read c = (-2) where d='c';
a b c d
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read a > (2) where b=-3 && c=-3;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name <= (value1,value2,...)
handler t1 read c <= (-2);
a b c d
2 -2 -2 b
# HANDLER tbl_name READ vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read c <= (-2) where b=-3;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name FIRST
handler t1 read c first;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ vcol_index_name NEXT
handler t1 read c next;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name PREV
handler t1 read c prev;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ vcol_index_name LAST
handler t1 read c last;
a b c d
1 -1 -1 c
# HANDLER tbl_name READ FIRST where non-vcol=expr
handler t1 read FIRST where a >= 2;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ FIRST where vcol=expr
handler t1 read FIRST where b >= -2;
a b c d
2 -2 -2 b
# HANDLER tbl_name READ NEXT where non-vcol=expr
handler t1 read NEXT where d='c';
a b c d
1 -1 -1 c
# HANDLER tbl_name READ NEXT where vcol=expr
handler t1 read NEXT where b<=-4;
a b c d
# HANDLER tbl_name CLOSE
handler t1 close;
drop table t1;
SET @@session.storage_engine = 'MyISAM';
create table t1 (a int,
b int as (-a),
c int as (-a) persistent,
d char(1),
index (a),
index (c));
insert into t1 (a,d) values (4,'a'), (2,'b'), (1,'c'), (3,'d');
select * from t1;
a b c d
4 -4 -4 a
2 -2 -2 b
1 -1 -1 c
3 -3 -3 d
# HANDLER tbl_name OPEN
handler t1 open;
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...)
handler t1 read a > (2);
a b c d
3 -3 -3 d
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read a > (2) where d='c';
a b c d
# HANDLER tbl_name READ vcol_index_name = (value1,value2,...)
handler t1 read c = (-2);
a b c d
2 -2 -2 b
# HANDLER tbl_name READ vcol_index_name = (value1,value2,...) WHERE non-vcol_field=expr
handler t1 read c = (-2) where d='c';
a b c d
# HANDLER tbl_name READ non-vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read a > (2) where b=-3 && c=-3;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name <= (value1,value2,...)
handler t1 read c <= (-2);
a b c d
2 -2 -2 b
# HANDLER tbl_name READ vcol_index_name > (value1,value2,...) WHERE vcol_field=expr
handler t1 read c <= (-2) where b=-3;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name FIRST
handler t1 read c first;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ vcol_index_name NEXT
handler t1 read c next;
a b c d
3 -3 -3 d
# HANDLER tbl_name READ vcol_index_name PREV
handler t1 read c prev;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ vcol_index_name LAST
handler t1 read c last;
a b c d
1 -1 -1 c
# HANDLER tbl_name READ FIRST where non-vcol=expr
handler t1 read FIRST where a >= 2;
a b c d
4 -4 -4 a
# HANDLER tbl_name READ FIRST where vcol=expr
handler t1 read FIRST where b >= -2;
a b c d
2 -2 -2 b
# HANDLER tbl_name READ NEXT where non-vcol=expr
handler t1 read NEXT where d='c';
a b c d
1 -1 -1 c
# HANDLER tbl_name READ NEXT where vcol=expr
handler t1 read NEXT where b<=-4;
a b c d
# HANDLER tbl_name CLOSE
handler t1 close;
drop table t1;
This diff is collapsed.
SET @@session.storage_engine = 'MyISAM';
create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
set sql_warnings = 1;
#
# *** INSERT ***
#
# INSERT INTO tbl_name VALUES... DEFAULT is specified against vcols
insert into t1 values (1,default,default);
select * from t1;
a b c
1 -1 -1
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name VALUES... NULL is specified against vcols
insert into t1 values (1,null,null);
select * from t1;
a b c
1 -1 -1
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name VALUES... a non-NULL value is specified against vcols
insert into t1 values (1,2,3);
Warnings:
Warning 1645 The value specified for computed column 'b' in table 't1' ignored.
Warning 1645 The value specified for computed column 'c' in table 't1' ignored.
select * from t1;
a b c
1 -1 -1
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name (<non_vcol_list>) VALUES...
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name (<normal+vcols>) VALUES... DEFAULT is specified
# against vcols
insert into t1 (a,b) values (1,default), (2,default);
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name (<normal+vcols>) VALUES... NULL is specified against vcols
insert into t1 (a,b) values (1,null), (2,null);
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
# INSERT INTO tbl_name (<normal+vcols>) VALUES... a non-NULL value is specified
# against vcols
insert into t1 (a,b) values (1,3), (2,4);
Warnings:
Warning 1645 The value specified for computed column 'b' in table 't1' ignored.
Warning 1645 The value specified for computed column 'b' in table 't1' ignored.
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
drop table t1;
# Table with UNIQUE non-vcol field. INSERT INTO tbl_name VALUES... ON DUPLICATE
# KEY UPDATE <non_vcol>=expr, <vcol>=expr
create table t1 (a int unique,
b int as (-a),
c int as (-a) persistent);
insert into t1 values (1,default,default);
insert into t1 values (1,default,default)
on duplicate key update a=2, b=default;
select a,b,c from t1;
a b c
2 -2 -2
delete from t1 where b in (1,2);
select * from t1;
a b c
2 -2 -2
drop table t1;
# Table with UNIQUE vcol field. INSERT INTO tbl_name VALUES... ON DUPLICATE
# KEY UPDATE <non_vcol>=expr, <vcol>=expr
create table t1 (a int,
b int as (-a),
c int as (-a) persistent unique);
insert into t1 values (1,default,default);
insert into t1 values (1,default,default)
on duplicate key update a=2, b=default;
select a,b,c from t1;
a b c
2 -2 -2
# CREATE new_table ... LIKE old_table
# INSERT INTO new_table SELECT * from old_table
create table t2 like t1;
insert into t2 select * from t1;
Warnings:
Warning 1645 The value specified for computed column 'b' in table 't2' ignored.
Warning 1645 The value specified for computed column 'c' in table 't2' ignored.
select * from t1;
a b c
2 -2 -2
drop table t2;
# CREATE new_table ... LIKE old_table INSERT INTO new_table (<non-vcols>, <vcols>)
# SELECT <non-vcols>, <vcols> from old_table
insert into t1 values (1,default,default);
select * from t1;
a b c
2 -2 -2
1 -1 -1
create table t2 like t1;
insert into t2 (a,b) select a,b from t1;
Warnings:
Warning 1645 The value specified for computed column 'b' in table 't2' ignored.
Warning 1645 The value specified for computed column 'b' in table 't2' ignored.
select * from t2;
a b c
2 -2 -2
1 -1 -1
drop table t2;
drop table t1;
#
# *** UPDATE ***
#
# UPDATE tbl_name SET non-vcol=expr WHERE non-vcol=expr
create table t1 (a int,
b int as (-a),
c int as (-a) persistent);
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set a=3 where a=2;
select * from t1;
a b c
1 -1 -1
3 -3 -3
delete from t1;
select * from t1;
a b c
# UPDATE tbl_name SET vcol=expr WHERE non-vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set c=3 where a=2;
Warnings:
Warning 1645 The value specified for computed column 'c' in table 't1' ignored.
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
# UPDATE tbl_name SET non-vcol=expr WHERE vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set a=3 where b=-2;
select * from t1;
a b c
1 -1 -1
3 -3 -3
delete from t1;
select * from t1;
a b c
# UPDATE tbl_name SET vcol=expr WHERE vcol=expr
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set c=3 where b=-2;
Warnings:
Warning 1645 The value specified for computed column 'c' in table 't1' ignored.
select * from t1;
a b c
1 -1 -1
2 -2 -2
delete from t1;
select * from t1;
a b c
drop table t1;
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr WHERE vcol=const
create table t1 (a int,
b int as (-a),
c int as (-a) persistent unique);
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set a=3 where c=-2;
select * from t1;
a b c
1 -1 -1
3 -3 -3
delete from t1;
select * from t1;
a b c
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr WHERE vcol=between const1 and const2
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set a=3 where c between -3 and -2;
select * from t1;
a b c
1 -1 -1
3 -3 -3
delete from t1;
select * from t1;
a b c
# No INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr WHERE vcol=between const1 and const2
insert into t1 (a) values (1), (2);
select * from t1;
a b c
1 -1 -1
2 -2 -2
update t1 set a=3 where b between -3 and -2;
select * from t1;
a b c
1 -1 -1
3 -3 -3
delete from t1;
select * from t1;
a b c
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr
# WHERE vcol=between const1 and const2 ORDER BY vcol
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
a b c
1 -1 -1
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
update t1 set a=6 where c between -1 and 0
order by c;
select * from t1;
a b c
6 -6 -6
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
delete from t1 where c between -6 and 0;
select * from t1;
a b c
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr
# WHERE vcol=between const1 and const2 ORDER BY vcol LIMIT 2
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
a b c
5 -5 -5
4 -4 -4
3 -3 -3
2 -2 -2
1 -1 -1
update t1 set a=6 where c between -1 and 0
order by c limit 2;
select * from t1;
a b c
5 -5 -5
4 -4 -4
3 -3 -3
2 -2 -2
6 -6 -6
delete from t1 where c between -2 and 0 order by c;
select * from t1;
a b c
5 -5 -5
4 -4 -4
3 -3 -3
6 -6 -6
delete from t1;
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr
# WHERE indexed vcol=between const1 and const2 and non-indexed vcol=const3
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
a b c
1 -1 -1
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
update t1 set a=6 where (c between -2 and 0) and (b=-1);
select * from t1;
a b c
6 -6 -6
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
delete from t1;
# INDEX created on vcol
# UPDATE tbl_name SET non-vcol=expr
# WHERE indexed vcol=between const1 and const2 and non-indexed vcol=const3
# ORDER BY indexed vcol
insert into t1 (a) values (1), (2), (3), (4), (5);
select * from t1;
a b c
1 -1 -1
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
update t1 set a=6 where (c between -2 and 0) and (b=-1) order by c;
select * from t1;
a b c
6 -6 -6
2 -2 -2
3 -3 -3
4 -4 -4
5 -5 -5
delete from t1;
drop table t1;
#
# *** REPLACE ***
#
# UNIQUE INDEX on vcol
# REPLACE tbl_name (non-vcols) VALUES (non-vcols);
create table t1 (a int,
b int as (-a),
c int as (-a) persistent unique,
d varchar(16));
insert into t1 (a,d) values (1,'a'), (2,'b');
select * from t1;
a b c d
1 -1 -1 a
2 -2 -2 b
replace t1 (a,d) values (1,'c');
select * from t1;
a b c d
1 -1 -1 c
2 -2 -2 b
delete from t1;
select * from t1;
a b c d
set sql_warnings = 0;
drop table t1;
This diff is collapsed.
This diff is collapsed.
SET @@session.storage_engine = 'memory';
create table t1 (a int, b int as (a+1));
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
create table t1 (a int);
alter table t1 add column b int as (a+1);
ERROR HY000: 'Specified storage engine' is not yet supported for computed columns.
drop table t1;
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
This diff is collapsed.
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