Drop Down MenusCSS Drop Down MenuPure CSS Dropdown Menu

find Index Size and Index Usage Statistics

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.
In below script, You can also find occupied size of Indexes, Total tuple read and scan by Indexes.
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;

Comments

Popular posts from this blog

How to find the server is whether standby (slave) or primary(master) in Postgresql replication ?

7 Steps to configure BDR replication in postgresql

How to Get Table Size, Database Size, Indexes Size, schema Size, Tablespace Size, column Size in PostgreSQL Database

Ora2PG - Oracle/MySQL to Postgres DB migration Version 20.0

PostgreSQL Introduction