Postgres cheatsheet
See also: wiki/postgres
SQL
-- timestamp literal
TIMESTAMP '2025-06-29 08:00:00'
TIMESTAMPTZ '2025-06-29 08:00:00 America/New_York'
Delete a single row
https://stackoverflow.com/a/5171473/3934904
DELETE FROM ONLY mytable
WHERE ctid IN (
SELECT ctid
FROM mytable
WHERE ...
ORDER BY ...
LIMIT 1
);
Columns
-- auto-incrementing primary key
id SERIAL PRIMARY KEY
-- fixed-point decimal (9 total digits, 2 after decimal point)
amount DECIMAL(9, 2)
-- string belongs to set
category TEXT NOT NULL CHECK (category IN ('A', 'B'))
-- foreign key column
parent_id INTEGER NOT NULL REFERENCES parent(id) ON DELETE CASCADE
-- or ON DELETE SET NULL
Constraints
CREATE TABLE objects(
...,
UNIQUE(column_a, column_b)
)
Database management
-- list databases
\l
-- connect to database
\c NAME
-- list tables
\d
-- show schema
\d+ TABLE
-- drop all tables in database
DROP SCHEMA public CASCADE;
CREATE SCHEMA public;
GRANT ALL ON SCHEMA public TO <role>
Default login: sudo -u postgres psql
Roles
- https://www.postgresql.org/docs/17/database-roles.html
- Roles are global per cluster, not per database.
- See "Authentication Methods" to understand how a role is associated with a client connection.
peer
associates a role with an OS user, so e.g. only the Linux userpostgres
can connect as thepostgres
role (only works for local connections)
CREATE ROLE <name> LOGIN;
-- allow role to create databases
ALTER ROLE <name> CREATEDB;
-- allow role to create other roles
ALTER ROLE <name> CREATEROLE;
-- create a database with an owner
CREATE DATABASE <dbname> OWNER <role>;
-- give full access to a table to a role
GRANT SELECT, INSERT, UPDATE, DELETE ON TABLE <table_name> TO <role>;
-- or: GRANT ALL PRIVILEGES
-- give access to sequence (e.g., primary key)
GRANT USAGE, SELECT ON SEQUENCE <table>_<column>_seq TO <role>;
-- revoke privileges
REVOKE ALL PRIVILEGES ON TABLE <table_name> FROM <role>;
-- grant all privileges on all existing tables
GRANT ALL PRIVILEGES ON ALL TABLES IN SCHEMA public TO <role>;
-- grant all privileges on all future tables
ALTER DEFAULT PRIVILEGES IN SCHEMA public
GRANT ALL PRIVILEGES ON TABLES TO <role>;
-- list roles
SELECT rolname FROM pg_roles;
-- create role if not exists
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_catalog.pg_roles WHERE rolname = '...'
) THEN CREATE ROLE <name> LOGIN;
END IF;
END
$$;
-- rename role
ALTER ROLE <old_name> RENAME TO <new_name>;
-- drop role
REASSIGN OWNED BY <old_role> TO <new_role>;
DROP OWNED BY <old_role>;
DROP ROLE <old_role>;
Table ownership
Who owns a table?
SELECT tablename, tableowner FROM pg_tables;
Change ownership:
ALTER TABLE <table> OWNER TO <user>;
Create an index
https://www.postgresql.org/docs/current/sql-createindex.html
CREATE INDEX ON <table>(<column>);
-- index on expression
CREATE INDEX ON <table>((lower(path)));
-- unique index, with explicit name
CREATE UNIQUE INDEX path_idx ON <table>(path);
Create a view
https://www.postgresql.org/docs/current/sql-createview.html
CREATE VIEW vw_whatever AS
SELECT *
FROM t;
- Apparently there is no equivalent to
CREATE TABLE IF NOT EXISTS
, though there isCREATE OR REPLACE VIEW
. *
is expanded into a list of columns at the time the view is created. Any columns added to the underlying table later will not be part of the view.
Profiling and optimization
Disk usage
Get disk usage of each table in the database:
SELECT
schemaname AS schema,
relname AS table,
pg_size_pretty(pg_total_relation_size(relid)) AS total_size,
pg_size_pretty(pg_relation_size(relid)) AS table_only,
pg_size_pretty(pg_total_relation_size(relid) -
pg_relation_size(relid)) AS indexes_and_toast
FROM pg_catalog.pg_statio_user_tables
ORDER BY pg_total_relation_size(relid) DESC;
SELECT pg_size_pretty(pg_total_relation_size('<table>'))
to see a table's total size (including indexes)SELECT pg_database_size('<db>')
to see a database's total size on disk
Current activity
- To see the current activity of each server process, you can query the
pg_stat_activity
table. For example,SELECT pid, user, state, query, now() - pg_stat_activity.query_start AS query_time FROM pg_stat_activity
.- You may need to run
GRANT pg_read_all_stats TO <username>
to access this table.
- You may need to run
Query optimization
- Use
EXPLAIN <query>
to see the database's query plan for a given query.
Tips
SELECT reltuples AS estimate FROM pg_class WHERE relname = 'tablename';
will show an approximate count of the number of rows in a table. This will be much faster thanSELECT COUNT(*) from tablename
.- Using
varchar(n)
is not more space-efficient than unboundedtext
; however it may still be worth it to constrain field length. (brandur, 2021)