|
| 1 | +## PostgreSQL 回收站功能 - 基于HOOK的recycle bin pgtrashcan |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2014-04-03 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , 回收站 , recycle bin , pgtranshcan , hook , _PG_init |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +PostgreSQL 本身不支持类似Oracle recycle bin这样的回收站机制. |
| 16 | + |
| 17 | +但是我们可以通过事件触发器来实现同类功能,参考 |
| 18 | + |
| 19 | +[《PostgreSQL 事件触发器 - 实现类似Oracle的回收站功能》](20150429_01.md) |
| 20 | + |
| 21 | +本文将介绍使用PostgreSQL 动态模块, 以及_PG_init函数来创建钩子程序. (_PG_init函数在加载动态模块时立即执行, 动态模块在会话建立时被加载, 所以很好被利用) |
| 22 | + |
| 23 | +在钩子程序中写一些逻辑, 将删除表的操作, 转移到其他SCHEMA. |
| 24 | + |
| 25 | +pgtrashcan就是利用这种机制来实现类似Oracle recycle bin的功能的. |
| 26 | + |
| 27 | +## _PG_init与pgtrashcan介绍 |
| 28 | +pgtrashcan写的_PG_init如下 |
| 29 | + |
| 30 | +``` |
| 31 | +void |
| 32 | +_PG_init(void) |
| 33 | +{ |
| 34 | + prev_ProcessUtility = ProcessUtility_hook; |
| 35 | + if (!prev_ProcessUtility) |
| 36 | + prev_ProcessUtility = standard_ProcessUtility; |
| 37 | + ProcessUtility_hook = pgtrashcan_ProcessUtility; |
| 38 | +} |
| 39 | +``` |
| 40 | + |
| 41 | +钩子程序对应的函数部分内容 : |
| 42 | + |
| 43 | +``` |
| 44 | +static void |
| 45 | +pgtrashcan_ProcessUtility(Node *parsetree, |
| 46 | + const char *queryString, |
| 47 | + ParamListInfo params, |
| 48 | + bool isTopLevel, |
| 49 | + DestReceiver *dest, |
| 50 | + char *completionTag) |
| 51 | +#endif |
| 52 | +{ |
| 53 | + if (nodeTag(parsetree) == T_DropStmt) |
| 54 | + { |
| 55 | + DropStmt *stmt = (DropStmt *) parsetree; |
| 56 | + |
| 57 | + if (stmt->removeType == OBJECT_TABLE) |
| 58 | + { |
| 59 | + RangeVar *r; |
| 60 | + AlterObjectSchemaStmt *newstmt = makeNode(AlterObjectSchemaStmt); |
| 61 | + newstmt->objectType = stmt->removeType; |
| 62 | + newstmt->newschema = pstrdup(trashcan_nspname); |
| 63 | +#if PG_VERSION_NUM >= 90200 |
| 64 | + newstmt->missing_ok = stmt->missing_ok; |
| 65 | +#endif |
| 66 | + if (stmt->behavior != DROP_RESTRICT) |
| 67 | + ereport(ERROR, |
| 68 | + (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), |
| 69 | + errmsg("trash can does not support DROP CASCADE"))); |
| 70 | + |
| 71 | + r = makeRangeVarFromAnyName(linitial(stmt->objects)); |
| 72 | + r->inhOpt = INH_YES; |
| 73 | + r->alias = NULL; |
| 74 | + newstmt->relation = r; |
| 75 | + |
| 76 | + if (!r->schemaname || strcmp(r->schemaname, trashcan_nspname) != 0) |
| 77 | + { |
| 78 | + parsetree = (Node *) newstmt; |
| 79 | + create_trashcan_schema(); |
| 80 | + } |
| 81 | + } |
| 82 | + } |
| 83 | + |
| 84 | +#if PG_VERSION_NUM >= 90300 |
| 85 | + (*prev_ProcessUtility) (parsetree, queryString, context, params, dest, completionTag); |
| 86 | +#else |
| 87 | + (*prev_ProcessUtility) (parsetree, queryString, params, isTopLevel, dest, completionTag); |
| 88 | +#endif |
| 89 | +} |
| 90 | + |
| 91 | +static void |
| 92 | +create_trashcan_schema(void) |
| 93 | +{ |
| 94 | + HeapTuple tuple; |
| 95 | + Oid datdba; |
| 96 | + |
| 97 | + if (SearchSysCacheExists1(NAMESPACENAME, PointerGetDatum(trashcan_nspname))) |
| 98 | + return; |
| 99 | + |
| 100 | + tuple = SearchSysCache1(DATABASEOID, ObjectIdGetDatum(MyDatabaseId)); |
| 101 | + if (!HeapTupleIsValid(tuple)) |
| 102 | + ereport(ERROR, |
| 103 | + (errcode(ERRCODE_UNDEFINED_DATABASE), |
| 104 | + errmsg("database with OID %u does not exist", MyDatabaseId))); |
| 105 | + |
| 106 | + datdba = ((Form_pg_database) GETSTRUCT(tuple))->datdba; |
| 107 | + ReleaseSysCache(tuple); |
| 108 | + |
| 109 | + NamespaceCreate(trashcan_nspname, datdba, false); |
| 110 | + |
| 111 | + CommandCounterIncrement(); |
| 112 | +} |
| 113 | +``` |
| 114 | + |
| 115 | +pgtrashcan的做法是, 在 drop一个表时, 创建一个名为Trash的schema, 然后将被删除的表移动到这个schema下面. |
| 116 | + |
| 117 | +目前pgtrashcan的功能比较单一, 且缺少一些判断, 见本文末尾, 还需要改进. |
| 118 | + |
| 119 | +## pgtrashcan测试 |
| 120 | +使用测试 : |
| 121 | + |
| 122 | +``` |
| 123 | +su - root |
| 124 | +git clone https://github.com/petere/pgtrashcan |
| 125 | + |
| 126 | +cd pgtrashcan/ |
| 127 | + |
| 128 | +export PATH=/home/pg93/pgsql9.3.3/bin:$PATH |
| 129 | +make |
| 130 | +make install |
| 131 | + |
| 132 | +su - pg93 |
| 133 | + |
| 134 | +cd $PGDATA |
| 135 | +vi postgresql.conf |
| 136 | + |
| 137 | +shared_preload_libraries = 'auto_explain,pgtrashcan' |
| 138 | + |
| 139 | +pg_ctl restart -m fast |
| 140 | +``` |
| 141 | + |
| 142 | +开始啦 |
| 143 | + |
| 144 | +``` |
| 145 | +pg93@db-172-16-3-150-> psql |
| 146 | +psql (9.3.3) |
| 147 | +Type "help" for help. |
| 148 | + |
| 149 | +digoal=# \dt |
| 150 | + List of relations |
| 151 | + Schema | Name | Type | Owner |
| 152 | +--------+----------+-------+---------- |
| 153 | + public | logtable | table | postgres |
| 154 | + public | test | table | postgres |
| 155 | +(2 rows) |
| 156 | + |
| 157 | +digoal=# drop table test; |
| 158 | +DROP TABLE |
| 159 | +digoal=# \dn |
| 160 | + List of schemas |
| 161 | + Name | Owner |
| 162 | +--------+---------- |
| 163 | + Trash | postgres |
| 164 | + digoal | postgres |
| 165 | + public | postgres |
| 166 | +(3 rows) |
| 167 | +``` |
| 168 | + |
| 169 | +这个表被重定向到"Trash" schema下面. |
| 170 | + |
| 171 | +``` |
| 172 | +digoal=# \dt+ "Trash".test |
| 173 | + List of relations |
| 174 | + Schema | Name | Type | Owner | Size | Description |
| 175 | +--------+------+-------+----------+-------+------------- |
| 176 | + Trash | test | table | postgres | 32 kB | |
| 177 | +(1 row) |
| 178 | +``` |
| 179 | + |
| 180 | +## pgtrashcan插件的使用限制 |
| 181 | +1\. 目前pgtrashcan不支持drop cascade用法(例如删除主表, 或者删除连带的FK关系). |
| 182 | + |
| 183 | +例如 : |
| 184 | + |
| 185 | +``` |
| 186 | +digoal=# drop table test cascade; |
| 187 | +ERROR: 0A000: trash can does not support DROP CASCADE |
| 188 | +LOCATION: pgtrashcan_ProcessUtility, pgtrashcan.c:146 |
| 189 | +``` |
| 190 | + |
| 191 | +2\. 代码中, 并没有同名表的判断, 所以当Trash schema中存在同名的表时, 也会报错. |
| 192 | + |
| 193 | +例如 : |
| 194 | + |
| 195 | +``` |
| 196 | +digoal=# \set VERBOSITY verbose |
| 197 | +digoal=# drop table test; |
| 198 | +ERROR: 42P07: relation "test" already exists in schema "Trash" |
| 199 | +LOCATION: AlterRelationNamespaceInternal, tablecmds.c:10054 |
| 200 | +``` |
| 201 | + |
| 202 | +3\. drop table 的用户需要创建schema的权限, 以及写Trash schema的权限. 如果没有创建schema 的权限也会报错. |
| 203 | + |
| 204 | +``` |
| 205 | +digoal=> drop table t; |
| 206 | +ERROR: 42501: permission denied for schema Trash |
| 207 | +LOCATION: aclcheck_error, aclchk.c:3371 |
| 208 | +``` |
| 209 | + |
| 210 | +不过这些问题都是可以解决的,看未来pgtrashcan的改进吧 |
| 211 | + |
| 212 | +也许稳定了之后就会合并到PG的master分支了 |
| 213 | + |
| 214 | +## 参考 |
| 215 | +1\. https://github.com/petere/pgtrashcan |
| 216 | + |
| 217 | +2\. http://www.postgresql.org/docs/9.3/static/xfunc-c.html |
| 218 | + |
| 219 | +``` |
| 220 | +Optionally, a dynamically loaded file can contain initialization and finalization functions. |
| 221 | + |
| 222 | +If the file includes a function named _PG_init, that function will be called immediately after loading the file. |
| 223 | + |
| 224 | +The function receives no parameters and should return void. If the file includes a function named _PG_fini, that function will be called immediately before unloading the file. |
| 225 | + |
| 226 | +Likewise, the function receives no parameters and should return void. |
| 227 | + |
| 228 | +Note that _PG_fini will only be called during an unload of the file, not during process termination. |
| 229 | + |
| 230 | +(Presently, unloads are disabled and will never occur, but this may change in the future.) |
| 231 | +``` |
| 232 | + |
| 233 | +[Count](http://info.flagcounter.com/h9V1) |
| 234 | + |
| 235 | + |
| 236 | + |
0 commit comments