SERIAL and BIGSERIAL data types
Informix®
SERIAL
,
BIGSERIAL
data types to produce automatic integer sequences:SERIAL
can produce 32 bit integers (INTEGER
)BIGSERIAL
can produce 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:
SQL statement Internal serial counter
------------------------------------------------------------------------------------------
CREATE TABLE tab ( pkey SERIAL, name VARCHAR(50) ); 0
INSERT INTO tab VALUES ( 0, 'aaa' ); 1
INSERT INTO tab VALUES ( 10, 'bbb' ); 10
INSERT INTO tab VALUES ( 0, 'ccc' ); 11
DELETE FROM tab; 11
INSERT INTO tab VALUES ( 0, 'ddd' ); 12
IBM® DB2®
IDENTITY
columns:CREATE TABLE tab ( k INTEGER GENERATED ALWAYS AS IDENTITY, name VARCHAR(50) )
To get the last generated IDENTITY
value after an INSERT
, DB2 provides the IDENTITY_VAL_LOCAL()
function.
SEQUENCES
:CREATE SEQUENCE sq1 START WITH 100
NEXTVAL FOR
operator:INSERT INTO table VALUES ( NEXTVAL FOR sq1, ... )
PREVVAL FOR
operator:SELECT PREVVAL FOR sq1 ...
Solution
For best SQL portability when using different types of databases, consider using sequences as described in Solution 3: Use native SEQUENCE database objects.
To emulate Informix serials with IBM DB2, you can use
IDENTITY
columns (1), or INSERT
triggers using sequences (2). The
first solution is faster, but does not allow explicit serial value specification in insert
statements; the second solution is slower but allows explicit serial value specification.
The trigger-based solution is provided to simplify the conversion from
Informix, but is slower as the solution using identity columns. We strongly recommend that you use
native IDENTITY
columns instead to get best performances.
SERIAL
types is defined by the
ifxemul.datatype.serial.emulation
FGLPROFILE
parameter:dbi.database.dbname.ifxemul.datatype.serial.emulation = {
"native"|
"trigseq"}
native
: usesIDENTITY
columns.trigseq
: usesINSERT
triggers with sequences.
The default emulation technique is "native
".
Do not mix a serial emulation modes: Choose one of the provided serial
emulations for all the tables of the application database. Do note create the tables with a given
serial emulation, and later switch to another serial emulation for INSERT
statements. This is not supported.
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]
For Informix compatibility, when the
SERIAL
type emulation is active, the ODI drivers automatically execute another SQL
query (or do a DB client API call when possible) after each INSERT
statement, 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
SERIAL
type emulation is
disabled with:dbi.database.dbname.ifxemul.datatype.serial = false
See also db_get_last_serial().
Using the native
serial emulation
In database creation scripts, all SERIAL[(n)]
data types must be converted by
hand to:
INTEGER GENERATED ALWAYS AS IDENTITY[( START WITH n, INCREMENT BY 1)]
SERIAL8
and BIGSERIAL[(n)]
types must be converted
to:BIGINT GENERATED ALWAYS AS IDENTITY[( START WITH n, INCREMENT BY 1)]
Tables created from the BDL programs can use the SERIAL
data type: When a BDL
program executes a CREATE [TEMP] TABLE
with a SERIAL
column, the
database interface automatically converts the SERIAL[(n)]
data type to an
IDENTITY
specification.
In BDL, the new generated SERIAL
value is available from the
sqlca.sqlerrd[2]
variable. The database interface performs a call to the
IDENTITY_VAL_LOCAL()
function. However, sqlca.sqlerrd[2]
is
defined as an INTEGER
, it cannot hold values from BIGINT
identity
columns. If you are using BIGINT IDENTITY
columns, you must use the
IDENTITY_VAL_LOCAL()
function.
IDENTITY
columns, it is mandatory to convert
all INSERT statements to remove the SERIAL
column from the list. For example, the
following statement: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
INSERT INTO tab VALUES rec.* -- without parentheses, serial column is removed
Using the trigseq
serial emulation
In database creation scripts, all SERIAL[(n)]
data types must be converted to
INTEGER
data types, SERIAL8/BIGSERIAL
must be converted to
BIGINT
, and you must create a sequence and a trigger for each table using a
SERIAL
.
To know how to write those triggers, you can create a small Genero program that creates a table
with a SERIAL
column. Set the FGLSQLDEBUG environment variable and run the program.
The debug output will show you the native SQL commands to create the sequence and the trigger.
Tables created from the BDL programs can use the SERIAL
data type: When a BDL
program executes a CREATE [TEMP] TABLE
with a SERIAL
column, the
database interface automatically converts the SERIAL[(n)]
data type to
INTEGER
and creates the sequence and the INSERT
trigger.
IBM DB2 performs
NOT NULL
data controls before the execution of triggers. If the serial column must
be NOT NULL
(for example, because it is part of the primary key), you cannot
specify a NULL
value for that column in INSERT
statements.
INSERT INTO tab VALUES (NULL,p_value)
INSERT INTO tab (col2) VALUES (p_value)
- IBM DB2 triggers are not automatically dropped when the corresponding table is dropped. They become inoperative instead. Database administrators must take care of this behavior when managing schemas.
- With IBM DB2,
INSERT
statements usingNULL
for theSERIAL
column will produce a new serial value:INSERT INTO tab ( col_serial, col_data ) VALUES ( NULL, 'data' )
This behavior is mandatory in order to supportINSERT
statements which do not use the serial column:INSERT INTO tab (col_data) VALUES ('data')
Check if your application uses tables with a
SERIAL
column that can contain aNULL
value. - With DB2, trigger creation is not allowed on
temporary tables. Therefore, the "
trigseq
" method cannot work with temporary tables using serials.