Thursday, June 19, 2025

Postgres: List all RANGE partitions, sorted by their range start value

My table contains 180 partitons, and looks like this when described in psql:
mydb=> \d mytable
      Partitioned table "myschema.mytable"
      Column       |           Type           | Collation | Nullable |           Default            
-------------------+--------------------------+-----------+----------+------------------------------
 id                | bigint                   |           | not null | generated always as identity
 ad_updtud_log_id  | bigint                   |           | not null | 
 period            | integer                  |           | not null | 
 created           | timestamp with time zone |           | not null | 
Partition key: RANGE (id)
Indexes:
    "mytable_pkey" PRIMARY KEY, btree (id, periode)
    "mytable_id_index" btree (im_oppsum_logg_id)
    "mytable_opprettet_index" btree (opprettet)
Foreign-key constraints:
    "fk_mytable" FOREIGN KEY (ad_updtud_log_id, period) REFERENCES mytable2(id, period)
Number of partitions: 180 (Use \d+ to list them.)
This is how you can list all partitions belonging to a range-partitioned table in postgreSQL, based on the values:
SELECT
    child.relname AS partition_name,
    regexp_replace(pg_get_expr(child.relpartbound, child.oid), '.*FROM \(''(\d+).*', '\1')::bigint AS range_start,
    pg_get_expr(child.relpartbound, child.oid) AS partition_range
FROM pg_inherits
JOIN pg_class parent ON pg_inherits.inhparent = parent.oid
JOIN pg_class child ON pg_inherits.inhrelid = child.oid
JOIN pg_namespace nm ON nm.oid = child.relnamespace
WHERE parent.relname = 'mytable'
  AND nm.nspname = 'myschema'
ORDER BY range_start;
Result (excerpt only):
   partition_name   | range_start | partition_range                  
---------------------------------------+-------------+--------------------------------------------
 mytable_0	    |           0 | FOR VALUES FROM ('0') TO ('30000000')
 mytable_30000000   |    30000000 | FOR VALUES FROM ('30000000') TO ('60000000')
 mytable_60000000   |    60000000 | FOR VALUES FROM ('60000000') TO ('90000000')
 mytable_90000000   |    90000000 | FOR VALUES FROM ('90000000') TO ('120000000')
 mytable_120000000  |   120000000 | FOR VALUES FROM ('120000000') TO ('150000000')
 mytable_150000000  |   150000000 | FOR VALUES FROM ('150000000') TO ('180000000')
 mytable_180000000  |   180000000 | FOR VALUES FROM ('180000000') TO ('210000000')
 mytable_210000000  |   210000000 | FOR VALUES FROM ('210000000') TO ('240000000')
 mytable_240000000  |   240000000 | FOR VALUES FROM ('240000000') TO ('270000000')
 mytable_270000000  |   270000000 | FOR VALUES FROM ('270000000') TO ('300000000')
 mytable_300000000  |   300000000 | FOR VALUES FROM ('300000000') TO ('330000000')
 mytable_330000000  |   330000000 | FOR VALUES FROM ('330000000') TO ('360000000')
 mytable_360000000  |   360000000 | FOR VALUES FROM ('360000000') TO ('390000000')
 mytable_390000000  |   390000000 | FOR VALUES FROM ('390000000') TO ('420000000')
 mytable_420000000  |   420000000 | FOR VALUES FROM ('420000000') TO ('450000000')
 mytable_450000000  |   450000000 | FOR VALUES FROM ('450000000') TO ('480000000')
 

No comments:

Post a Comment