SERIAL and BIGSERIAL data type
Informix®
SERIAL
,
BIGSERIAL
data types to produce automatic integer sequences:SERIAL
can produce 32 bit integers (INTEGER
)BIGSERIAL
can produced 64 bit integers (BIGINT
)SERIAL8
is a synonym forBIGSERIAL
- Create the table with a column using
SERIAL
, orBIGSERIAL
. - To generate a new serial, no value or a zero value is specified in the
INSERT
statement:INSERT INTO tab1 ( c ) VALUES ( 'aa' ) INSERT INTO tab1 ( k, c ) VALUES ( 0, 'aa' )
- After
INSERT
, the new value of aSERIAL
column is provided inSQLCA.SQLERRD[2]
, while the new value of aBIGSERIAL
value must be fetched with aSELECT dbinfo('bigserial')
query.
Informix allows you to insert rows with a value
different from zero for a serial column. Using an explicit value will automatically increment the
internal serial counter, to avoid conflicts with future INSERT
statements that are
using a zero value:
CREATE TABLE tab ( k SERIAL); -- internal counter = 0
INSERT INTO tab VALUES ( 0 ); -- internal counter = 1
INSERT INTO tab VALUES ( 10 ); -- internal counter = 10
INSERT INTO tab VALUES ( 0 ); -- internal counter = 11
DELETE FROM tab; -- internal counter = 11
INSERT INTO tab VALUES ( 0 ); -- internal counter = 12
Oracle® MySQL and MariaDB
MySQL supports the AUTO_INCREMENT
column definition option as well as the
SERIAL
keyword:
-
In
CREATE TABLE
, you specify a auto-incremented column with theAUTO_INCREMENT
attribute -
Auto-incremented columns have the same behavior as Informix
SERIAL
columns -
A start value can be defined with
ALTER TABLE tabname AUTO_INCREMENT = value
-
The column must be the primary key, or the first column of an index.
-
When using the InnoDB engine, with MySQL 5.7 and earlier, auto-incremented columns might reuse unused sequences after a server restart. For example, if you insert rows that generate the numbers 101, 102 and 103, then you delete rows 102 and 103; When the server is restarted, next generated number will be 101 + 1 = 102. Starting with MySQL 8.0, the last auto-incremented value is written to the disk and persists across server restarts.
-
SERIAL
is a synonym forBIGINT UNSIGNED NOT NULL AUTO_INCREMENT UNIQUE
.
Solution
The Informix SERIAL
data type is
emulated with MySQL AUTO_INCREMENT
option.
dbi.database.dbname.ifxemul.datatype.serial = {true|false}
dbi.database.dbname.ifxemul.datatype.serial8 = {true|false}
dbi.database.dbname.ifxemul.datatype.bigserial = {true|false}
Disabling automatic serial retrieval for SQLCA.SQLERRD[2]
ifxemul.datatype.serial
FGLPROFILE entry to
false:dbi.database.dbname.ifxemul.datatype.serial = false
For Informix compatibility, after an
INSERT
statement, the ODI drivers automatically execute another SQL query (or do a
DB client API call when possible), to get the last generated serial, and fill the
SQLCA.SQLERRD[2]
register. This results in some overhead that can be avoided, if
the SQLCA.SQLERRD[2]
register is not used by the program.
When SERIAL emulation is required (to create temp tables with a serial column during program
execution), and the SQLCA.SQLERRD[2]
register does not need to be filled,
(typically because you use your own method to retrieve the last generated serial), you can set the
ifxemul.datatype.serial.sqlerrd2
FGLPROFILE entry to false. This will avoid the
automatic retrieval of last serial value to fill SQLCA.SQLERRD[2]
:
dbi.database.dbname.ifxemul.datatype.serial.sqlerrd2 = false
See also db_get_last_serial().
Using the native
serial emulation (only option)
After an insert, SQLCA.SQLERRD[2]
holds the last generated serial value.
However, SQLCA.SQLERRD[2]
is defined as an INTEGER
, it cannot hold
values from BIGINT
auto incremented columns. If you are using
BIGINT
auto incremented columns, you must use the LAST_INSERT_ID()
SQL function.
AUTO_INCREMENT
columns must be primary keys. This is handled automatically when
you create a table in a BDL program.
Like Informix, MySQL allows you to specify a zero for
auto-incremented columns. However, for SQL portability, it is recommended to review
INSERT
statements to remove the SERIAL
column from the list.
INSERT INTO tab (col1,col2) VALUES ( 0, p_value)
INSERT INTO tab (col2) VALUES (p_value)
Static SQL INSERT
using records defined from the schema file must also be
reviewed:
DEFINE rec LIKE tab.*
INSERT INTO tab VALUES ( rec.* ) -- will use the serial column
can be converted to:
INSERT INTO tab VALUES rec.* -- without parentheses, serial column is removed