Overview of Sequences¶
Let us go through some of the important details related to sequences.
- For almost all the tables in relational databases we define primary key constraints.
- Primary key is nothing but unique constraint with not null and there can be only one primary key in any given table.
- Many times, we might not have appropriate column in the table which can be used as primary key. In those scenarios we will define a column which does not have any business relevant values. This is called as surrogate key.
- Relational Database technologies provide sequences to support these surrogate primary keys.
- In postgres we can define surrogate primary key for a given table as
SERIAL
. Internally it will create a sequence. - We can also pre-create a sequence and use it to populate multiple tables.
- Even if we do not specify the column and value as part of the insert statement, a sequence generated number will be populated in that column.
- Typically, the sequence generated number will be incremented by 1. We can change it by specifying a constant value using
INCREMENT BY
. - Here are some of the properties that can be set for a sequence. Most of them are self explanatory.
START WITH
RESTART WITH
MINVALUE
MAXVALUE
CACHE
- We can use functions such as
nextval
andcurrval
to explicitly generate sequence numbers and also to get current sequence number in the current session. - We might have to use
RESTART WITH
to reset the sequences after the underlying tables are populated with values in surrogate key.
In [1]:
%load_ext sql
In [2]:
%env DATABASE_URL=postgresql://itversity_retail_user:retail_password@pg.itversity.com:5432/itversity_retail_db
env: DATABASE_URL=postgresql://itversity_retail_user:retail_password@pg.itversity.com:5432/itversity_retail_db
{note}
Let us create a sequence which start with 101 with minimum value 101 and maximum value 1000.
In [3]:
%%sql
DROP SEQUENCE IF EXISTS test_seq
Done.
Out[3]:
[]
In [4]:
%%sql
CREATE SEQUENCE test_seq
START WITH 101
MINVALUE 101
MAXVALUE 1000
INCREMENT BY 100
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[4]:
[]
In [5]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db (psycopg2.errors.ObjectNotInPrerequisiteState) currval of sequence "test_seq" is not yet defined in this session [SQL: SELECT currval('test_seq')] (Background on this error at: https://sqlalche.me/e/14/e3q8)
In [6]:
%sql SELECT nextval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[6]:
nextval |
---|
101 |
In [7]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[7]:
currval |
---|
101 |
In [8]:
%sql SELECT nextval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[8]:
nextval |
---|
201 |
In [9]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[9]:
currval |
---|
201 |
In [10]:
%sql SELECT nextval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[10]:
nextval |
---|
301 |
In [11]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[11]:
currval |
---|
301 |
In [12]:
%%sql
ALTER SEQUENCE test_seq
INCREMENT BY 1
RESTART WITH 101
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[12]:
[]
In [13]:
%sql SELECT nextval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[13]:
nextval |
---|
101 |
In [14]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[14]:
currval |
---|
101 |
In [15]:
%sql SELECT nextval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[15]:
nextval |
---|
102 |
In [16]:
%sql SELECT currval('test_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[16]:
currval |
---|
102 |
In [17]:
%sql DROP SEQUENCE test_seq
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[17]:
[]
{note}
`SERIAL` will make sure user_id is populated using sequence and `PRIMARY KEY` will enforce not null and unique constraints.
In [18]:
%sql DROP TABLE IF EXISTS users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[18]:
[]
In [19]:
%sql DROP SEQUENCE IF EXISTS users_user_id_seq
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[19]:
[]
In [20]:
%%sql
CREATE TABLE users (
user_id SERIAL PRIMARY KEY,
user_first_name VARCHAR(30) NOT NULL,
user_last_name VARCHAR(30) NOT NULL,
user_email_id VARCHAR(50) NOT NULL,
user_email_validated BOOLEAN,
user_password VARCHAR(200),
user_role VARCHAR(1),
is_active BOOLEAN,
created_dt DATE DEFAULT CURRENT_DATE
)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[20]:
[]
In [21]:
%%sql
SELECT * FROM information_schema.sequences
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[21]:
sequence_catalog | sequence_schema | sequence_name | data_type | numeric_precision | numeric_precision_radix | numeric_scale | start_value | minimum_value | maximum_value | increment | cycle_option |
---|---|---|---|---|---|---|---|---|---|---|---|
itversity_retail_db | public | users_user_id_seq | integer | 32 | 2 | 0 | 1 | 1 | 2147483647 | 1 | NO |
In [22]:
%sql SELECT nextval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[22]:
nextval |
---|
1 |
In [23]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[23]:
currval |
---|
1 |
In [24]:
%%sql
INSERT INTO users (user_first_name, user_last_name, user_email_id)
VALUES ('Donald', 'Duck', 'donald@duck.com')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[24]:
[]
In [25]:
%%sql
SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[25]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
2 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
In [26]:
%%sql
INSERT INTO users (user_first_name, user_last_name, user_email_id, user_role, is_active)
VALUES ('Mickey', 'Mouse', 'mickey@mouse.com', 'U', true)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[26]:
[]
In [27]:
%%sql
SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 2 rows affected.
Out[27]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
2 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
3 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
In [28]:
%%sql
INSERT INTO users
(user_first_name, user_last_name, user_email_id, user_password, user_role, is_active)
VALUES
('Gordan', 'Bradock', 'gbradock0@barnesandnoble.com', 'h9LAz7p7ub', 'U', true),
('Tobe', 'Lyness', 'tlyness1@paginegialle.it', 'oEofndp', 'U', true),
('Addie', 'Mesias', 'amesias2@twitpic.com', 'ih7Y69u56', 'U', true)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 3 rows affected.
Out[28]:
[]
In [29]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[29]:
currval |
---|
6 |
In [30]:
%sql SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 5 rows affected.
Out[30]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
2 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
3 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
4 | Gordan | Bradock | gbradock0@barnesandnoble.com | None | h9LAz7p7ub | U | True | 2022-03-13 |
5 | Tobe | Lyness | tlyness1@paginegialle.it | None | oEofndp | U | True | 2022-03-13 |
6 | Addie | Mesias | amesias2@twitpic.com | None | ih7Y69u56 | U | True | 2022-03-13 |
{warning}
It is not a good idea to populate surrogate key fields by passing the values. Either we should specify sequence generated number or let database take care of populating the field.
In [31]:
%%sql
INSERT INTO users (user_id, user_first_name, user_last_name, user_email_id)
VALUES (7, 'Scott', 'Tiger', 'scott@tiger.com')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[31]:
[]
In [32]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[32]:
currval |
---|
6 |
{note}
When data is loaded with surrogate key values into the table from external sources, it is recommended to create sequence with maximum + 1 value using`START WITH`
In [33]:
%sql DROP TABLE IF EXISTS users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[33]:
[]
In [34]:
%sql DROP SEQUENCE IF EXISTS users_user_id_seq
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[34]:
[]
{note}
`SERIAL` will make sure user_id is populated using sequence and `PRIMARY KEY` will enforce not null and unique constraints.
In [35]:
%%sql
CREATE TABLE users (
user_id SERIAL PRIMARY KEY,
user_first_name VARCHAR(30) NOT NULL,
user_last_name VARCHAR(30) NOT NULL,
user_email_id VARCHAR(50) NOT NULL,
user_email_validated BOOLEAN,
user_password VARCHAR(200),
user_role VARCHAR(1),
is_active BOOLEAN,
created_dt DATE DEFAULT CURRENT_DATE
)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[35]:
[]
In [36]:
%%sql
INSERT INTO users (user_id, user_first_name, user_last_name, user_email_id)
VALUES (1, 'Donald', 'Duck', 'donald@duck.com')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[36]:
[]
In [37]:
%%sql
INSERT INTO users (user_id, user_first_name, user_last_name, user_email_id, user_role, is_active)
VALUES (2, 'Mickey', 'Mouse', 'mickey@mouse.com', 'U', true)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[37]:
[]
In [38]:
%%sql
INSERT INTO users
(user_id, user_first_name, user_last_name, user_email_id, user_password, user_role, is_active)
VALUES
(3, 'Gordan', 'Bradock', 'gbradock0@barnesandnoble.com', 'h9LAz7p7ub', 'U', true),
(4, 'Tobe', 'Lyness', 'tlyness1@paginegialle.it', 'oEofndp', 'U', true),
(5, 'Addie', 'Mesias', 'amesias2@twitpic.com', 'ih7Y69u56', 'U', true)
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 3 rows affected.
Out[38]:
[]
In [39]:
%sql SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 5 rows affected.
Out[39]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
1 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
2 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
3 | Gordan | Bradock | gbradock0@barnesandnoble.com | None | h9LAz7p7ub | U | True | 2022-03-13 |
4 | Tobe | Lyness | tlyness1@paginegialle.it | None | oEofndp | U | True | 2022-03-13 |
5 | Addie | Mesias | amesias2@twitpic.com | None | ih7Y69u56 | U | True | 2022-03-13 |
In [40]:
%sql SELECT nextval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[40]:
nextval |
---|
1 |
In [41]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[41]:
currval |
---|
1 |
In [42]:
%sql ALTER SEQUENCE users_user_id_seq RESTART WITH 5
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[42]:
[]
In [43]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[43]:
currval |
---|
1 |
In [44]:
%sql SELECT nextval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[44]:
nextval |
---|
5 |
In [45]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[45]:
currval |
---|
5 |
In [46]:
%%sql
INSERT INTO users (user_first_name, user_last_name, user_email_id)
VALUES ('Scott', 'Tiger', 'scott@tiger.com')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[46]:
[]
In [47]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[47]:
currval |
---|
6 |
In [48]:
%sql SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 6 rows affected.
Out[48]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
1 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
2 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
3 | Gordan | Bradock | gbradock0@barnesandnoble.com | None | h9LAz7p7ub | U | True | 2022-03-13 |
4 | Tobe | Lyness | tlyness1@paginegialle.it | None | oEofndp | U | True | 2022-03-13 |
5 | Addie | Mesias | amesias2@twitpic.com | None | ih7Y69u56 | U | True | 2022-03-13 |
6 | Scott | Tiger | scott@tiger.com | None | None | None | None | 2022-03-13 |
In [49]:
%sql DROP SEQUENCE users_user_id_seq CASCADE
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[49]:
[]
In [50]:
%sql SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 6 rows affected.
Out[50]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
1 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
2 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
3 | Gordan | Bradock | gbradock0@barnesandnoble.com | None | h9LAz7p7ub | U | True | 2022-03-13 |
4 | Tobe | Lyness | tlyness1@paginegialle.it | None | oEofndp | U | True | 2022-03-13 |
5 | Addie | Mesias | amesias2@twitpic.com | None | ih7Y69u56 | U | True | 2022-03-13 |
6 | Scott | Tiger | scott@tiger.com | None | None | None | None | 2022-03-13 |
In [51]:
%%sql
CREATE SEQUENCE users_user_id_seq
START WITH 7
MINVALUE 1
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[51]:
[]
In [52]:
%%sql
ALTER SEQUENCE users_user_id_seq
OWNED BY users.user_id
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[52]:
[]
In [53]:
%%sql
ALTER TABLE users
ALTER COLUMN user_id
SET DEFAULT nextval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db Done.
Out[53]:
[]
In [54]:
%%sql
INSERT INTO users (user_first_name, user_last_name, user_email_id)
VALUES ('Matt', 'Clarke', 'matt@clarke.com')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[54]:
[]
In [55]:
%sql SELECT * FROM users
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 7 rows affected.
Out[55]:
user_id | user_first_name | user_last_name | user_email_id | user_email_validated | user_password | user_role | is_active | created_dt |
---|---|---|---|---|---|---|---|---|
1 | Donald | Duck | donald@duck.com | None | None | None | None | 2022-03-13 |
2 | Mickey | Mouse | mickey@mouse.com | None | None | U | True | 2022-03-13 |
3 | Gordan | Bradock | gbradock0@barnesandnoble.com | None | h9LAz7p7ub | U | True | 2022-03-13 |
4 | Tobe | Lyness | tlyness1@paginegialle.it | None | oEofndp | U | True | 2022-03-13 |
5 | Addie | Mesias | amesias2@twitpic.com | None | ih7Y69u56 | U | True | 2022-03-13 |
6 | Scott | Tiger | scott@tiger.com | None | None | None | None | 2022-03-13 |
7 | Matt | Clarke | matt@clarke.com | None | None | None | None | 2022-03-13 |
In [56]:
%sql SELECT currval('users_user_id_seq')
* postgresql://itversity_retail_user:***@pg.itversity.com:5432/itversity_retail_db 1 rows affected.
Out[56]:
currval |
---|
7 |