SERIAL and BIGSERIAL data types

Informix®

Informix supports the 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 for BIGSERIAL
Steps to use serials with Informix:
  1. Create the table with a column using SERIAL, or BIGSERIAL.
  2. 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' )
  3. After INSERT, the new value of a SERIAL column is provided in SQLCA.SQLERRD[2], while the new value of a BIGSERIAL value must be fetched with a SELECT 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's SERIAL data type has the same name as in Informix, but it behaves differently.
  • You cannot define a start value ( SERIAL(100) ).
  • You cannot 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 next INSERT 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

Note: For best SQL portability when using different types of databases, consider using sequences as described in Solution 3: Use native SEQUENCE database objects.

The Informix SERIAL data type can be emulated with three different methods.

The method used to emulate SERIAL types is defined by the 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".

The serial types emulation can be enabled or disabled with the folllowing FGLPROFILE entries:
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]

SERIAL emulation can be totally disabled by setting the 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 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 column type, based on sequences.

Note: INSERT statements cannot use the serial column, even with a value zero. When using a NULL value, PostgreSQL will report an non-null constraint error. Therefore, the serial column must be omitted from the INSERT statement.

See also the PostgreSQL documentation for more details about the native SERIAL type.

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 )
)
Important: The SERIALREG table must be created before the triggers. The serial production is based on the SERIALREG table which registers the last generated number for each table. If you delete rows of this table, sequences will restart at 1 and you will get unexpected data.

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.

With this emulation mode, INSERT statements using NULL for the SERIAL column will produce a new serial value:
INSERT INTO tab ( col1, col2 ) VALUES ( NULL, 'data' )
This behavior is mandatory in order to support INSERT statements that do not use the serial column:
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.

With this emulation mode, INSERT statements using NULL for the SERIAL column will produce a new serial value:
INSERT INTO tab ( col1, col2 ) VALUES ( NULL, 'data' )
This behavior is mandatory in order to support INSERT statements which do not use the serial column:
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
Important: When using the Static SQL INSERT and UPDATE syntax using record.* without parentheses, make sure that you database schema files contain information about serials: This information can be lost when extracting the schema from a PostgreSQL database which does not use native serial emulation. See Database Schema for more details about the serial flag in column type encoding (data type code must be 6)