SERIAL and BIGSERIAL data types
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
SQLite
SQLite supports the AUTOINCREMENT
attribute for columns:
- Only one column must be declared as
INTEGER PRIMARY KEY AUTOINCREMENT
. - SQLite (version 3.8.3.1) does not support
SEQUENCE
objects. - SQLite (version 3.8.3.1) does not allow
AUTOINCREMENT
onBIGINT
columns. - To get the last generated number, SQLite provides the sqlite_sequence table:
SELECT seq FROM sqlite_sequence WHERE name='tabname'
- At INSERT, for the auto-incremented column:
- When specifying a zero, SQLite will not generate a new sequence like Informix does.
- When specifying a NULL, SQLite generates a new sequence; Informix denies NULLs in serials.
- When specifying a value different from zero and NULL, SQLite will use that value. The next INSERT statement not providing a value > 0 will produce a new auto-incremented value that is greater as the last inserted value.
Solution
When using SQLite, the SERIAL
data type is converted to INTEGER PRIMARY
KEY AUTOINCREMENT
.
dbi.database.dbname.ifxemul.datatype.serial = {true|false}
dbi.database.dbname.ifxemul.datatype.serial8 = {true|false}
dbi.database.dbname.ifxemul.datatype.bigserial = {true|false}
For more details see IBM Informix emulation parameters in FGLPROFILE.
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)
The SQLCA.SQLERRD[2]
register is filled automatically after each
INSERT
with the last generated number, by fetching the value from the
sqlite_sequence
table.
BIGINT
columns. Therefore, BIGSERIAL
or SERIAL8
cannot be supported.
These Informix SQL types are converted to BIGINT PRIMARY KEY AUTOINCREMENT
, but
that will produce an SQL error "AUTOINCREMENT is only allowed on an INTEGER PRIMARY
KEY"
.Because SQLite does not behave like Informix regarding
zero and NULL
value specification for auto-incremented columns, all
INSERT
statements must be reviewed to remove the SERIAL
column
from the list.
For example, the following statement:
INSERT INTO tab (col1,col2) VALUES ( 0 , p_value)
Can be converted to:
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