운영중인 DB가 느려진 것 같아서 인덱스 리빌드를 결정했다.

대상 선정을 위한 쿼리를 만들어 보았다.

SELECT
    PSUI.schemaname
    , PSUI.relname AS table_name
    , PSUI.indexrelname AS index_name
    , PSUI.idx_scan /* 인덱스가 사용된 횟수 */
    , PSUI.idx_tup_read /* 인덱스 튜플 수 */
    , PSUI.idx_tup_fetch /* 인덱스에서 실제 검색된 튜플 수 */
    , pg_size_pretty(pg_relation_size(PSAI.indexrelid)) AS index_size /* 인덱스의 크기 */
    , 'REINDEX INDEX CONCURRENTLY ' || PSUI.schemaname || '.' || PSUI.indexrelname || ';'
FROM pg_stat_user_indexes PSUI
    LEFT OUTER JOIN pg_stat_all_indexes PSAI
        ON PSAI.relname = PSUI.relname
        AND PSAI.indexrelname = PSUI.indexrelname
ORDER BY PSUI.idx_tup_read DESC, PSUI.idx_scan DESC, pg_relation_size(PSAI.indexrelid) DESC
;
------------------------------------------------------------------------------------------------------------------------
-- 거의 사용되니 않는 인덱스 -> 삭제하는 게 나을 수 있겠다
SELECT
    PSUI.schemaname
    , PSUI.relname AS table_name
    , PSUI.indexrelname AS index_name
    , PSUI.idx_scan /* 인덱스가 사용된 횟수 */
    , PSUI.idx_tup_read /* 인덱스 튜플 수 */
    , PSUI.idx_tup_fetch /* 인덱스에서 실제 검색된 튜플 수 */
    , pg_size_pretty(pg_relation_size(PSAI.indexrelid)) AS index_size /* 인덱스의 크기 */
    , 'REINDEX INDEX CONCURRENTLY ' || PSUI.schemaname || '.' || PSUI.indexrelname || ';'
FROM pg_stat_user_indexes PSUI
    LEFT OUTER JOIN pg_stat_all_indexes PSAI
        ON PSAI.relname = PSUI.relname
        AND PSAI.indexrelname = PSUI.indexrelname
WHERE PSUI.idx_scan < 100
ORDER BY PSUI.idx_scan DESC
;
------------------------------------------------------------------------------------------------------------------------
-- 크기가 너무 큰 인덱스
SELECT
    PSUI.schemaname
    , PSUI.relname AS table_name
    , PSUI.indexrelname AS index_name
    , PSUI.idx_scan /* 인덱스가 사용된 횟수 */
    , PSUI.idx_tup_read /* 인덱스 튜플 수 */
    , PSUI.idx_tup_fetch /* 인덱스에서 실제 검색된 튜플 수 */
    , pg_size_pretty(pg_relation_size(PSAI.indexrelid)) AS index_size /* 인덱스의 크기 */
    , 'REINDEX INDEX CONCURRENTLY ' || PSUI.schemaname || '.' || PSUI.indexrelname || ';'
FROM pg_stat_user_indexes PSUI
    LEFT OUTER JOIN pg_stat_all_indexes PSAI
        ON PSAI.relname = PSUI.relname
        AND PSAI.indexrelname = PSUI.indexrelname
ORDER BY pg_relation_size(PSAI.indexrelid) DESC
LIMIT 50
;
------------------------------------------------------------------------------------------------------------------------
-- 테이블 싸이즈에 비해 크기가 너무 큰 인덱스
SELECT
    PSUI.schemaname
    , PSUI.relname AS table_name
    , PSUI.indexrelname AS index_name
    , PSUI.idx_scan /* 인덱스가 사용된 횟수 */
    , PSUI.idx_tup_read /* 인덱스 튜플 수 */
    , PSUI.idx_tup_fetch /* 인덱스에서 실제 검색된 튜플 수 */
    , pg_size_pretty(pg_relation_size(PSAI.indexrelid)) AS index_size /* 인덱스의 크기 */
    , pg_size_pretty(pg_relation_size(T.oid)) AS table_size /* 테이블의 크기 */
    , ROUND(pg_relation_size(PSAI.indexrelid)::numeric / pg_relation_size(T.oid) * 100, 2) AS INDEX_RATIO
    , 'REINDEX INDEX CONCURRENTLY ' || PSUI.schemaname || '.' || PSUI.indexrelname || ';'
FROM pg_stat_user_indexes PSUI
    INNER JOIN pg_class T
        ON PSUI.relname = T.relname
    LEFT OUTER JOIN pg_stat_all_indexes PSAI
        ON PSAI.relname = PSUI.relname
        AND PSAI.indexrelname = PSUI.indexrelname
WHERE pg_relation_size(T.oid) > 0
AND pg_relation_size(PSAI.indexrelid) > 0
AND PSUI.idx_scan > 0
AND ROUND(pg_relation_size(PSAI.indexrelid)::numeric / pg_relation_size(T.oid) * 100, 2) > 100
ORDER BY INDEX_RATIO DESC
LIMIT 50
;
------------------------------------------------------------------------------------------------------------------------
-- 오래된 인덱스
SELECT
    PSUI.schemaname
    , PSUI.relname AS table_name
    , PSUI.indexrelname AS index_name
    , PSUI.idx_scan /* 인덱스가 사용된 횟수 */
    , PSUI.idx_tup_read /* 인덱스 튜플 수 */
    , PSUI.idx_tup_fetch /* 인덱스에서 실제 검색된 튜플 수 */
    , pg_size_pretty(pg_relation_size(PSAI.indexrelid)) AS index_size /* 인덱스의 크기 */
    , pg_stat_get_last_vacuum_time(PSAI.indexrelid) AS last_vacumm
    , 'REINDEX INDEX CONCURRENTLY ' || PSUI.schemaname || '.' || PSUI.indexrelname || ';'
FROM pg_stat_user_indexes PSUI
    LEFT OUTER JOIN pg_stat_all_indexes PSAI
        ON PSAI.relname = PSUI.relname
        AND PSAI.indexrelname = PSUI.indexrelname
WHERE PSUI.idx_scan = 0
OR PSAI.idx_scan = 0
ORDER BY last_vacumm ASC NULLS FIRST
;
728x90
반응형

+ Recent posts