PostgreSQL Cheatsheet: A Developer’s Quick Reference
Quick reference to postgresql
Page content
A quick reference for day‑to‑day PostgreSQL work: connections, SQL syntax, psql meta-commands, performance, JSON, window functions, and more.
A concise SQL cheatsheet covering the most essential commands and operations is also available.
Connect & Basics
# Connect
psql -h HOST -p 5432 -U USER -d DB
psql $DATABASE_URL
# Inside psql
\conninfo -- show connection
\l[+] -- list databases
\c DB -- connect to DB
\dt[+] [schema.]pat -- list tables
\dv[+] -- list views
\ds[+] -- list sequences
\df[+] [pat] -- list functions
\d[S+] name -- describe table/view/seq
\dn[+] -- list schemas
\du[+] -- list roles
\timing -- toggle query timing
\x -- expanded display
\e -- edit buffer in $EDITOR
\i file.sql -- run file
\copy ... -- client-side COPY
\! shell_cmd -- run shell command
Data Types (common)
- Numeric:
smallint
,integer
,bigint
,decimal(p,s)
,numeric
,real
,double precision
,serial
,bigserial
- Text:
text
,varchar(n)
,char(n)
- Boolean:
boolean
- Temporal:
timestamp [with/without time zone]
,date
,time
,interval
- UUID:
uuid
- JSON:
json
,jsonb
(preferred) - Array:
type[]
e.g.text[]
- Network:
inet
,cidr
,macaddr
- Geometric:
point
,line
,polygon
, etc.
Check PostgreSQL version
SELECT version();
PostgreSQL Server version:
pg_config --version
PostgreSQL Client version:
psql --version
DDL (Create / Alter)
-- Create schema & table
CREATE SCHEMA IF NOT EXISTS app;
CREATE TABLE app.users (
id bigserial PRIMARY KEY,
email text NOT NULL UNIQUE,
name text,
active boolean NOT NULL DEFAULT true,
created_at timestamptz NOT NULL DEFAULT now(),
profile jsonb,
tags text[]
);
-- Alter
ALTER TABLE app.users ADD COLUMN last_login timestamptz;
ALTER TABLE app.users ALTER COLUMN name SET NOT NULL;
ALTER TABLE app.users DROP COLUMN tags;
-- Constraints
ALTER TABLE app.users ADD CONSTRAINT email_lower_uk UNIQUE (lower(email));
-- Indexes
CREATE INDEX ON app.users (email);
CREATE UNIQUE INDEX CONCURRENTLY users_email_uidx ON app.users (lower(email));
CREATE INDEX users_profile_gin ON app.users USING gin (profile);
CREATE INDEX users_created_at_idx ON app.users (created_at DESC);
DML (Insert / Update / Upsert / Delete)
INSERT INTO app.users (email, name) VALUES
('a@x.com','A'), ('b@x.com','B')
RETURNING id;
-- Upsert (ON CONFLICT)
INSERT INTO app.users (email, name)
VALUES ('a@x.com','Alice')
ON CONFLICT (email)
DO UPDATE SET name = EXCLUDED.name, updated_at = now();
UPDATE app.users SET active = false WHERE last_login < now() - interval '1 year';
DELETE FROM app.users WHERE active = false AND last_login IS NULL;
Querying Essentials
SELECT * FROM app.users ORDER BY created_at DESC LIMIT 20 OFFSET 40; -- pagination
-- Filtering
SELECT * FROM app.users WHERE email ILIKE '%@example.%' AND active;
-- Aggregates & GROUP BY
SELECT active, count(*) AS n
FROM app.users
GROUP BY active
HAVING count(*) > 10;
-- Joins
SELECT o.id, u.email, o.total
FROM app.orders o
JOIN app.users u ON u.id = o.user_id
LEFT JOIN app.discounts d ON d.id = o.discount_id;
-- DISTINCT ON (Postgres-specific)
SELECT DISTINCT ON (user_id) user_id, status, created_at
FROM app.events
ORDER BY user_id, created_at DESC;
-- CTEs
WITH recent AS (
SELECT * FROM app.orders WHERE created_at > now() - interval '30 days'
)
SELECT count(*) FROM recent;
-- Recursive CTE
WITH RECURSIVE t(n) AS (
SELECT 1
UNION ALL
SELECT n+1 FROM t WHERE n < 10
)
SELECT sum(n) FROM t;
Window Functions
SELECT
user_id,
created_at,
sum(total) OVER (PARTITION BY user_id ORDER BY created_at) AS running_total,
row_number() OVER (PARTITION BY user_id ORDER BY created_at) AS rn,
lag(total, 1) OVER (PARTITION BY user_id ORDER BY created_at) AS prev_total
FROM app.orders;
JSON / JSONB
-- Extracting
SELECT profile->>'company' AS company FROM app.users;
SELECT profile->'address'->>'city' FROM app.users;
-- Index for jsonb queries
CREATE INDEX users_profile_company_gin ON app.users USING gin ((profile->>'company'));
-- Existence / containment
SELECT * FROM app.users WHERE profile ? 'company'; -- key exists
SELECT * FROM app.users WHERE profile @> '{"role":"admin"}'; -- contains
-- Update jsonb
UPDATE app.users
SET profile = jsonb_set(COALESCE(profile,'{}'::jsonb), '{prefs,theme}', '"dark"', true);
Arrays
-- membership & containment
SELECT * FROM app.users WHERE 'vip' = ANY(tags);
SELECT * FROM app.users WHERE tags @> ARRAY['beta'];
-- append
UPDATE app.users SET tags = array_distinct(tags || ARRAY['vip']);
Time & Dates
SELECT now() AT TIME ZONE 'Australia/Melbourne';
SELECT date_trunc('day', created_at) AS d, count(*)
FROM app.users GROUP BY d ORDER BY d;
-- Intervals
SELECT now() - interval '7 days';
Transactions & Locks
BEGIN;
UPDATE app.accounts SET balance = balance - 100 WHERE id = 1;
UPDATE app.accounts SET balance = balance + 100 WHERE id = 2;
COMMIT; -- or ROLLBACK
-- Isolation level
SET TRANSACTION ISOLATION LEVEL REPEATABLE READ;
-- Check locks
SELECT * FROM pg_locks l JOIN pg_stat_activity a USING (pid);
Roles & Permissions
-- Create role/user
CREATE ROLE app_user LOGIN PASSWORD 'secret';
GRANT USAGE ON SCHEMA app TO app_user;
GRANT SELECT, INSERT, UPDATE, DELETE ON ALL TABLES IN SCHEMA app TO app_user;
ALTER DEFAULT PRIVILEGES IN SCHEMA app GRANT SELECT, INSERT, UPDATE, DELETE ON TABLES TO app_user;
Import / Export
-- Server-side (requires superuser or proper grants)
COPY app.users TO '/tmp/users.csv' CSV HEADER;
COPY app.users(email,name) FROM '/tmp/users.csv' CSV HEADER;
-- Client-side (psql)
\copy app.users TO 'users.csv' CSV HEADER
\copy app.users(email,name) FROM 'users.csv' CSV HEADER
Performance & Observability
EXPLAIN (ANALYZE, BUFFERS, VERBOSE) SELECT ...; -- actual runtime
-- Stats views
SELECT * FROM pg_stat_user_tables;
SELECT * FROM pg_stat_statements ORDER BY total_time DESC LIMIT 20; -- needs extension
-- Maintenance
VACUUM [FULL] [VERBOSE] table_name;
ANALYZE table_name;
REINDEX TABLE table_name;
Enable extensions as needed:
CREATE EXTENSION IF NOT EXISTS pg_stat_statements;
CREATE EXTENSION IF NOT EXISTS btree_gin;
CREATE EXTENSION IF NOT EXISTS pg_trgm; -- trigram search
Full‑Text Search (quick)
ALTER TABLE app.docs ADD COLUMN tsv tsvector;
UPDATE app.docs SET tsv = to_tsvector('english', coalesce(title,'') || ' ' || coalesce(body,''));
CREATE INDEX docs_tsv_idx ON app.docs USING gin(tsv);
SELECT id FROM app.docs WHERE tsv @@ plainto_tsquery('english', 'quick brown fox');
Useful psql Settings
\pset pager off -- disable pager
\pset null '∅'
\pset format aligned -- other: unaligned, csv
\set ON_ERROR_STOP on
\timing on
Handy Catalog Queries
-- Table size
SELECT relname, pg_size_pretty(pg_total_relation_size(relid)) AS size
FROM pg_catalog.pg_statio_user_tables ORDER BY pg_total_relation_size(relid) DESC;
-- Index bloat (approx)
SELECT schemaname, relname, indexrelname, idx_scan
FROM pg_stat_user_indexes ORDER BY idx_scan ASC NULLS FIRST LIMIT 20;
Backup / Restore
# Logical dump
pg_dump -h HOST -U USER -d DB -F c -f db.dump # custom format
pg_restore -h HOST -U USER -d NEW_DB -j 4 db.dump
# Plain SQL
pg_dump -h HOST -U USER -d DB > dump.sql
psql -h HOST -U USER -d DB -f dump.sql
Replication (high‑level)
- WAL files stream from primary → standby
- Key settings:
wal_level
,max_wal_senders
,hot_standby
,primary_conninfo
- Tools:
pg_basebackup
,standby.signal
(PG ≥12)
Gotchas & Tips
- Always use
jsonb
, notjson
, for indexing & operators. - Prefer
timestamptz
(timezone-aware). DISTINCT ON
is Postgres gold for “top‑N per group”.- Use
GENERATED ALWAYS AS IDENTITY
instead ofserial
. - Avoid
SELECT *
in production queries. - Create indexes for selective filters and join keys.
- Measure with
EXPLAIN (ANALYZE)
before optimizing.
Version‑specific niceties (≥v12+)
-- Generated identity
CREATE TABLE t (id bigINT GENERATED ALWAYS AS IDENTITY, ...);
-- UPSERT with partial index
CREATE UNIQUE INDEX ON t (key) WHERE is_active;