This article is half-done without your Comment! *** Please share your thoughts via Comment ***
In this post, I am sharing a script to measure the size of a PostgreSQL Table Row.
I taken reference from this dba.statckexchange.
But again, I would like to share this information with some additional information.
Fillfactor storage parameter of PostgreSQL Table.
Before changing the default value of Fillfactor, we should measure the size of Table Row.
For knowing the row size is very important because if table row size is larger, we should not change the default value of Fillfactor.
When we are doing performance optimization, this is very important to find the size of the Data page and Table row, otherwise unnecessary we are dealing with high fragmentation and executing VACUUM FULL or VACUUM again and again.
If your total row size is under 8kb, you can take decision to alter table storage parameters.
Create sample table using JSON data type:
1 2 3 4 5 6 7 |
CREATE TABLE tbl_TestJSON ( ID INTEGER PRIMARY KEY ,DepartName VARCHAR(250) ,EmployeeDetails JSON ,Address JSON ); |
Insert few sample JSON formatted record:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 |
INSERT INTO tbl_TestJSON VALUES ( 1 ,'Sales' ,'{"firstName": "Anvesh", "lastName": "Patel"}' ,' {"address" : { "India": "Hyderabad" ,"USA": "Newyork" } }' ) ,( 2 ,'Production' ,'{"firstName": "Neevan", "lastName": "Patel"}' ,' {"address" : { "India": "Ahmedabad" ,"USA": "Washington DC" } }' ) ,( 3 ,'Animation' ,'{"firstName": "Eric", "lastName": "Lorn"}' ,' {"address" : { "India": "Mumbai" ,"USA": "Chicago" } }' ); |
Script to measure the size of Table row and Data page:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 |
WITH cteTableInfo AS ( SELECT COUNT(1) AS ct ,SUM(length(t::text)) AS TextLength ,'public.tbl_testjson'::regclass AS TableName FROM public.tbl_testjson AS t ) ,cteRowSize AS ( SELECT ARRAY [pg_relation_size(TableName) , pg_relation_size(TableName, 'vm') , pg_relation_size(TableName, 'fsm') , pg_table_size(TableName) , pg_indexes_size(TableName) , pg_total_relation_size(TableName) , TextLength ] AS val , ARRAY ['Total Relation Size' , 'Visibility Map' , 'Free Space Map' , 'Table Included Toast Size' , 'Indexes Size' , 'Total Toast and Indexes Size' , 'Live Row Byte Size' ] AS Name FROM cteTableInfo ) SELECT unnest(name) AS Description ,unnest(val) AS Bytes ,pg_size_pretty(unnest(val)) AS BytesPretty ,unnest(val) / ct AS bytes_per_row FROM cteTableInfo, cteRowSize UNION ALL SELECT '------------------------------', NULL, NULL, NULL UNION ALL SELECT 'TotalRows', ct, NULL, NULL FROM cteTableInfo UNION ALL SELECT 'LiveTuples', pg_stat_get_live_tuples(TableName), NULL, NULL FROM cteTableInfo UNION ALL SELECT 'DeadTuples', pg_stat_get_dead_tuples(TableName), NULL, NULL FROM cteTableInfo; |