Skip to content

Commit 44dbfb8

Browse files
committed
improve
1 parent 9c67efc commit 44dbfb8

File tree

6 files changed

+369
-0
lines changed

6 files changed

+369
-0
lines changed

201504/20150409_03.md

Lines changed: 134 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,134 @@
1+
## PostgreSQL 9.5 new feature - record transaction commit timestamp
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2015-04-09
8+
9+
### 标签
10+
PostgreSQL , 时间戳 , commit , pg_commit_ts
11+
12+
----
13+
14+
## 背景
15+
PostgreSQL 9.5新增的一个功能, 允许用户开启过关闭记录事务提交时间.
16+
17+
代码见
18+
19+
src/backend/access/transam/commit_ts.c
20+
21+
```
22+
* commit_ts.c
23+
* PostgreSQL commit timestamp manager
24+
*
25+
* This module is a pg_clog-like system that stores the commit timestamp
26+
* for each transaction.
27+
*
28+
* XLOG interactions: this module generates an XLOG record whenever a new
29+
* CommitTs page is initialized to zeroes. Also, one XLOG record is
30+
* generated for setting of values when the caller requests it; this allows
31+
* us to support values coming from places other than transaction commit.
32+
* Other writes of CommitTS come from recording of transaction commit in
33+
* xact.c, which generates its own XLOG records for these events and will
34+
* re-perform the status update on redo; so we need make no additional XLOG
35+
* entry here.
36+
*
37+
* Portions Copyright (c) 1996-2015, PostgreSQL Global Development Group
38+
* Portions Copyright (c) 1994, Regents of the University of California
39+
*
40+
* src/backend/access/transam/commit_ts.c
41+
```
42+
43+
使用和block_size同样大小的数据块.
44+
45+
```
46+
/*
47+
* Defines for CommitTs page sizes. A page is the same BLCKSZ as is used
48+
* everywhere else in Postgres.
49+
*
50+
* Note: because TransactionIds are 32 bits and wrap around at 0xFFFFFFFF,
51+
* CommitTs page numbering also wraps around at
52+
* 0xFFFFFFFF/COMMIT_TS_XACTS_PER_PAGE, and CommitTs segment numbering at
53+
* 0xFFFFFFFF/COMMIT_TS_XACTS_PER_PAGE/SLRU_PAGES_PER_SEGMENT. We need take no
54+
* explicit notice of that fact in this module, except when comparing segment
55+
* and page numbers in TruncateCommitTs (see CommitTsPagePrecedes).
56+
*/
57+
```
58+
59+
使用12个字节记录一个事务和对应的时间.
60+
61+
```
62+
/*
63+
* We need 8+4 bytes per xact. Note that enlarging this struct might mean
64+
* the largest possible file name is more than 5 chars long; see
65+
* SlruScanDirectory.
66+
*/
67+
typedef struct CommitTimestampEntry
68+
{
69+
TimestampTz time;
70+
CommitTsNodeId nodeid;
71+
} CommitTimestampEntry;
72+
73+
#define SizeOfCommitTimestampEntry (offsetof(CommitTimestampEntry, nodeid) + \
74+
sizeof(CommitTsNodeId))
75+
76+
#define COMMIT_TS_XACTS_PER_PAGE \
77+
(BLCKSZ / SizeOfCommitTimestampEntry)
78+
```
79+
80+
这个模块和pg_clog类似, 也是记录在XLOG以外的位置, 如下, 我们可看到新增的目录pg_commit_ts :
81+
82+
```
83+
pg95@db-172-16-3-150-> cd $PGDATA
84+
pg95@db-172-16-3-150-> ll
85+
...
86+
drwx------ 2 pg95 pg95 4.0K Apr 9 09:04 pg_commit_ts
87+
```
88+
89+
查看控制文件可以得知当前是否开启了跟踪事务提交时间.
90+
91+
```
92+
pg95@db-172-16-3-150-> pg_controldata
93+
Current track_commit_timestamp setting: off
94+
```
95+
96+
如果要开启, 显然需要重启数据库.
97+
98+
```
99+
vi $PGDATA/postgresql.conf
100+
track_commit_timestamp = on
101+
102+
pg_ctl restart -m fast
103+
pg95@db-172-16-3-150-> pg_controldata |grep track
104+
Current track_commit_timestamp setting: on
105+
```
106+
107+
如果你开启了跟踪事务时间, 那么在需要重置xlog时, 也多了需要指定的值.
108+
109+
```
110+
[-c xid,xid]
111+
· A safe value for the oldest transaction ID for which the commit time can be retrieved (first part of -c)
112+
can be determined by looking for the numerically smallest file name in the directory pg_committs under the
113+
data directory. Conversely, a safe value for the newest transaction ID for which the commit time can be
114+
retrieved (second part of -c) can be determined by looking for the numerically greatest file name in the
115+
same directory. As above, the file names are in hexadecimal.
116+
```
117+
118+
记录事务提交时的时间底有啥用呢?
119+
120+
目前暂时未看到有使用这块的,
121+
122+
不过可以想象一下 垃圾回收(例如snapshot too old), 逻辑复制有一定关系.
123+
124+
未来也许会针对这个开发一系列附加功能.
125+
126+
## 参考
127+
1\. src/backend/access/transam/commit_ts.c
128+
129+
2\. src/backend/access/rmgrdesc/committsdesc.c
130+
131+
3\. man pg_resetxlog
132+
133+
<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a>
134+

201504/20150409_04.md

Lines changed: 137 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,137 @@
1+
## PostgreSQL 9.5 new feature - log replication commands
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2015-04-09
8+
9+
### 标签
10+
PostgreSQL , 逻辑复制 , command
11+
12+
----
13+
14+
## 背景
15+
PostgreSQL 9.5新增一个参数, 可以记录流复制协议中用到的命令到日志中.
16+
17+
```
18+
log_replication_commands = on
19+
```
20+
21+
协议解释详见 :
22+
23+
http://www.postgresql.org/docs/devel/static/protocol-replication.html
24+
25+
测试
26+
27+
```
28+
pg_hba.conf
29+
# Allow replication connections from localhost, by a user with the
30+
# replication privilege.
31+
local replication postgres trust
32+
host replication postgres 127.0.0.1/32 trust
33+
host replication postgres ::1/128 trust
34+
postgresql.conf
35+
wal_level = logical
36+
max_wal_senders = 2
37+
max_replication_slots = 2
38+
log_replication_commands = on
39+
40+
pg95@db-172-16-3-150-> pg_ctl restart -m fast
41+
```
42+
43+
使用一个流复制协议command测试 :
44+
45+
```
46+
pg95@db-172-16-3-150-> psql "dbname=postgres replication=database" -c "IDENTIFY_SYSTEM;"
47+
systemid | timeline | xlogpos | dbname
48+
---------------------+----------+-----------+----------
49+
6135538990815133068 | 1 | 0/1B186A0 | postgres
50+
(1 row)
51+
```
52+
53+
以上命令在数据库日志中可以看到.
54+
55+
```
56+
2015-04-09 10:49:59.481 CST,"postgres","postgres",21664,"[local]",5525e8d7.54a0,3,"idle",2015-04-09 10:49:59 CST,2/0,0,LOG,00000,"received replication command: IDENTIFY_SYSTEM;",,,,,,,,"exec_replication_command, walsender.c:1274","psql"
57+
```
58+
59+
用于区分连接流复制的代码:
60+
61+
src/backend/replication/libpqwalreceiver/libpqwalreceiver.c
62+
63+
```
64+
/*
65+
* Establish the connection to the primary server for XLOG streaming
66+
*/
67+
static void
68+
libpqrcv_connect(char *conninfo)
69+
{
70+
char conninfo_repl[MAXCONNINFO + 75];
71+
72+
/*
73+
* Connect using deliberately undocumented parameter: replication. The
74+
* database name is ignored by the server in replication mode, but specify
75+
* "replication" for .pgpass lookup.
76+
*/
77+
snprintf(conninfo_repl, sizeof(conninfo_repl),
78+
"%s dbname=replication replication=true fallback_application_name=walreceiver",
79+
conninfo);
80+
81+
streamConn = PQconnectdb(conninfo_repl);
82+
if (PQstatus(streamConn) != CONNECTION_OK)
83+
ereport(ERROR,
84+
(errmsg("could not connect to the primary server: %s",
85+
PQerrorMessage(streamConn))));
86+
}
87+
```
88+
89+
src/bin/pg_basebackup/streamutil.c
90+
91+
```
92+
* streamutil.c - utility functions for pg_basebackup and pg_receivelog
93+
*
94+
* Author: Magnus Hagander <[email protected]>
95+
*
96+
* Portions Copyright (c) 1996-2014, PostgreSQL Global Development Group
97+
*
98+
* IDENTIFICATION
99+
* src/bin/pg_basebackup/streamutil.c
100+
101+
/*
102+
* Connect to the server. Returns a valid PGconn pointer if connected,
103+
* or NULL on non-permanent error. On permanent error, the function will
104+
* call exit(1) directly.
105+
*/
106+
PGconn *
107+
GetConnection(void)
108+
{
109+
...
110+
keywords[i] = "dbname";
111+
values[i] = dbname == NULL ? "replication" : dbname;
112+
i++;
113+
keywords[i] = "replication";
114+
values[i] = dbname == NULL ? "true" : "database";
115+
i++;
116+
keywords[i] = "fallback_application_name";
117+
values[i] = progname;
118+
i++;
119+
...
120+
```
121+
122+
只需要提供replication=true的连接串即可。
123+
124+
```
125+
psql "replication=true" postgres
126+
psql (9.5.0)
127+
Type "help" for help.
128+
postgres=# IDENTIFY_SYSTEM;
129+
systemid | timeline | xlogpos | dbname
130+
---------------------+----------+-------------+--------
131+
6243682321523937214 | 1 | 1F/FB2D7B48 |
132+
(1 row)
133+
```
134+
135+
136+
<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a>
137+

201504/readme.md

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -9,6 +9,8 @@
99
##### 20150419_01.md [《PostgreSQL 9.5 new feature - BRIN (block range index) index》](20150419_01.md)
1010
##### 20150414_01.md [《PivotalR between R & PostgreSQL-like Databases(for exp : Greenplum, hadoop access by hawq)》](20150414_01.md)
1111
##### 20150410_01.md [《如何比较PostgreSQL表的定义(compare table ddl)》](20150410_01.md)
12+
##### 20150409_04.md [《PostgreSQL 9.5 new feature - log replication commands》](20150409_04.md)
13+
##### 20150409_03.md [《PostgreSQL 9.5 new feature - record transaction commit timestamp》](20150409_03.md)
1214
##### 20150409_02.md [《PostgreSQL 9.5 使用 import foreign schema 语法一键创建外部表》](20150409_02.md)
1315
##### 20150409_01.md [《PostgreSQL 行安全策略 - PostgreSQL 9.5 new feature - can define row security policy for table》](20150409_01.md)
1416
##### 20150407_02.md [《PostgreSQL aggregate function 4 : Hypothetical-Set Aggregate Functions》](20150407_02.md)

201807/20180704_01.md

Lines changed: 92 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,92 @@
1+
## PostgreSQL 模拟两个update语句死锁 - 利用扫描方法
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2018-07-04
8+
9+
### 标签
10+
PostgreSQL , 死锁 , update , 模拟
11+
12+
----
13+
14+
## 背景
15+
在单条UPDATE中模拟死锁,需要借助扫描方法,以及明确让AB两个会话分别锁定一条记录后再锁定对方已经锁定的记录。
16+
17+
利用批量update的语法以及values子句即可实现,这里利用了嵌套循环,确保被更新的表被多次扫描,并且每次扫描时两个会话更新的记录被错开,达到死锁效果。
18+
19+
同时为了让速度慢下来,使用pg_sleep函数,让每一条更新都放缓1秒。
20+
21+
## 例子
22+
1、建表
23+
24+
```
25+
postgres=# create table a (id int primary key, info timestamp);
26+
CREATE TABLE
27+
```
28+
29+
2、写入测试数据
30+
31+
```
32+
postgres=# insert into a select generate_series(1,10);
33+
INSERT 0 10
34+
```
35+
36+
3、会话1 SQL,执行计划
37+
38+
先锁定ID=2的记录,然后锁定ID=1的记录。
39+
40+
```
41+
postgres=# explain update a set info=clock_timestamp() from (values (2),(1)) t(id) where a.id=t.id and pg_sleep(1) is not null;
42+
QUERY PLAN
43+
-----------------------------------------------------------------------------
44+
Update on a (cost=0.15..4.80 rows=2 width=46)
45+
-> Nested Loop (cost=0.15..4.80 rows=2 width=46)
46+
Join Filter: (pg_sleep('1'::double precision) IS NOT NULL) -- 放缓1秒
47+
-> Values Scan on "*VALUES*" (cost=0.00..0.03 rows=2 width=32) -- 按values写的顺序扫描
48+
-> Index Scan using a_pkey on a (cost=0.15..2.37 rows=1 width=10) -- 先更新2,再更新1
49+
Index Cond: (id = "*VALUES*".column1)
50+
(6 rows)
51+
```
52+
53+
4、会话2 SQL,执行计划,与会话1相反。
54+
55+
先锁定ID=1的记录,然后锁定ID=2的记录。
56+
57+
```
58+
postgres=# explaIN update a set info=clock_timestamp() from (values (2),(1)) t(id) where a.id=t.id and pg_sleep(1) is not null;
59+
QUERY PLAN
60+
-----------------------------------------------------------------------------
61+
Update on a (cost=0.15..4.80 rows=2 width=46)
62+
-> Nested Loop (cost=0.15..4.80 rows=2 width=46)
63+
Join Filter: (pg_sleep('1'::double precision) IS NOT NULL) -- 放缓1秒
64+
-> Values Scan on "*VALUES*" (cost=0.00..0.03 rows=2 width=32) -- 按values写的顺序扫描
65+
-> Index Scan using a_pkey on a (cost=0.15..2.37 rows=1 width=10) -- 先更新1,再更新2
66+
Index Cond: (id = "*VALUES*".column1)
67+
(6 rows)
68+
```
69+
70+
5、模拟死锁
71+
72+
```
73+
会话1
74+
75+
postgres=# update a set info=clock_timestamp() from (values (2),(1)) t(id) where a.id=t.id and pg_sleep(1) is not null;
76+
ERROR: deadlock detected
77+
DETAIL: Process 19893 waits for ShareLock on transaction 18613573; blocked by process 9910.
78+
Process 9910 waits for ShareLock on transaction 18613572; blocked by process 19893.
79+
HINT: See server log for query details.
80+
CONTEXT: while updating tuple (0,1) in relation "a"
81+
82+
马上发起会话2
83+
84+
postgres=# update a set info=clock_timestamp() from (values (1),(2)) t(id) where a.id=t.id and pg_sleep(1) is not null;
85+
UPDATE 2
86+
```
87+
88+
89+
90+
91+
<a rel="nofollow" href="http://info.flagcounter.com/h9V1" ><img src="http://s03.flagcounter.com/count/h9V1/bg_FFFFFF/txt_000000/border_CCCCCC/columns_2/maxflags_12/viewers_0/labels_0/pageviews_0/flags_0/" alt="Flag Counter" border="0" ></a>
92+

201807/readme.md

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -2,6 +2,7 @@
22

33
### 文章列表
44
----
5+
##### 20180704_01.md [《PostgreSQL 模拟两个update语句死锁 - 利用扫描方法》](20180704_01.md)
56
##### 20180703_02.md [《PostgreSQL 电商业务(任意维度商品圈选应用) - json包range数组的命中优化 - 展开+索引优化》](20180703_02.md)
67
##### 20180703_01.md [《PostgreSQL 函数式索引使用注意 - 暨非immutable函数不适合索引的原因》](20180703_01.md)
78
##### 20180702_02.md [《如何让json里面的value支持索引范围检索》](20180702_02.md)

README.md

Lines changed: 3 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -31,6 +31,7 @@ digoal's|PostgreSQL|文章|归类
3131

3232
### 未归类文档如下
3333
----
34+
##### 201807/20180704_01.md [《PostgreSQL 模拟两个update语句死锁 - 利用扫描方法》](201807/20180704_01.md)
3435
##### 201807/20180703_02.md [《PostgreSQL 电商业务(任意维度商品圈选应用) - json包range数组的命中优化 - 展开+索引优化》](201807/20180703_02.md)
3536
##### 201807/20180703_01.md [《PostgreSQL 函数式索引使用注意 - 暨非immutable函数不适合索引的原因》](201807/20180703_01.md)
3637
##### 201807/20180702_02.md [《如何让json里面的value支持索引范围检索》](201807/20180702_02.md)
@@ -1452,6 +1453,8 @@ digoal's|PostgreSQL|文章|归类
14521453
##### 201504/20150419_01.md [《PostgreSQL 9.5 new feature - BRIN (block range index) index》](201504/20150419_01.md)
14531454
##### 201504/20150414_01.md [《PivotalR between R & PostgreSQL-like Databases(for exp : Greenplum, hadoop access by hawq)》](201504/20150414_01.md)
14541455
##### 201504/20150410_01.md [《如何比较PostgreSQL表的定义(compare table ddl)》](201504/20150410_01.md)
1456+
##### 201504/20150409_04.md [《PostgreSQL 9.5 new feature - log replication commands》](201504/20150409_04.md)
1457+
##### 201504/20150409_03.md [《PostgreSQL 9.5 new feature - record transaction commit timestamp》](201504/20150409_03.md)
14551458
##### 201504/20150409_02.md [《PostgreSQL 9.5 使用 import foreign schema 语法一键创建外部表》](201504/20150409_02.md)
14561459
##### 201504/20150409_01.md [《PostgreSQL 行安全策略 - PostgreSQL 9.5 new feature - can define row security policy for table》](201504/20150409_01.md)
14571460
##### 201504/20150407_02.md [《PostgreSQL aggregate function 4 : Hypothetical-Set Aggregate Functions》](201504/20150407_02.md)

0 commit comments

Comments
 (0)