|
| 1 | +## Compare PostgreSQL and Oracle dead lock detect and transaction |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2011-04-08 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , Oracle , dead lock |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +Oracle 和 PostgreSQL的死锁检测和处理有较大区别。 |
| 16 | + |
| 17 | +主要差别在于 : |
| 18 | + |
| 19 | +1\. 死锁被检测到的属于哪个SESSION?Oracle随机检出,从实验来看应该是第一个启动的死锁事务。而PostgreSQL是死锁发生时的最后一个事务,与ORACLE相反(从PG的deadlock_timeout参数可以看出PostgreSQL的死锁检测不是随机的,而是可预见的。This is the amount of time, in milliseconds, to wait on a lock before checking to see if there is a deadlock condition.)。 |
| 20 | + |
| 21 | +2\. 死锁被检测到之后的处理上的差别,oracle允许单个事务中的部分SQL执行成功,部分SQL执行失败(其实这是非常严重的缺陷)。而PostgreSQL不允许事务中的部分SQL语句执行成功,要么全部成功,要么全部失败。 |
| 22 | + |
| 23 | +如图: |
| 24 | + |
| 25 | +PostgreSQL 模拟死锁场景和检测结果, |
| 26 | + |
| 27 | + |
| 28 | + |
| 29 | +Oracle 模拟死锁场景和检测结果, |
| 30 | + |
| 31 | + |
| 32 | + |
| 33 | +## PostgreSQL |
| 34 | + |
| 35 | +``` |
| 36 | +deadlock_timeout = 1s |
| 37 | +``` |
| 38 | + |
| 39 | +死锁检查会消耗部分数据库资源,如果数据库压力比较大的话可以考虑调大这个值。 |
| 40 | + |
| 41 | +SESSION A : |
| 42 | + |
| 43 | +``` |
| 44 | +digoal=> begin; |
| 45 | +BEGIN |
| 46 | +Time: 0.122 ms |
| 47 | +digoal=> update tbl_test set id=id+1 where id=100; |
| 48 | +UPDATE 1 |
| 49 | +Time: 0.379 ms |
| 50 | +``` |
| 51 | + |
| 52 | +SESSION B : |
| 53 | + |
| 54 | +``` |
| 55 | +digoal=> begin; |
| 56 | +BEGIN |
| 57 | +Time: 0.126 ms |
| 58 | +digoal=> update tbl_test2 set id=id+1 where id=100; |
| 59 | +UPDATE 1 |
| 60 | +Time: 0.437 ms |
| 61 | +``` |
| 62 | + |
| 63 | +SESSION C : |
| 64 | + |
| 65 | +``` |
| 66 | +digoal=> begin; |
| 67 | +BEGIN |
| 68 | +digoal=> update tbl_test1 set id=id+1 where id=100; |
| 69 | +UPDATE 1 |
| 70 | +``` |
| 71 | + |
| 72 | +SESSION A : |
| 73 | + |
| 74 | +``` |
| 75 | +digoal=> update tbl_test2 set id=id+2 where id=100; |
| 76 | +``` |
| 77 | + |
| 78 | +SESSION B : |
| 79 | + |
| 80 | +``` |
| 81 | +digoal=> update tbl_test1 set id=id+3 where id=100; |
| 82 | +``` |
| 83 | + |
| 84 | +SESSION C : |
| 85 | + |
| 86 | +``` |
| 87 | +digoal=> update tbl_test set id=id+4 where id=100; |
| 88 | +ERROR: deadlock detected |
| 89 | +DETAIL: Process 11953 waits for ShareLock on transaction 4232; blocked by process 2873. |
| 90 | +Process 2873 waits for ShareLock on transaction 4233; blocked by process 6616. |
| 91 | +Process 6616 waits for ShareLock on transaction 4234; blocked by process 11953. |
| 92 | +HINT: See server log for query details. |
| 93 | +``` |
| 94 | + |
| 95 | +SESSION B : |
| 96 | + |
| 97 | +``` |
| 98 | +UPDATE 1 |
| 99 | +Time: 7839.728 ms |
| 100 | +``` |
| 101 | + |
| 102 | +SESSION A : |
| 103 | + |
| 104 | +``` |
| 105 | +UPDATE 0 |
| 106 | +Time: 40903.601 ms |
| 107 | +digoal=> commit; |
| 108 | +COMMIT |
| 109 | +Time: 0.099 ms |
| 110 | +``` |
| 111 | + |
| 112 | +SESSION C : |
| 113 | + |
| 114 | +``` |
| 115 | +digoal=> commit; |
| 116 | +ROLLBACK |
| 117 | +Time: 0.196 ms |
| 118 | +``` |
| 119 | + |
| 120 | +注意到在PostgreSQL中,整个SESSION C回滚了。 |
| 121 | + |
| 122 | +这个和psql的默认配置有关 : |
| 123 | + |
| 124 | +``` |
| 125 | + ON_ERROR_ROLLBACK |
| 126 | + When on, if a statement in a transaction block generates an error, the error is ignored and the |
| 127 | + transaction continues. When interactive, such errors are only ignored in interactive sessions, and not |
| 128 | + when reading script files. When off (the default), a statement in a transaction block that generates an |
| 129 | + error aborts the entire transaction. The on_error_rollback-on mode works by issuing an implicit |
| 130 | + SAVEPOINT for you, just before each command that is in a transaction block, and rolls back to the |
| 131 | + savepoint on error. |
| 132 | + |
| 133 | + ON_ERROR_STOP |
| 134 | + By default, command processing continues after an error. When this variable is set, it will instead |
| 135 | + stop immediately. In interactive mode, psql will return to the command prompt; otherwise, psql will |
| 136 | + exit, returning error code 3 to distinguish this case from fatal error conditions, which are reported |
| 137 | + using error code 1. In either case, any currently running scripts (the top-level script, if any, and |
| 138 | + any other scripts which it may have in invoked) will be terminated immediately. If the top-level |
| 139 | + command string contained multiple SQL commands, processing will stop with the current command. |
| 140 | +``` |
| 141 | + |
| 142 | +如果开启ON_ERROR_ROLLBACK, 会在每一句SQL前设置隐形的savepoint, 可以继续下面的SQL, 而不用全部回滚, 如下 : |
| 143 | + |
| 144 | +``` |
| 145 | +postgres=# \set ON_ERROR_ROLLBACK on |
| 146 | +postgres=# begin; |
| 147 | +BEGIN |
| 148 | +postgres=# insert into t values (1); |
| 149 | +ERROR: relation "t" does not exist |
| 150 | +LINE 1: insert into t values (1); |
| 151 | + ^ |
| 152 | +postgres=# \dt |
| 153 | +No relations found. |
| 154 | +postgres=# create table t (id int); |
| 155 | +CREATE TABLE |
| 156 | +postgres=# insert into t values (1); |
| 157 | +INSERT 0 1 |
| 158 | +postgres=# insert into t values ('a'); |
| 159 | +ERROR: invalid input syntax for integer: "a" |
| 160 | +LINE 1: insert into t values ('a'); |
| 161 | + ^ |
| 162 | +postgres=# commit; |
| 163 | +COMMIT |
| 164 | +postgres=# select * from t; |
| 165 | + id |
| 166 | +---- |
| 167 | + 1 |
| 168 | +(1 row) |
| 169 | + |
| 170 | +postgres=# \set ON_ERROR_ROLLBACK off |
| 171 | +postgres=# begin; |
| 172 | +BEGIN |
| 173 | +postgres=# insert into t values (1); |
| 174 | +INSERT 0 1 |
| 175 | +postgres=# insert into t values ('a'); |
| 176 | +ERROR: invalid input syntax for integer: "a" |
| 177 | +LINE 1: insert into t values ('a'); |
| 178 | + ^ |
| 179 | +postgres=# commit; |
| 180 | +ROLLBACK |
| 181 | +postgres=# select * from t; |
| 182 | + id |
| 183 | +---- |
| 184 | + 1 |
| 185 | +(1 row) |
| 186 | +``` |
| 187 | + |
| 188 | +## Oracle |
| 189 | + |
| 190 | +SESSION A: |
| 191 | + |
| 192 | +``` |
| 193 | +SQL> update tbl_test set id=id+1 where id=100; |
| 194 | +1 row updated. |
| 195 | +Elapsed: 00:00:00.00 |
| 196 | +``` |
| 197 | + |
| 198 | +SESSION B: |
| 199 | + |
| 200 | +``` |
| 201 | +SQL> update tbl_test2 set id=id+1 where id=100; |
| 202 | +1 row updated. |
| 203 | +Elapsed: 00:00:00.01 |
| 204 | +``` |
| 205 | + |
| 206 | +SESSION C: |
| 207 | + |
| 208 | +``` |
| 209 | +SQL> update tbl_test1 set id=id+1 where id=100; |
| 210 | +1 row updated. |
| 211 | +Elapsed: 00:00:00.00 |
| 212 | +``` |
| 213 | + |
| 214 | +SESSION A: |
| 215 | + |
| 216 | +``` |
| 217 | +SQL> update tbl_test2 set id=id+2 where id=100; |
| 218 | +``` |
| 219 | + |
| 220 | +SESSION B: |
| 221 | + |
| 222 | +``` |
| 223 | +SQL> update tbl_test1 set id=id+3 where id=100; |
| 224 | +0 rows updated. |
| 225 | +Elapsed: 00:00:39.50 |
| 226 | +``` |
| 227 | + |
| 228 | +SESSION C: |
| 229 | + |
| 230 | +``` |
| 231 | +SQL> update tbl_test set id=id+4 where id=100; |
| 232 | +0 rows updated. |
| 233 | +Elapsed: 00:00:17.34 |
| 234 | +``` |
| 235 | + |
| 236 | +SESSION A: |
| 237 | + |
| 238 | +``` |
| 239 | +SQL> update tbl_test2 set id=id+2 where id=100 |
| 240 | + * |
| 241 | +ERROR at line 1: |
| 242 | +ORA-00060: deadlock detected while waiting for resource |
| 243 | +Elapsed: 00:00:18.05 |
| 244 | +``` |
| 245 | + |
| 246 | +SESSION A: |
| 247 | + |
| 248 | +``` |
| 249 | +SQL> commit; |
| 250 | +Commit complete. |
| 251 | +Elapsed: 00:00:00.01 |
| 252 | +``` |
| 253 | + |
| 254 | +SESSION B: |
| 255 | + |
| 256 | +``` |
| 257 | +SQL> commit; |
| 258 | +Commit complete. |
| 259 | +Elapsed: 00:00:00.00 |
| 260 | +``` |
| 261 | + |
| 262 | +SESSION C: |
| 263 | + |
| 264 | +``` |
| 265 | +SQL> commit; |
| 266 | +Commit complete. |
| 267 | +Elapsed: 00:00:00.01 |
| 268 | +``` |
| 269 | + |
| 270 | +显然,ORACLE的SESSION A检测到了死锁,并且COMMIT后SESSION A部分SQL执行成功。 |
| 271 | + |
| 272 | +``` |
| 273 | +SQL> select * from tbl_test where id>=100; |
| 274 | + ID |
| 275 | +---------- |
| 276 | + 101 |
| 277 | +Elapsed: 00:00:00.00 |
| 278 | +``` |
| 279 | + |
| 280 | +Oracle 允许事务中部分SQL执行成功, 可能会带来一些比较麻烦的问题, 如下. |
| 281 | + |
| 282 | +举个简单的例子:充值。 |
| 283 | + |
| 284 | +A花了100元购买100个斯凯币。 |
| 285 | + |
| 286 | +``` |
| 287 | +update tbl_account_rmb set amount=amount-100 where id='A'; |
| 288 | +success |
| 289 | +update tbl_account_kb set amount=amount+100 where id='A'; |
| 290 | +deadlock,failed. |
| 291 | +commit; |
| 292 | +``` |
| 293 | + |
| 294 | +此时A的100元花出去了,但是KB没有充值到账。 |
0 commit comments