Database Research & Development

  • Home
  • NoSQL
    • NoSQL
    • Cassandra
  • Databases
    • Database Theory
    • Database Designing
    • SQL Server Coding Standards
    • SQL Server
    • PostgreSQL
    • MySQL
    • Greenplum
    • Linux
  • Interviews
    • SQL Server Interviews
    • MySQL Interviews
    • SQL Puzzles
  • DBA Scripts
    • SQL Server DBA Scripts
    • PostgreSQL DBA Scripts
    • MySQL DBA Scripts
    • Greenplum DBA Scripts
  • Home
  • Blog Archives !
  • (: Laugh@dbrnd :)
  • Contact Me !
sqlserverinterviews
Home 2016 March PostgreSQL: How to measure the size of a Table Row and Data Page?

PostgreSQL: How to measure the size of a Table Row and Data Page?

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;

Mar 29, 2016Anvesh Patel
PostgreSQL: The Awesome Table Fillfactor to speedup UPDATE and SELECT statementPostgreSQL: ALTER TABLE to change Fillfactor Value
Comments: 7
  1. Ronnie
    November 16, 2016 at 12:17 am

    ERROR: relation “public.tbl_testjson” does not exist
    LINE 7: FROM public.tbl_testjson AS t

    • Anvesh Patel
      Anvesh Patel
      November 17, 2016 at 5:49 pm

      Thank you Ronnie for this update.
      I have modified this article. Please visit again.
      Thanks,

  2. dheer choudhary
    August 23, 2017 at 6:14 am

    hello sir i have a question about postgresql database

    • Anvesh Patel
      Anvesh Patel
      August 23, 2017 at 6:39 am

      please tell me or contact me

  3. ptcgh
    October 19, 2017 at 12:03 am

    i find you use “SUM(length(t::text)) AS TextLength” ,how about these words used in a big table?

  4. Alok Mishra
    July 2, 2018 at 6:24 am

    what do you mean by “your total row size is under 8kb”… If I do “tuple_len / tuple_count”, I get average tuple size (tuple size of a single row).
    So, should I consider this average tuple size (tuple size of a single row) and compare it wth 8kb block size? If not, can you please explain your sentence?
    Thanks for your help.

    • Anvesh Patel
      Anvesh Patel
      July 3, 2018 at 7:10 pm

      Hey Alok,

      You are right, that was my mistake. It is 8kb data page size not a row size, but if a row size is 7kb then we should spare some free space for future alter. So we have to check the size of the row as well.

      If I am wrong, please correct me.

      I can see that you are from EnterpriseDB so please share some more internal on this and later I will update this article accordingly.

Anvesh Patel
Anvesh Patel

Database Engineer

March 29, 2016 PostgreSQL, PostgreSQL DBA ScriptAnvesh Patel, database, database research and development, dbrnd, Fillfactor, measure, plpgsql, Postgres Query, postgresql, PostgreSQL Administrator, PostgreSQL Error, PostgreSQL Programming, PostgreSQL Tips and Tricks
About Me!

I'm Anvesh Patel, a Database Engineer certified by Oracle and IBM. I'm working as a Database Architect, Database Optimizer, Database Administrator, Database Developer. Providing the best articles and solutions for different problems in the best manner through my blogs is my passion. I have more than six years of experience with various RDBMS products like MSSQL Server, PostgreSQL, MySQL, Greenplum and currently learning and doing research on BIGData and NoSQL technology. -- Hyderabad, India.

About DBRND !

dbrnd

This is a personal blog (www.dbrnd.com).

Any views or opinions represented in this blog are personal and belong solely to the blog owner and do not represent those of people, institutions or organizations that the owner may or may not be associated with in professional or personal capacity, unless explicitly stated.

Feel free to challenge me, disagree with me, or tell me I’m completely nuts in the comments section of each blog entry, but I reserve the right to delete any comment for any reason whatsoever (abusive, profane, rude, or anonymous comments) - so keep it polite.

The content of this website is protected by copyright. No portion of this website may be copied or replicated in any form without the written consent of the website owner.

Recent Comments !
  • Anvesh Patel { Sure will do... } – May 27, 12:43 PM
  • Anvesh Patel { Great... } – May 27, 12:41 PM
  • Anvesh Patel { Great... } – May 27, 12:39 PM
  • Anvesh Patel { Great... } – May 27, 12:36 PM
  • Anvesh Patel { Great... } – May 27, 12:28 PM
  • Anvesh Patel { Great... } – May 27, 12:27 PM
  • Anvesh Patel { Great... } – May 27, 12:16 PM
  • Older »
Follow Me !
  • facebook
  • linkedin
  • twitter
  • youtube
  • google
  • flickr
© 2015 – 2019 All rights reserved. Database Research & Development (dbrnd.com)
Posting....