mirror of
https://github.com/MariaDB/server.git
synced 2025-01-19 05:22:25 +01:00
17a87d6063
Working features: CREATE OR REPLACE [TEMPORARY] SEQUENCE [IF NOT EXISTS] name [ INCREMENT [ BY | = ] increment ] [ MINVALUE [=] minvalue | NO MINVALUE ] [ MAXVALUE [=] maxvalue | NO MAXVALUE ] [ START [ WITH | = ] start ] [ CACHE [=] cache ] [ [ NO ] CYCLE ] ENGINE=xxx COMMENT=".." SELECT NEXT VALUE FOR sequence_name; SELECT NEXTVAL(sequence_name); SELECT PREVIOUS VALUE FOR sequence_name; SELECT LASTVAL(sequence_name); SHOW CREATE SEQUENCE sequence_name; SHOW CREATE TABLE sequence_name; CREATE TABLE sequence-structure ... SEQUENCE=1 ALTER TABLE sequence RENAME TO sequence2; RENAME TABLE sequence TO sequence2; DROP [TEMPORARY] SEQUENCE [IF EXISTS] sequence_names Missing features - SETVAL(value,sequence_name), to be used with replication. - Check replication, including checking that sequence tables are marked not transactional. - Check that a commit happens for NEXT VALUE that changes table data (may already work) - ALTER SEQUENCE. ANSI SQL version of setval. - Share identical sequence entries to not add things twice to table list. - testing insert/delete/update/truncate/load data - Run and fix Alibaba sequence tests (part of mysql-test/suite/sql_sequence) - Write documentation for NEXT VALUE / PREVIOUS_VALUE - NEXTVAL in DEFAULT - Ensure that NEXTVAL in DEFAULT uses database from base table - Two NEXTVAL for same row should give same answer. - Oracle syntax sequence_table.nextval, without any FOR or FROM. - Sequence tables are treated as 'not read constant tables' by SELECT; Would be better if we would have a separate list for sequence tables so that select doesn't know about them, except if refereed to with FROM. Other things done: - Improved output for safemalloc backtrack - frm_type_enum changed to Table_type - Removed lex->is_view and replaced with lex->table_type. This allows use to more easy check if item is view, sequence or table. - Added table flag HA_CAN_TABLES_WITHOUT_ROLLBACK, needed for handlers that want's to support sequences - Added handler calls: - engine_name(), to simplify getting engine name for partition and sequences - update_first_row(), to be able to do efficient sequence implementations. - Made binlog_log_row() global to be able to call it from ha_sequence.cc - Added handler variable: row_already_logged, to be able to flag that the changed row is already logging to replication log. - Added CF_DB_CHANGE and CF_SCHEMA_CHANGE flags to simplify deny_updates_if_read_only_option() - Added sp_add_cfetch() to avoid new conflicts in sql_yacc.yy - Moved code for add_table_options() out from sql_show.cc::show_create_table() - Added String::append_longlong() and used it in sql_show.cc to simplify code. - Added extra option to dd_frm_type() and ha_table_exists to indicate if the table is a sequence. Needed by DROP SQUENCE to not drop a table.
201 lines
4.9 KiB
Text
201 lines
4.9 KiB
Text
--source include/have_sequence.inc
|
|
--source include/have_innodb.inc
|
|
|
|
#
|
|
# Test sequence generation
|
|
#
|
|
|
|
CREATE SEQUENCE t1 start with 1 minvalue 1 maxvalue 10 increment by 1 cache 2 cycle;
|
|
show create table t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
|
|
select NEXT VALUE for t1,seq from seq_1_to_20;
|
|
|
|
drop sequence t1;
|
|
|
|
CREATE SEQUENCE t1 minvalue 1 maxvalue 10 increment by -1 cache 2 cycle engine=aria;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
select next value for t1;
|
|
select next_value,round from t1;
|
|
|
|
select NEXT VALUE for t1,seq from seq_1_to_20;
|
|
|
|
drop sequence t1;
|
|
|
|
CREATE SEQUENCE t1 start with 8 minvalue 1 maxvalue 10 increment by 1 cache 2 nocycle;
|
|
select next value for t1;
|
|
select next value for t1;
|
|
select next value for t1;
|
|
select previous value for t1;
|
|
--error ER_SEQUENCE_RUN_OUT
|
|
select next value for t1;
|
|
select previous value for t1;
|
|
--error ER_SEQUENCE_RUN_OUT
|
|
select next value for t1;
|
|
drop sequence t1;
|
|
|
|
create sequence s1 start with 1 cache 2 maxvalue 5;
|
|
select next value for s1;
|
|
select next value for s1;
|
|
select next value for s1;
|
|
select next value for s1;
|
|
select next value for s1;
|
|
--error ER_SEQUENCE_RUN_OUT
|
|
select next value for s1;
|
|
drop sequence s1;
|
|
|
|
#
|
|
# Test that flush tables jumps to next next_value
|
|
#
|
|
|
|
CREATE SEQUENCE t1 start with 1 minvalue 1 maxvalue 100 increment by 1 cache 10;
|
|
select next value for t1;
|
|
select * from t1;
|
|
flush tables;
|
|
select next value for t1;
|
|
select nextval(t1);
|
|
drop sequence t1;
|
|
|
|
#
|
|
# Test currval/previous
|
|
#
|
|
|
|
CREATE SEQUENCE t9 start with 1 minvalue 1 maxvalue 10 increment by 1 cache 5 cycle;
|
|
select previous value for t9;
|
|
select next value for t9;
|
|
select previous value for t9, lastval(t9);
|
|
select next value for t9;
|
|
select previous value for t9, lastval(t9);
|
|
select seq, previous value for t9, NEXT VALUE for t9, previous value for t9 from seq_1_to_20;
|
|
select * from t9;
|
|
drop sequence t9;
|
|
|
|
#
|
|
# Check what happens when one refers to a sequence that has been closed/deleted
|
|
#
|
|
|
|
CREATE SEQUENCE t1 start with 1 minvalue 1 maxvalue 10 increment by 1 cache 5 cycle;
|
|
select next value for t1;
|
|
select previous value for t1;
|
|
flush tables;
|
|
select previous value for t1;
|
|
drop sequence t1;
|
|
--error ER_NO_SUCH_TABLE
|
|
select previous value for t1;
|
|
CREATE SEQUENCE t1 start with 5 minvalue 1 maxvalue 10 increment by 1 cache 5 cycle;
|
|
select previous value for t1;
|
|
select next value for t1;
|
|
select previous value for t1;
|
|
drop sequence t1;
|
|
|
|
# This failed in an early build
|
|
|
|
CREATE or replace SEQUENCE s1 MINVALUE 1 MAXVALUE 9999999999
|
|
INCREMENT BY 1 START WITH 3984356 CACHE 20 CYCLE engine=innodb;
|
|
show create table s1;
|
|
select * from s1;
|
|
select NEXT VALUE FOR s1;
|
|
select NEXT VALUE FOR s1;
|
|
select NEXT VALUE FOR s1;
|
|
select * from s1;
|
|
FLUSH TABLES;
|
|
select * from s1;
|
|
select NEXT VALUE FOR s1;
|
|
select * from s1;
|
|
drop sequence s1;
|
|
|
|
#
|
|
# Explain
|
|
#
|
|
|
|
CREATE SEQUENCE t1 start with 5 minvalue 1 maxvalue 10 increment by 1 cache 5 cycle;
|
|
explain select next value for t1;
|
|
explain select next value for t1, min_value from t1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Using insert with NEXT VALUE
|
|
#
|
|
|
|
CREATE SEQUENCE s1;
|
|
CREATE TABLE t1 (a int);
|
|
insert into t1 values (next value for s1);
|
|
insert into t1 values (next value for s1);
|
|
select * from t1;
|
|
drop table t1,s1;
|
|
|
|
#
|
|
# Using update with NEXT VALUE
|
|
#
|
|
|
|
CREATE SEQUENCE s1;
|
|
CREATE TABLE t1 (a int primary key auto_increment, b int default 0) engine=myisam;
|
|
insert into t1 values (),(),(),(),(),(),();
|
|
update t1 set b= next value for s1 where a <= 3;
|
|
select * from t1;
|
|
drop table t1,s1;
|
|
|
|
#
|
|
# NO CACHE and InnoDB
|
|
#
|
|
|
|
CREATE OR REPLACE SEQUENCE s1 MINVALUE 1 MAXVALUE 9999999999 INCREMENT BY 1 START WITH 3984356 nocache CYCLE engine='innodb';
|
|
select * from s1;
|
|
select next value for s1;
|
|
drop sequence s1;
|
|
|
|
|
|
#
|
|
# Some error testing
|
|
#
|
|
|
|
create table t1 (a int);
|
|
--error ER_NOT_SEQUENCE
|
|
select next value for t1;
|
|
drop table t1;
|
|
|
|
create sequence t1;
|
|
select next value for t1;
|
|
--error ER_BAD_FIELD_ERROR
|
|
select next value for t1, min_value;
|
|
drop sequence t1;
|