Skip to content

Instantly share code, notes, and snippets.

@vpol
Created July 14, 2022 12:51
Show Gist options
  • Save vpol/60037325aaf54d7a533843ebb679694d to your computer and use it in GitHub Desktop.
Save vpol/60037325aaf54d7a533843ebb679694d to your computer and use it in GitHub Desktop.
Function to estimate BTREE index size based on the table and column(s)
CREATE OR REPLACE FUNCTION f_index_minimum_size(_tbl regclass, _cols VARIADIC text[], OUT estimated_minimum_size bigint)
LANGUAGE plpgsql AS
$func$
DECLARE
_missing_column text;
BEGIN
-- assert
SELECT i.attname
FROM unnest(_cols) AS i(attname)
LEFT JOIN pg_catalog.pg_attribute a ON a.attname = i.attname
AND a.attrelid = _tbl
WHERE a.attname IS NULL
INTO _missing_column;
IF FOUND THEN
RAISE EXCEPTION 'Table % has no column named %', _tbl, quote_ident(_missing_column);
END IF;
SELECT INTO estimated_minimum_size
COALESCE(1 + ceil(reltuples/trunc((blocksize-page_overhead)/(4+tuple_size)))::int, 0) * blocksize -- AS estimated_minimum_size
FROM (
SELECT maxalign, blocksize, reltuples, fillfactor, page_overhead
, (maxalign -- up to 16 columns, else nullbitmap may force another maxalign step
+ CASE WHEN datawidth <= maxalign THEN maxalign
WHEN datawidth%maxalign = 0 THEN datawidth
ELSE (datawidth + maxalign) - datawidth%maxalign END -- add padding to the data to align on MAXALIGN
) AS tuple_size
FROM (
SELECT c.reltuples, count(*)
, 90 AS fillfactor
, current_setting('block_size')::bigint AS blocksize
, CASE WHEN version() ~ '64-bit|x86_64|ppc64|ia64|amd64|mingw32' -- MAXALIGN: 4 on 32bits, 8 on 64bits
THEN 8 ELSE 4 END AS maxalign
, 40 AS page_overhead -- 24 bytes page header + 16 bytes "special space"
-- avg data width without null values
, sum(ceil((1-COALESCE(s.null_frac, 0)) * COALESCE(s.avg_width, 1024))::int) AS datawidth -- ceil() because avg width has a low bias
FROM pg_catalog.pg_class c
JOIN pg_catalog.pg_attribute a ON a.attrelid = c.oid
JOIN pg_catalog.pg_stats s ON s.schemaname = c.relnamespace::regnamespace::text
AND s.tablename = c.relname
AND s.attname = a.attname
WHERE c.oid = _tbl
AND a.attname = ANY(_cols) -- all exist, verified above
GROUP BY 1
) sub1
) sub2;
END
$func$;
SELECT pg_size_pretty(f_index_minimum_size('user_post_events', 'user_id', 'post_id'));
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment