Creating and Using Sequences

A sequence is a database object that generates unique integers according to a certain rule and is usually used to generate primary key values.

You can create a sequence for a column in either of the following methods:

  • Set the data type of a column to sequence integer. A sequence will be automatically created by the database for this column.

  • Use CREATE SEQUENCE to create a new sequenc. Use the nextval('sequence_name') function to increment the sequence and return a new value. Specify the default value of the column as the sequence value returned by the nextval('sequence_name') function. In this way, this column can be used as a unique identifier.

Creating a Sequence.

Method 1: Set the data type of a column to a sequence integer. For example:

CREATE TABLE T1
(
    id    serial,
    name  text
);

Method 2: Create a sequence and set the initial value of the nextval('sequence_name') function to the default value of a column. You can cache a specific number of sequence values to reduce the requests to the GTM, improving the performance.

  1. Create a sequence.

    CREATE SEQUENCE seq1 cache 100;
    
  2. Set the initial value of the nextval('sequence_name') function to the default value of a column.

    CREATE TABLE T2
    (
        id   int not null default nextval('seq1'),
        name text
    );
    

Note

Methods 1 and 2 are similar except that method 2 specifies cache for the sequence. A sequence using cache has holes (non-consecutive values, for example, 1, 4, 5) and cannot keep the order of the values. After a sequence is deleted, its sub-sequences will be deleted automatically. A sequence shared by multiple columns is not forbidden in a database, but you are not advised to do that.

Currently, the preceding two methods cannot be used for existing tables.

Modifying a Sequence

The ALTER SEQUENCE statement changes the attributes of an existing sequence, including the owner, owning column, and maximum value.

  • Associate the sequence with a column.

    The sequence will be deleted when you delete the column or the table where the column resides.

    ALTER SEQUENCE seq1 OWNED BY T2.id;
    
  • Modify the maximum value of serial to 300.

    ALTER SEQUENCE seq1 MAXVALUE 300;
    

Deleting a Sequence

Run the DROP SEQUENCE command to delete a sequence. For example, to delete the sequence named seq1, run the following command:

DROP SEQUENCE seq1;

Precautions

Sequence values are generated by the GTM. By default, each request for a sequence value is sent to the GTM. The GTM calculates the result of the current value plus the step and then returns the result. As GTM is a globally unique node, generating default sequence numbers can cause performance issues. For operations that need frequent sequence number generation, such as bulkload data import, this is not recommended. For example, the INSERT FROM SELECT statement has poor performance in the following scenario:

CREATE SEQUENCE newSeq1;
CREATE TABLE newT1
           (
             id   int not null default nextval('newSeq1'),
             name text
            );
INSERT INTO newT1(name) SELECT name from T1;

To improve the performance, run the following statements (assume that data of 10,000 rows will be imported from T1 to newT1):

INSERT INTO newT1(id, name) SELECT id,name from T1;
SELECT SETVAL('newSeq1',10000);

Note

Rollback is not supported by sequence functions, including nextval() and setval(). The value of the setval function immediately takes effects on nextval in the current session in any cases and takes effects in other sessions only when no cache is specified for them. If cache is specified for a session, it takes effect only after all the cached values have been used. To avoid duplicate values, use setval only when necessary. Do not set it to an existing sequence value or a cached sequence value.

If BulkLoad is used, set sufficient cache for newSeq1 and do not set Maxvalue or Minvalue. To improve the performance, database may push down the invocation of nextval('sequence_name') to DNs. Currently, the concurrent connection requests that can be processed by the GTM are limited. If there are too many DNs, a large number of concurrent connection requests will be sent to the GTM. In this case, you need to limit the concurrent connection of BulkLoad to save the GTM connection resources. If the target table is a replication table (DISTRIBUTE BY REPLICATION), pushdown cannot be performed. If the data volume is large, this will be a disaster for the database. In addition, the database space may be exhausted. After the import is complete, do VACUUM FULL. Therefore, you are not advised to use sequences when BulkLoad is used.

After a sequence is created, a single-row table is maintained on each node to store the sequence definition and value, which is obtained from the last interaction with the GTM rather than updated in real time. The single-row table on a node does not update when other nodes request a new value from the GTM or when the sequence is modified using setval.