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
PostgreSQL
PostgreSQL SERIAL
data type:
- PostgreSQL provides native
SERIAL
andBIGSERIAL
data type which are similar to Informix serial types. However, native PostgreSQL serial types behaves differently. - It is not possible to define a start value (
SERIAL(100)
). - It is not possible to specify zero as serial value to get a new serial: The PostgreSQL serial is
based on default values, thus you must omit the serial column in the
INSERT
statement. - When you
INSERT
a row with a specific value for the serial column, the underlying sequence will not be incremented. As result, the nextINSERT
that does not specify the serial column may get a new sequence that was already inserted explicitly. - With some old versions of PostgreSQL, when you drop the table you must drop the sequence too.
PostgreSQL sequences:
- The purpose of sequences is to provide unique integer numbers.
- To create a sequence, you must use the
CREATE SEQUENCE
statement. - To get a new sequence value, you must use the
nextval()
function:INSERT INTO tab1 VALUES ( nextval('tab1_seq'), ... )
- To get the last generated number, PostgreSQL provides the
currval()
function:SELECT currval('tab1_seq')
Solution
The Informix SERIAL and BIGSERIAL data types can be emulated with three different methods.
ifxemul.datatype.serial.emulation
FGLPROFILE
parameter:dbi.database.dbname.ifxemul.datatype.serial.emulation = {"native"|"regtable"|"trigseq"}
native
: uses the native PostgreSQL serial data type.regtable
: uses insert triggers with the SERIALREG table.trigseq
: uses insert triggers with sequences.
The default emulation technique is "native
".
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
The "native
" mode is the default serial emulation mode, using the native
PostgreSQL SERIAL or BIGSERIAL data type. In this mode, the original type name will be left
untouched by the SQL Translator and you will get the behavior of the PostgreSQL SERIAL/BIGSERIAL
column types, based on sequences.
sqlca.sqlerrd[2]
register. For BIGSERIAL, you need to execute the following
query:SELECT currval(pg_get_serial_sequence('[schema.]tabname','colname'));
GRANT USAGE, SELECT ON ALL SEQUENCES IN SCHEMA public TO user-name;
ALTER DEFAULT PRIVILEGES IN SCHEMA public GRANT USAGE, SELECT ON SEQUENCES TO user-name;
See also the PostgreSQL documentation for more details about the native serial types.
Using the regtable
serial emulation
With the "regtable
" mode, the SERIAL data type is emulated with a PostgreSQL
INTEGER data type and INSERT triggers using the table SERIALREG which is dedicated to sequence
production. After an insert, sqlca.sqlerrd[2]
register holds the last generated
serial value. BIGSERIAL and SERIAL8 types can be converted to BIGINT in PostgreSQL, but the
sqlca.sqlerrd[2]
register cannot be used since it is defined as an INTEGER
type.
The triggers can be created manually during the application database installation procedure, or automatically from a BDL program: When a BDL program executes a CREATE [TEMP] TABLE with a SERIAL column, the database interface automatically converts the SERIAL data type to INTEGER and dynamically creates the triggers.
You must create the SERIALREG table as follows:
CREATE TABLE SERIALREG (
TABLENAME VARCHAR(50) NOT NULL,
LASTSERIAL DECIMAL(20,0) NOT NULL,
PRIMARY KEY ( TABLENAME )
)
In database creation scripts, all SERIAL[(n)] data types must be converted to INTEGER data types and you must create one trigger for each table. 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 trigger creation command.
INSERT INTO tab ( col1, col2 ) VALUES ( NULL, 'data' )
INSERT INTO tab (col2) VALUES ('data')
Check if your application uses tables with a SERIAL column that can contain a NULL value. Consider removing the serial column from the INSERT statements.
Using the trigseq
serial emulation
With "trigseq
", the SERIAL data type is emulated with a PostgreSQL INTEGER data
type and INSERT triggers using a sequence tablename_seq
. After
an insert, sqlca.sqlerrd[2]
register holds the last generated serial value.
The triggers can be created manually during the application database installation procedure, or automatically from a BDL program: When a BDL program executes a CREATE [TEMP] TABLE with a SERIAL column, the database interface automatically converts the SERIAL data type to INTEGER and dynamically creates the triggers.
In database creation scripts, all SERIAL[(n)] data types must be converted to INTEGER data types and you must create one trigger for each table. 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 trigger creation command.
INSERT INTO tab ( col1, col2 ) VALUES ( NULL, 'data' )
INSERT INTO tab (col2) VALUES ('data')
Check if your application uses tables with a SERIAL column that can contain a NULL value. Consider removing the serial column from the INSERT statements.
Notes common to all serial emulation modes
Since sqlca.sqlerrd[2]
is defined as an INTEGER, it cannot hold values from
BIGSERIAL (BIGINT) auto incremented columns. If you are using BIGSERIAL columns, you must query the
sequence pseudo-column CURRVAL() or fetch the LASTSERIAL column from the SERIALREG table if
used.
For SQL portability, it is recommended to review INSERT statements 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