天天看點

HGDB wal檔案産生量統計

作者:瀚高PG實驗室 (Highgo PG Lab)

目錄

環境

文檔用途

詳細資訊

環境

系統平台:Linux x86 Red Hat Enterprise Linux 5,Linux x86 Red Hat Enterprise Linux 6,Linux x86 SLES 11,Linux x86-64 Red Hat Enterprise Linux 5,Linux x86-64 Red Hat Enterprise Linux 6,Linux x86-64 Red Hat Enterprise Linux 7,Linux x86-64 SLES 11,Linux x86-64 SLES 12,Microsoft Windows (32-bit) 2003 R2,Microsoft Windows (32-bit) 2003,Microsoft Windows (32-bit) 2008,Microsoft Windows (32-bit) 7,Microsoft Windows (32-bit) 8,Microsoft Windows (32-bit) 8.1,Microsoft Windows (64-bit) 2003 R2,Microsoft Windows (64-bit) 2008 SP2,Microsoft Windows (64-bit) 2008,Microsoft Windows (64-bit) 2008 R2,Microsoft Windows (64-bit) 2012,Microsoft Windows (64-bit) 2012 R2,Microsoft Windows (64-bit) 7,Microsoft Windows (64-bit) 8,Microsoft Windows (64-bit) 8.1,Microsoft Windows (64-bit) 10,Microsoft Windows (64-bit) XP,中科方德(CPU兆芯),普華Linux(CPU龍芯),中标麒麟(CPU申威)7,中标麒麟(CPU海光)7,中标麒麟(CPU龍芯)6,中标麒麟(CPU飛騰)6,中标麒麟(CPU龍芯)7,中标麒麟(CPU飛騰)7,中标麒麟 (CPU x86-64) 6

版本:5.6.5,5.6.4,5.6.3,5.6.1,4.3.4.8,4.3.4.7,4.3.4.6,4.3.4.5,4.3.4.4,4.3.4.3,4.3.4.2,4.3.4,4.7.8,4.7.7,4.7.6,4.7.5,4.3.2,4.1.1

文檔用途

本文提供企業版及安全版下,查詢wal文檔的産生量及各個時段的産生量的SQL語句。

詳細資訊

本文提供的SQL語句因涉及通路作業系統檔案,普通使用者沒有權限,需要使用資料庫的管理者使用者。

1、企業版V5、安全版V4及更新版本,使用如下SQL語句進行查詢,不區分作業系統平台。

select to_char(date_trunc('day',wal.modification),'yyyymmdd') as day_id,

        sum(case when date_part('hour',wal.modification) >=0 and date_part('hour',wal.modification) <24 then 1 else 0 end) as wal_all,

        sum(case when date_part('hour',wal.modification) >=0 and date_part('hour',wal.modification) <1 then 1 else 0 end) as wal_00_01,

        sum(case when date_part('hour',wal.modification) >=1 and date_part('hour',wal.modification) <2 then 1 else 0 end) as wal_01_02,

        sum(case when date_part('hour',wal.modification) >=2 and date_part('hour',wal.modification) <3 then 1 else 0 end) as wal_02_03,

        sum(case when date_part('hour',wal.modification) >=3 and date_part('hour',wal.modification) <4 then 1 else 0 end) as wal_03_04,

        sum(case when date_part('hour',wal.modification) >=4 and date_part('hour',wal.modification) <5 then 1 else 0 end) as wal_04_05,

        sum(case when date_part('hour',wal.modification) >=5 and date_part('hour',wal.modification) <6 then 1 else 0 end) as wal_05_06,

        sum(case when date_part('hour',wal.modification) >=6 and date_part('hour',wal.modification) <7 then 1 else 0 end) as wal_06_07,

        sum(case when date_part('hour',wal.modification) >=7 and date_part('hour',wal.modification) <8 then 1 else 0 end) as wal_07_08,

        sum(case when date_part('hour',wal.modification) >=8 and date_part('hour',wal.modification) <9 then 1 else 0 end) as wal_08_09,

        sum(case when date_part('hour',wal.modification) >=9 and date_part('hour',wal.modification) <10 then 1 else 0 end) as wal_09_10,

        sum(case when date_part('hour',wal.modification) >=10 and date_part('hour',wal.modification) <11 then 1 else 0 end) as wal_10_11,

        sum(case when date_part('hour',wal.modification) >=11 and date_part('hour',wal.modification) <12 then 1 else 0 end) as wal_11_12,

        sum(case when date_part('hour',wal.modification) >=12 and date_part('hour',wal.modification) <13 then 1 else 0 end) as wal_12_13,

        sum(case when date_part('hour',wal.modification) >=13 and date_part('hour',wal.modification) <14 then 1 else 0 end) as wal_13_14,

        sum(case when date_part('hour',wal.modification) >=14 and date_part('hour',wal.modification) <15 then 1 else 0 end) as wal_14_15,

        sum(case when date_part('hour',wal.modification) >=15 and date_part('hour',wal.modification) <16 then 1 else 0 end) as wal_15_16,

        sum(case when date_part('hour',wal.modification) >=16 and date_part('hour',wal.modification) <17 then 1 else 0 end) as wal_16_17,

        sum(case when date_part('hour',wal.modification) >=17 and date_part('hour',wal.modification) <18 then 1 else 0 end) as wal_17_18,

        sum(case when date_part('hour',wal.modification) >=18 and date_part('hour',wal.modification) <19 then 1 else 0 end) as wal_18_19,

        sum(case when date_part('hour',wal.modification) >=19 and date_part('hour',wal.modification) <20 then 1 else 0 end) as wal_19_20,

        sum(case when date_part('hour',wal.modification) >=20 and date_part('hour',wal.modification) <21 then 1 else 0 end) as wal_20_21,

        sum(case when date_part('hour',wal.modification) >=21 and date_part('hour',wal.modification) <22 then 1 else 0 end) as wal_21_22,

        sum(case when date_part('hour',wal.modification) >=22 and date_part('hour',wal.modification) <23 then 1 else 0 end) as wal_22_23,

        sum(case when date_part('hour',wal.modification) >=23 and date_part('hour',wal.modification) <24 then 1 else 0 end) as wal_23_24

from (select * from  pg_ls_waldir()) wal

where wal.name not in ('archive_status')

  and wal.name not like '%.backup'

group by to_char(date_trunc('day',wal.modification),'yyyymmdd')

order by to_char(date_trunc('day',wal.modification),'yyyymmdd') desc;

執行結果中會統計出,每天各個時段的wal産生量。

2、企業版V4在Linux下的查詢語句

with tmp_file as (

    select t1.file,

           t1.file_ls,

           (pg_stat_file(t1.file)).modification as modification,

           round( ((pg_stat_file(t1.file)).size)/1024/1024*1.0,1) as log_size_mb

      from (select dir||'/'||pg_ls_dir(t0.dir) as file,

                   pg_ls_dir(t0.dir) as file_ls

              from (select 'pg_xlog'::text as dir) t0

            ) t1

更多詳細資訊請登入【瀚高技術支援平台】檢視https://support.highgo.com/#/index/docContentHighgo/c3287e0301672491