PostgreSQL Tutorial

  • Home
  • Stored Procedures
  • Triggers
  • Views
  • Interfaces
    • PostgreSQL PHP
    • PostgreSQL Python
    • PostgreSQL JDBC
  • Functions
Home / PostgreSQL Tutorial / Using PostgreSQL SERIAL To Create Auto-increment Column

Using PostgreSQL SERIAL To Create Auto-increment Column

PostgreSQL SerialSummary: in this tutorial, we will introduce you to the PostgreSQL SERIAL and show you how to use the serial to create an auto-increment column in a database table.

Introduction to the PostgreSQL SERIAL pseudo-type

In PostgreSQL, a sequence is a special kind of database object that generates a sequence of integers. A sequence is often used as a primary key column. The concept of the sequence in PostgreSQL is similar to the AUTO_INCREMENT concept in MySQL.

When creating a new table, the sequence is created through the SERIAL pseudo-type as follows:

1
2
3
CREATE TABLE table_name(
    id SERIAL
);

By assigning the SERIAL pseudo-type to the id column, PostgreSQL will perform the following:

  • Creates a sequence object and set the next value generated by the sequence as the default value for the column.
  • Adds the NOT NULL constraint to the column because a sequence always generates an integer, which is a non-null value.
  • Assigns the owner of the sequence to the id column; as a result, the sequence object is deleted when the id column or table is dropped

Behind the scenes, the following statement:

1
2
3
CREATE TABLE table_name(
    id SERIAL
);

is equivalent to the following statements:

1
2
3
4
5
6
7
8
CREATE SEQUENCE table_name_id_seq;
 
CREATE TABLE table_name (
    id integer NOT NULL DEFAULT nextval('table_name_id_seq')
);
 
ALTER SEQUENCE table_name_id_seq
OWNED BY table_name.id;

PostgreSQL provides three serial pseudo-types SMALLSERIAL, SERIAL, and BIGSERIAL with the following characteristics:

NameStorage SizeRange
SMALLSERIAL2 bytes1 to 32,767
SERIAL4 bytes1 to 2,147,483,647
BIGSERIAL8 bytes1 to 922,337,2036,854,775,807

PostgresQL SERIAL example

It is important to note that the SERIAL does not implicitly create an index on the column or make the column as the primary key column. However, this can be done easily by specifying the PRIMARY KEY constraint for the SERIAL column.

The following statement creates the fruits table with the id column is the SERIAL column:

1
2
3
4
CREATE TABLE fruits(
   id SERIAL PRIMARY KEY,
   name VARCHAR NOT NULL
);

To assign the default value for the serial column, you ignore the column or use the DEFAULT keyword in the INSERT statement.

See the following example:

1
INSERT INTO fruits(name) VALUES('orange');

And

1
INSERT INTO fruits(id,name) VALUES(DEFAULT,'apple');

PostgreSQL inserted two rows into the fruits table with the values for the id column are 1 and 2.

1
2
SELECT *
FROM fruits;

1
2
3
4
5
id |  name
----+--------
  1 | apple
  2 | orange
(2 rows)

To get the sequence name of a SERIAL column in a table, you use the pg_get_serial_sequence() function as follows:

1
pg_get_serial_sequence('table_name','column_name')

You can pass a sequence name to the  currval() function to get the recent value generated by a sequence. For example, the following statement returns the recent value generated by the fruits_id_seq object:

1
SELECT currval(pg_get_serial_sequence('fruits', 'id'));

1
2
3
4
currval
---------
2
(1 row)

If you want to get the value generated by the sequence when you insert a new row into the table, you use the RETURNING id clause in the INSERT statement. The following statement inserts a new row into the fruits table and returns the value generated for the id column.

1
2
INSERT INTO fruits(name) VALUES('banana')
RETURNING id;

1
2
3
4
id
----
3
(1 row)

The sequence generator operation is not transaction-safe. It means that if two concurrent database connections attempt to get the next value from a sequence, each client will get a different value. If one of the clients rolls back the transaction, the sequence number of that client will be unused, creating a gap in the sequence.

In this tutorial, you have learned how to use the serial data type to create an auto-increment column for a database table.

Related Tutorials

  • PostgreSQL Data Types
Previous Tutorial: A Look At Various PostgreSQL Integer Data Types
Next Tutorial: PostgreSQL Boolean Data Type with Practical Examples

PostgreSQL Quick Start

  • What is PostgreSQL?
  • Install PostgreSQL
  • Connect to Database
  • Download PostgreSQL Sample Database
  • Load Sample Database
  • Explore Server and Database Objects

PostgreSQL Fundamentals

  • PostgreSQL Select
  • PostgreSQL Order By
  • PostgreSQL Select Distinct
  • PostgreSQL Where
  • PostgreSQL LIMIT
  • PostgreSQL IN
  • PostgreSQL Between
  • PostgreSQL Like
  • PostgreSQL Inner Join
  • PostgreSQL Left Join
  • PostgreSQL Full Outer Join
  • PostgreSQL Cross Join
  • PostgreSQL Natural Join
  • PostgreSQL Group By
  • PostgreSQL Having
  • PostgreSQL Union
  • PostgreSQL Intersect
  • PostgreSQL Except
  • PostgreSQL Subquery
  • PostgreSQL Insert
  • PostgreSQL Update
  • PostgreSQL Delete
  • PostgreSQL Data Types
  • PostgreSQL Create Table
  • PostgreSQL Alter Table
  • PostgreSQL Drop Table
  • PostgreSQL Truncate Table
  • PostgreSQL CHECK Constraint
  • PostgreSQL Not-Null Constraint
  • PostgreSQL Foreign Key
  • PostgreSQL Primary Key
  • PostgreSQL UNIQUE Constraint

About PostgreSQL Tutorial

PostgreSQLTutorial.com is a website dedicated to developers and database administrators who are working on PostgreSQL database management system.

We constantly publish useful PostgreSQL tutorials to keep you up-to-date with the latest PostgreSQL features and technologies. All PostgreSQL tutorials are simple, easy-to-follow and practical.

Recent PostgreSQL Tutorials

  • How To Change The Password of a PostgreSQL User
  • PostgreSQL AGE Function
  • PostgreSQL DATE_PART Function
  • PostgreSQL List Users
  • PostgreSQL NOW Function
  • PostgreSQL DATE_TRUNC Function
  • PostgreSQL TO_DATE Function: Convert String to Date
  • A Look at PostgreSQL User-defined Data Types
  • PostgreSQL Copy Database Made Easy
  • How to Get Table, Database, Indexes, Tablespace, and Value Size in PostgreSQL

More Tutorials

  • PostgreSQL Cheat Sheet
  • PostgreSQL Administration
  • PostgreSQL PHP
  • PostgreSQL Python
  • PostgreSQL JDBC
  • PostgreSQL Resources

Site Info

  • Home
  • About Us
  • Contact Us
  • Privacy Policy

Copyright © 2017 by PostgreSQL Tutorial Website. All Rights Reserved.