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 2017 January PostgreSQL: Script to find Index Size and Index Usage Statistics

PostgreSQL: Script to find Index Size and Index Usage Statistics

This article is half-done without your Comment! *** Please share your thoughts via Comment ***

In this post, I am sharing one script to find Index Usage Statistics of PostgreSQL Database.
This is a very useful script for DBA to find out the usage of indexes and size of indexes which help them for performance tuning activity.

For DBA, working with Indexes is always important tasks so I have already shared a couple of articles on PostgreSQL Indexes.

Duplicate Indexes:
Missing Indexes:
Expression Index:
BRIN Index:

In below script, You can also find occupied size of Indexes, Total tuple read and scan by Indexes.

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
SELECT
pt.tablename AS TableName
,t.indexname AS IndexName
,pc.reltuples AS TotalRows
,pg_size_pretty(pg_relation_size(quote_ident(pt.tablename)::text)) AS TableSize
,pg_size_pretty(pg_relation_size(quote_ident(t.indexrelname)::text)) AS IndexSize
,t.idx_scan AS TotalNumberOfScan
,t.idx_tup_read AS TotalTupleRead
,t.idx_tup_fetch AS TotalTupleFetched
FROM pg_tables AS pt
LEFT OUTER JOIN pg_class AS pc
ON pt.tablename=pc.relname
LEFT OUTER JOIN
(
SELECT
pc.relname AS TableName
,pc2.relname AS IndexName
,psai.idx_scan
,psai.idx_tup_read
,psai.idx_tup_fetch
,psai.indexrelname
FROM pg_index AS pi
JOIN pg_class AS pc
ON pc.oid = pi.indrelid
JOIN pg_class AS pc2
ON pc2.oid = pi.indexrelid
JOIN pg_stat_all_indexes AS psai
ON pi.indexrelid = psai.indexrelid
)AS T
ON pt.tablename = T.TableName
WHERE pt.schemaname='public'
ORDER BY 1;

Jan 17, 2017Anvesh Patel
PostgreSQL psql FATAL: error Peer authentication failed for userPostgreSQL: Script to find size of all Databases of Server
Comments: 5
  1. Jo
    May 15, 2018 at 10:12 am

    This does not work while having multiple user defined schemas and while queried on one of the schemas alone.

    • Anvesh Patel
      Anvesh Patel
      May 15, 2018 at 7:42 pm

      Use IN condition and give multiple schemas

  2. Jay
    August 22, 2018 at 5:56 am

    SELECT
    pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size
    FROM pg_tables t
    WHERE t.schemaname=’public’

    – For this it is working fine and gives details of public schema But if I change the schema name it says relation “table inside the schema name” does not exist

    • Anvesh Patel
      Anvesh Patel
      August 22, 2018 at 8:02 pm

      Yup valid error, give schema name outside only

  3. Bassel
    March 18, 2020 at 1:11 pm

    Great efforts and really appreciated.

    I need to know something. The indexes with total number of scan ‘0’, it will be better if I delete them ?

Anvesh Patel
Anvesh Patel

Database Engineer

January 17, 2017 PostgreSQL, PostgreSQL DBA ScriptAnvesh Patel, BRIN Index, database, database research and development, dbrnd, index duplicate, Index statestics, index usage, missing index, 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....