分类: Mysql/postgreSQL
2011-04-21 15:21:48
像其它数据库一样,PostgreSQL也有自己的日志系统,postgresql
日志方面有非常全
面的设置参数,这篇不准备仔细的介绍PG的日志参数,只介绍日志分析的一种方法,即可以将
日志文件内容导入到数据库表里,便于分析日志。
--日志文件目录
日志的目录可以通过参数 log_directory
来设置,下面是我的参数设置。
log_directory = '/data/pgsql/data/pg_log'
[postgres@pg_log]$ ll /data/pgsql/data/pg_log
-rw------- 1 postgres postgres 2473 Apr 21 15:03 postgresql-2011-04-21_000000.csv
-rw------- 1 postgres postgres 0 Apr 21 00:00 postgresql-2011-04-21_000000.log
-rw------- 1 postgres postgres 669 Apr 21 15:03 postgresql-2011-04-21_150344.csv
-rw------- 1 postgres postgres 0 Apr 21 15:03 postgresql-2011-04-21_150344.log
--CSV日志文件内容
2011-04-21 15:03:44.172 CST,,,1892,,4dafd6d0.764,1,,2011-04-21 15:03:44 CST,,0,LOG,00000,"database system was shut down at 2011-04-21 15:03:12 CST",,,,,,,,,""
2011-04-21 15:03:44.380 CST,,,1604,,4dafd6cf.644,1,,2011-04-21 15:03:43 CST,,0,LOG,00000,"database system is ready to accept connections",,,,,,,,,""
2011-04-21 15:03:44.381 CST,,,1914,,4dafd6d0.77a,1,,2011-04-21 15:03:44 CST,,0,LOG,00000,"autovacuum launcher started",,,,,,,,,""
2011-04-21 15:03:44.945 CST,"repluser1","",2303,"10.0.100.19:42221",4dafd6d0.8ff,1,"authentication",2011-04-21 15:03:44 CST,2/1,0,LOG,00000,"replication connection authorized: user=repluser1 host=10.0.100.19 port=42221",,,,,,,,,""
上面两条是 postgresql-2011-04-21_150344.csv 日志文件的部分内容
,由于日志文件的可读性
较差,于是可以通过下面方法将CSV日志导入到数据库表里。详细如下
将CSV日志导入数据库表里
1--调整参数
log_destination =
'csvlog'
logging_collector = on
这两个参数修改后,PG SERVER 需要重启。
2--创建日志记录表
CREATE TABLE
postgres_log
(
log_time timestamp(3) with time zone,
user_name
text,
database_name text,
process_id integer,
connection_from
text,
session_id text,
session_line_num bigint,
command_tag
text,
session_start_time timestamp with time zone,
virtual_transaction_id text,
transaction_id bigint,
error_severity
text,
sql_state_code text,
message text,
detail text,
hint
text,
internal_query text,
internal_query_pos integer,
context
text,
query text,
query_pos integer,
location text,
application_name text,
PRIMARY KEY (session_id, session_line_num)
);
NOTICE: CREATE TABLE / PRIMARY KEY will create implicit index
"postgres_log_pkey" for table "postgres_log"
CREATE TABLE;
备注:创建日志表 postgres_log 用来保存 CSV日志数据。
3--导入操作系统 csv 日志到表 postgres_log
表
skytf=# copy public.postgres_log from
'/data/pgsql/data/pg_log/postgresql-2011-03-14_000000.csv' with csv;
COPY
26031
skytf=# copy public.postgres_log from
'/data/pgsql/data/pg_log/postgresql-2011-03-15_000000.csv' with csv;
COPY 1297
备注:文件形式导入导出数据需要以超级用户 postgres 连接到目标库。
4--常用日志分析sql
postgres=# select min(log_time),max(log_time) from public.postgres_log;
min | max
----------------------------+----------------------------
2011-03-14 14:00:54.175+08 | 2011-04-22 05:39:33.463+08
(1 row)
postgres=> select log_time,database_name,user_name,application_name,message
from postgres_log where message like '%duration%';
log_time | database_name | user_name | application_name
|
mess
age
----------------------------+---------------+-----------+------------------+--------------------------------------------------------
-------------------------------------------------------
2011-03-15
00:23:38.957+08 | db_lbs | lbs | | duration:
1297.440 ms execute
yname,province,the_geom
as the_geom FROM china_city
.......
postgres=# SELECT * from postgres_log where log_time='2011-04-22 05:03:44.945+08';
log_time | user_name | database_name | process_id | connection_from | session_id | session_line_num | command_tag | session_start_time | virtual_transaction_id | transaction_id | error_severity | sql_state_code | message | detail | hint | internal_query | internal_query_pos | context | query | query_pos | location | application_name
----------------------------+-----------+---------------+------------+-------------------+--------------+------------------+----------------+------------------------+------------------------+----------------+----------------+----------------+-------------------------------------------------------------------------------+--------+------+----------------+--------------------+---------+-------+-----------+----------+------------------
2011-04-22 05:03:44.945+08 | repluser1 | | 2303 | 10.0.100.19:42221 | 4dafd6d0.8ff | 1 | authentication | 2011-04-22 05:03:44+08 | 2/1 | 0 | LOG | 00000 | replication connection authorized: user=repluser1 host=10.0.100.19 port=42221 | | | | | | | | |
(1 row)
为了显示方便,上面只取一条记录。
5--总结
当数据库出现异常需要详细分析日志文件时,上面的方法提供了一个非常有效的方式,
将数据库日志导入到表里,能够更准确,方便地分析数据库日志。