目录
环境
文档用途
详细信息
环境
系统平台: 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
)
select to_char(date_trunc('day',tf0.modification),'yyyymmdd') as day,
sum(case when date_part('hour',tf0.modification) >=0 and date_part('hour',tf0.modification) <24 then 1 else 0 end) as all,
sum(case when date_part('hour',tf0.modification) >=0 and date_part('hour',tf0.modification) <1 then 1 else 0 end) as w0_01,
sum(case when date_part('hour',tf0.modification) >=1 and date_part('hour',tf0.modification) <2 then 1 else 0 end) as w1_02,
sum(case when date_part('hour',tf0.modification) >=2 and date_part('hour',tf0.modification) <3 then 1 else 0 end) as w2_03,
sum(case when date_part('hour',tf0.modification) >=3 and date_part('hour',tf0.modification) <4 then 1 else 0 end) as w3_04,
sum(case when date_part('hour',tf0.modification) >=4 and date_part('hour',tf0.modification) <5 then 1 else 0 end) as w4_05,
sum(case when date_part('hour',tf0.modification) >=5 and date_part('hour',tf0.modification) <6 then 1 else 0 end) as w5_06,
sum(case when date_part('hour',tf0.modification) >=6 and date_part('hour',tf0.modification) <7 then 1 else 0 end) as w6_07,
sum(case when date_part('hour',tf0.modification) >=7 and date_part('hour',tf0.modification) <8 then 1 else 0 end) as w7_08,
sum(case when date_part('hour',tf0.modification) >=8 and date_part('hour',tf0.modification) <9 then 1 else 0 end) as w8_09,
sum(case when date_part('hour',tf0.modification) >=9 and date_part('hour',tf0.modification) <10 then 1 else 0 end) as w9_10,
sum(case when date_part('hour',tf0.modification) >=10 and date_part('hour',tf0.modification) <11 then 1 else 0 end) as wal_10_11,
sum(case when date_part('hour',tf0.modification) >=11 and date_part('hour',tf0.modification) <12 then 1 else 0 end) as wal_11_12,
sum(case when date_part('hour',tf0.modification) >=12 and date_part('hour',tf0.modification) <13 then 1 else 0 end) as wal_12_13,
sum(case when date_part('hour',tf0.modification) >=13 and date_part('hour',tf0.modification) <14 then 1 else 0 end) as wal_13_14,
sum(case when date_part('hour',tf0.modification) >=14 and date_part('hour',tf0.modification) <15 then 1 else 0 end) as wal_14_15,
sum(case when date_part('hour',tf0.modification) >=15 and date_part('hour',tf0.modification) <16 then 1 else 0 end) as wal_15_16,
sum(case when date_part('hour',tf0.modification) >=16 and date_part('hour',tf0.modification) <17 then 1 else 0 end) as wal_16_17,
sum(case when date_part('hour',tf0.modification) >=17 and date_part('hour',tf0.modification) <18 then 1 else 0 end) as wal_17_18,
sum(case when date_part('hour',tf0.modification) >=18 and date_part('hour',tf0.modification) <19 then 1 else 0 end) as wal_18_19,
sum(case when date_part('hour',tf0.modification) >=19 and date_part('hour',tf0.modification) <20 then 1 else 0 end) as wal_19_20,
sum(case when date_part('hour',tf0.modification) >=20 and date_part('hour',tf0.modification) <21 then 1 else 0 end) as wal_20_21,
sum(case when date_part('hour',tf0.modification) >=21 and date_part('hour',tf0.modification) <22 then 1 else 0 end) as wal_21_22,
sum(case when date_part('hour',tf0.modification) >=22 and date_part('hour',tf0.modification) <23 then 1 else 0 end) as wal_22_23,
sum(case when date_part('hour',tf0.modification) >=23 and date_part('hour',tf0.modification) <24 then 1 else 0 end) as wal_23_24
from tmp_file tf0
where tf0.file_ls not in ('archive_status')
and tf0.file_ls not like '%.backup'
group by to_char(date_trunc('day',tf0.modification),'yyyymmdd')
order by to_char(date_trunc('day',tf0.modification),'yyyymmdd') desc;
3、企业版V4在windows下的查询语句
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
)
select to_char(date_trunc('day',tf0.modification),'yyyymmdd') as day,
sum(case when date_part('hour',tf0.modification) >=0 and date_part('hour',tf0.modification) <24 then 1 else 0 end) as all,
sum(case when date_part('hour',tf0.modification) >=0 and date_part('hour',tf0.modification) <1 then 1 else 0 end) as w0_01,
sum(case when date_part('hour',tf0.modification) >=1 and date_part('hour',tf0.modification) <2 then 1 else 0 end) as w1_02,
sum(case when date_part('hour',tf0.modification) >=2 and date_part('hour',tf0.modification) <3 then 1 else 0 end) as w2_03,
sum(case when date_part('hour',tf0.modification) >=3 and date_part('hour',tf0.modification) <4 then 1 else 0 end) as w3_04,
sum(case when date_part('hour',tf0.modification) >=4 and date_part('hour',tf0.modification) <5 then 1 else 0 end) as w4_05,
sum(case when date_part('hour',tf0.modification) >=5 and date_part('hour',tf0.modification) <6 then 1 else 0 end) as w5_06,
sum(case when date_part('hour',tf0.modification) >=6 and date_part('hour',tf0.modification) <7 then 1 else 0 end) as w6_07,
sum(case when date_part('hour',tf0.modification) >=7 and date_part('hour',tf0.modification) <8 then 1 else 0 end) as w7_08,
sum(case when date_part('hour',tf0.modification) >=8 and date_part('hour',tf0.modification) <9 then 1 else 0 end) as w8_09,
sum(case when date_part('hour',tf0.modification) >=9 and date_part('hour',tf0.modification) <10 then 1 else 0 end) as w9_10,
sum(case when date_part('hour',tf0.modification) >=10 and date_part('hour',tf0.modification) <11 then 1 else 0 end) as wal_10_11,
sum(case when date_part('hour',tf0.modification) >=11 and date_part('hour',tf0.modification) <12 then 1 else 0 end) as wal_11_12,
sum(case when date_part('hour',tf0.modification) >=12 and date_part('hour',tf0.modification) <13 then 1 else 0 end) as wal_12_13,
sum(case when date_part('hour',tf0.modification) >=13 and date_part('hour',tf0.modification) <14 then 1 else 0 end) as wal_13_14,
sum(case when date_part('hour',tf0.modification) >=14 and date_part('hour',tf0.modification) <15 then 1 else 0 end) as wal_14_15,
sum(case when date_part('hour',tf0.modification) >=15 and date_part('hour',tf0.modification) <16 then 1 else 0 end) as wal_15_16,
sum(case when date_part('hour',tf0.modification) >=16 and date_part('hour',tf0.modification) <17 then 1 else 0 end) as wal_16_17,
sum(case when date_part('hour',tf0.modification) >=17 and date_part('hour',tf0.modification) <18 then 1 else 0 end) as wal_17_18,
sum(case when date_part('hour',tf0.modification) >=18 and date_part('hour',tf0.modification) <19 then 1 else 0 end) as wal_18_19,
sum(case when date_part('hour',tf0.modification) >=19 and date_part('hour',tf0.modification) <20 then 1 else 0 end) as wal_19_20,
sum(case when date_part('hour',tf0.modification) >=20 and date_part('hour',tf0.modification) <21 then 1 else 0 end) as wal_20_21,
sum(case when date_part('hour',tf0.modification) >=21 and date_part('hour',tf0.modification) <22 then 1 else 0 end) as wal_21_22,
sum(case when date_part('hour',tf0.modification) >=22 and date_part('hour',tf0.modification) <23 then 1 else 0 end) as wal_22_23,
sum(case when date_part('hour',tf0.modification) >=23 and date_part('hour',tf0.modification) <24 then 1 else 0 end) as wal_23_24
from tmp_file tf0
where tf0.file_ls not in ('archive_status')
and tf0.file_ls not like '%.backup'
group by to_char(date_trunc('day',tf0.modification),'yyyymmdd')
order by to_char(date_trunc('day',tf0.modification),'yyyymmdd') desc;
以上语句查询结果均如下图所示,第一列为时间,具体到天,第二列为当天产生的总数。第三列之后,为每个时间段产生的日志数量。如w0_1列表示,当天0点到1点产生的wal数量
更多详细信息请登录【瀚高技术支持平台】查看https://support.highgo.com/#/index/docContentHighgo/c3287e0301672491