|
| 1 | +## PostgreSQL 逻辑备份一致性讲解 - Why pg_dump backup a database in consistent status |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2012-05-11 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , 逻辑备份 , 一致性 |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +今天一位群里的朋友在问怎么做一致的逻辑备份, 比如在hot_standby上使用pg_dump备份数据库时,是不是要先把recovery停掉再进行备份? |
| 16 | + |
| 17 | +回答,不需要停止其他读写,使用pg_dump备份是一致的备份。 |
| 18 | + |
| 19 | +为什么呢? |
| 20 | + |
| 21 | +因为pg_dump备份时使用的是serializable隔离级别, 如在hot_standby上面备份将使用repeatable read隔离级别.(目前hot_standby数据库不支持serializable隔离级别). 使用这两种隔离级别进行备份,整个事务从开始时就是看到的一个数据库的snapshot。 |
| 22 | + |
| 23 | +pg_dump代码中开头就有一段介绍如下: |
| 24 | + |
| 25 | +``` |
| 26 | + * pg_dump will read the system catalogs in a database and dump out a |
| 27 | + * script that reproduces the schema in terms of SQL that is understood |
| 28 | + * by PostgreSQL |
| 29 | + * |
| 30 | + * Note that pg_dump runs in a transaction-snapshot mode transaction, |
| 31 | + * so it sees a consistent snapshot of the database including system |
| 32 | + * catalogs. However, it relies in part on various specialized backend |
| 33 | + * functions like pg_get_indexdef(), and those things tend to run on |
| 34 | + * SnapshotNow time, ie they look at the currently committed state. So |
| 35 | + * it is possible to get 'cache lookup failed' error if someone |
| 36 | + * performs DDL changes while a dump is happening. The window for this |
| 37 | + * sort of thing is from the acquisition of the transaction snapshot to |
| 38 | + * getSchemaData() (when pg_dump acquires AccessShareLock on every |
| 39 | + * table it intends to dump). It isn't very large, but it can happen. |
| 40 | +``` |
| 41 | + |
| 42 | +另外代码中还有一段关于启动事务的如下, |
| 43 | + |
| 44 | +``` |
| 45 | + /* |
| 46 | + * Start transaction-snapshot mode transaction to dump consistent data. |
| 47 | + */ |
| 48 | + do_sql_command(g_conn, "BEGIN"); |
| 49 | + if (g_fout->remoteVersion >= 90100) |
| 50 | + { |
| 51 | + if (serializable_deferrable) |
| 52 | + do_sql_command(g_conn, |
| 53 | + "SET TRANSACTION ISOLATION LEVEL SERIALIZABLE, " |
| 54 | + "READ ONLY, DEFERRABLE"); |
| 55 | + else |
| 56 | + do_sql_command(g_conn, |
| 57 | + "SET TRANSACTION ISOLATION LEVEL REPEATABLE READ"); |
| 58 | + } |
| 59 | + else |
| 60 | + do_sql_command(g_conn, "SET TRANSACTION ISOLATION LEVEL SERIALIZABLE"); |
| 61 | +``` |
| 62 | + |
| 63 | +接下来我们测试一下: |
| 64 | + |
| 65 | +1\. SESSION A: |
| 66 | + |
| 67 | +``` |
| 68 | +postgres@db-172-16-3-33-> pg_dump -f ./digoal.dmp -F p -v -C -E UTF8 -h 127.0.0.1 -U postgres digoal |
| 69 | +pg_dump: reading schemas |
| 70 | +pg_dump: reading user-defined tables |
| 71 | +pg_dump: reading extensions |
| 72 | +pg_dump: reading user-defined functions |
| 73 | +pg_dump: reading user-defined types |
| 74 | +pg_dump: reading procedural languages |
| 75 | +pg_dump: reading user-defined aggregate functions |
| 76 | +pg_dump: reading user-defined operators |
| 77 | +pg_dump: reading user-defined operator classes |
| 78 | +pg_dump: reading user-defined operator families |
| 79 | +pg_dump: reading user-defined text search parsers |
| 80 | +pg_dump: reading user-defined text search templates |
| 81 | +pg_dump: reading user-defined text search dictionaries |
| 82 | +pg_dump: reading user-defined text search configurations |
| 83 | +pg_dump: reading user-defined foreign-data wrappers |
| 84 | +pg_dump: reading user-defined foreign servers |
| 85 | +pg_dump: reading default privileges |
| 86 | +pg_dump: reading user-defined collations |
| 87 | +pg_dump: reading user-defined conversions |
| 88 | +pg_dump: reading type casts |
| 89 | +pg_dump: reading table inheritance information |
| 90 | +pg_dump: reading rewrite rules |
| 91 | +pg_dump: finding extension members |
| 92 | +pg_dump: finding inheritance relationships |
| 93 | +pg_dump: reading column info for interesting tables |
| 94 | +pg_dump: finding the columns and types of table "restore_point" |
| 95 | +pg_dump: finding default expressions of table "restore_point" |
| 96 | +pg_dump: finding the columns and types of table "t1" |
| 97 | +pg_dump: finding the columns and types of table "t2" |
| 98 | +pg_dump: finding the columns and types of table "t3" |
| 99 | +pg_dump: finding the columns and types of table "a1" |
| 100 | +pg_dump: finding the columns and types of table "a2" |
| 101 | +pg_dump: flagging inherited columns in subtables |
| 102 | +pg_dump: reading indexes |
| 103 | +pg_dump: reading indexes for table "t1" |
| 104 | +pg_dump: reading indexes for table "t2" |
| 105 | +pg_dump: reading constraints |
| 106 | +pg_dump: reading triggers |
| 107 | +pg_dump: reading large objects |
| 108 | +pg_dump: reading dependency data |
| 109 | +pg_dump: saving encoding = UTF8 |
| 110 | +pg_dump: saving standard_conforming_strings = on |
| 111 | +pg_dump: saving database definition |
| 112 | +pg_dump: creating DATABASE digoal |
| 113 | +pg_dump: connecting to new database "digoal" |
| 114 | +pg_dump: creating SCHEMA public |
| 115 | +pg_dump: creating COMMENT SCHEMA public |
| 116 | +pg_dump: creating EXTENSION plpgsql |
| 117 | +pg_dump: creating COMMENT EXTENSION plpgsql |
| 118 | +pg_dump: creating TABLE a1 |
| 119 | +pg_dump: creating TABLE a2 |
| 120 | +pg_dump: creating TABLE restore_point |
| 121 | +pg_dump: creating SEQUENCE restore_point_id_seq |
| 122 | +pg_dump: creating SEQUENCE OWNED BY restore_point_id_seq |
| 123 | +pg_dump: executing SEQUENCE SET restore_point_id_seq |
| 124 | +pg_dump: creating TABLE t1 |
| 125 | +pg_dump: creating TABLE t2 |
| 126 | +pg_dump: creating TABLE t3 |
| 127 | +pg_dump: creating DEFAULT id |
| 128 | +pg_dump: restoring data for table "a1" |
| 129 | +pg_dump: dumping contents of table a1 |
| 130 | +``` |
| 131 | + |
| 132 | +到这个点的时候,pg_dump还未结束,在SESSION B执行: |
| 133 | + |
| 134 | +``` |
| 135 | +digoal=# begin; |
| 136 | +BEGIN |
| 137 | +digoal=# drop table t2; |
| 138 | + |
| 139 | +``` |
| 140 | + |
| 141 | +处于waiting状态. 这个要等到SESSION A的备份完成. |
| 142 | + |
| 143 | +或者在SESSION B执行: |
| 144 | + |
| 145 | +``` |
| 146 | +digoal=# begin; |
| 147 | +BEGIN |
| 148 | +digoal=# truncate table t2; |
| 149 | + |
| 150 | +``` |
| 151 | + |
| 152 | +也处于waiting状态. 这个也要等到SESSION A的备份完成. |
| 153 | + |
| 154 | +但是执行创建新表是可以的, 给已有表创建索引也是可以的. 但是删除已有表的索引需要等待. |
| 155 | + |
| 156 | +既然会堵塞对已有表的一些DDL操作, 那么会不会堵塞对表的DML操作呢? |
| 157 | + |
| 158 | +在备份过程中我在SESSION B执行如下 : |
| 159 | + |
| 160 | +``` |
| 161 | +digoal=> delete from t1 where id=10000000; |
| 162 | +DELETE 1 |
| 163 | +digoal=> delete from t2 where id=10000000; |
| 164 | +DELETE 1 |
| 165 | +digoal=> delete from t2 where id=1000000; |
| 166 | +DELETE 1 |
| 167 | +digoal=> delete from t1 where id=1000000; |
| 168 | +DELETE 1 |
| 169 | +``` |
| 170 | + |
| 171 | +可以执行DML,也就是说pg_dump不会堵塞对表的DML操作。 |
| 172 | + |
| 173 | +那么从备份开始到备份结束是不是处于同一个事务中呢, 我们看一下备份这个进程的事务开始时间和QUERY开始时间. |
| 174 | + |
| 175 | +``` |
| 176 | +digoal=# select usename,datname,current_query,xact_start,query_start from pg_stat_activity; |
| 177 | + usename | datname | current_query | xact_start |
| 178 | + | query_start |
| 179 | +----------+---------+------------------------------------------------------------------------------------+-------------------------- |
| 180 | +-----+------------------------------- |
| 181 | + postgres | digoal | select usename,datname,current_query,xact_start,query_start from pg_stat_activity; | 2012-05-11 15:39:44.92349 |
| 182 | +3+08 | 2012-05-11 15:39:44.923493+08 |
| 183 | + postgres | digoal | COPY public.a1 (id) TO stdout; | 2012-05-11 15:39:43.59293 |
| 184 | +4+08 | 2012-05-11 15:39:43.687405+08 |
| 185 | +(2 rows) |
| 186 | +``` |
| 187 | + |
| 188 | +结束前再执行查询看看xact_start时间未变化, 说明pg_dump备份是在一个事务中完成的. |
| 189 | + |
| 190 | +``` |
| 191 | +digoal=# select usename,datname,current_query,xact_start,query_start from pg_stat_activity; |
| 192 | + usename | datname | current_query | xact_start |
| 193 | + | query_start |
| 194 | +----------+---------+------------------------------------------------------------------------------------+-------------------------- |
| 195 | +-----+------------------------------- |
| 196 | + postgres | digoal | select usename,datname,current_query,xact_start,query_start from pg_stat_activity; | 2012-05-11 15:39:52.60046 |
| 197 | +3+08 | 2012-05-11 15:39:52.600463+08 |
| 198 | + postgres | digoal | COPY public.t3 (id) TO stdout; | 2012-05-11 15:39:43.59293 |
| 199 | +4+08 | 2012-05-11 15:39:51.891716+08 |
| 200 | +(2 rows) |
| 201 | +``` |
| 202 | + |
| 203 | +备份结束后,我们看一下备份的数据是不是一致的,换句话说,我执行的那几个DML操作,删除了4条记录,这4条记录在备份开始时是存在的,如果是一致的备份,这个4条记录应该在备份的记录里面存在。 |
| 204 | + |
| 205 | +我在digoal.dmp这个文件里面找到了这4条记录,再一次验证pg_dump的备份是一致的。 |
| 206 | + |
| 207 | + |
| 208 | +## 小结 |
| 209 | +1\. 使用pg_dump备份的时候,这个过程产生的垃圾数据不可以被VACUUM掉,所以一个很长时间的pg_dump操作会带来更多的垃圾数据.换句话说表的膨胀。 |
| 210 | + |
0 commit comments