Last active
May 4, 2021 10:36
-
-
Save jehaby/2f654ed6ceb7cf89b668d7f00c3f92b9 to your computer and use it in GitHub Desktop.
jsonb storage size bench
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
-- Check "JSONB storage does not deduplicate the key names in the JSON. This can result in considerably larger storage footprint.. " from https://scalegrid.io/blog/using-jsonb-in-postgresql-how-to-effectively-store-index-json-data-in-postgresql/ | |
create table jt_1 (a integer, b numeric, c text); | |
create table jt_2 (data jsonb); | |
create table jt_3 (data jsonb); | |
create table jt_4 (data jsonb); | |
-- 10 million records for jt_1 and jt_2 | |
insert into jt_1 SELECT (random() * 100000)::integer, | |
(random() * 1000000)::numeric, | |
md5(random()::text) FROM generate_series(1, 10000000); | |
insert into jt_2 SELECT jsonb_build_object('aaa', (random() * 100000)::integer, | |
'bbb', (random() * 1000000), | |
'ccc', md5(random()::text)) FROM generate_series(1, 10000000); | |
-- 1 million records for jt_3 and jt_4 | |
insert into jt_3 SELECT jsonb_build_object('aaa', (random() * 100000)::integer, | |
'bbb', (random() * 1000000), | |
'ccc', md5(random()::text)) FROM generate_series(1, 1000000); | |
-- longer keys in jt_4 | |
insert into jt_4 SELECT jsonb_build_object('aaa123444378590', (random() * 100000)::integer, | |
'bbbSomeMuchMuchLongerKey', (random() * 1000000), | |
repeat('abcde', 10), md5(random()::text)) FROM generate_series(1, 1000000); | |
-- res * | |
table_name | row_estimate | toast | table | |
------------+---------------+------------+--------- | |
jt_1 | 9.99465e+06 | 8192 bytes | 879 MB | |
jt_2 | 1.0000059e+07 | 8192 bytes | 1281 MB | |
jt_3 | 1e+06 | 8192 bytes | 128 MB | |
jt_4 | 1e+06 | 8192 bytes | 206 MB | |
(4 rows) | |
-- * | |
SELECT table_name | |
, row_estimate | |
, pg_size_pretty(toast_bytes) as toast | |
, pg_size_pretty(table_bytes) AS table | |
FROM ( | |
SELECT *, total_bytes-index_bytes-coalesce(toast_bytes,0) AS table_bytes FROM ( | |
SELECT c.oid,nspname AS table_schema, relname AS table_name | |
, c.reltuples AS row_estimate | |
, pg_total_relation_size(c.oid) AS total_bytes | |
, pg_indexes_size(c.oid) AS index_bytes | |
, pg_total_relation_size(reltoastrelid) AS toast_bytes | |
FROM pg_class c | |
LEFT JOIN pg_namespace n ON n.oid = c.relnamespace | |
WHERE relkind = 'r' | |
) a | |
) a where table_name LIKE 'jt_%'; |
Sign up for free
to join this conversation on GitHub.
Already have an account?
Sign in to comment