|
| 1 | +## TOAST table with pgfincore |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2012-01-05 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , toast , 内存持久化 , pg_fadvise , flag , pgfincore |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +pgfincore 可以修改文件的posix_advise属性,输入参数是对象名。如表名,索引名。 |
| 16 | + |
| 17 | +注意有些PostgreSQL数据类型的存储如果选择了为extended或者EXTERNAL存储时。实际上这些内容是存储在TOAST表里面。 |
| 18 | + |
| 19 | +例如text 类型. |
| 20 | + |
| 21 | +下面来看一个例子 : |
| 22 | + |
| 23 | +``` |
| 24 | +digoal=> \d text |
| 25 | + Table "digoal.text" |
| 26 | + Column | Type | Modifiers |
| 27 | +--------+---------+----------- |
| 28 | + id | integer | not null |
| 29 | + info | text | |
| 30 | +Indexes: |
| 31 | + "text_pkey" PRIMARY KEY, btree (id), tablespace "digoal_idx" |
| 32 | +``` |
| 33 | + |
| 34 | +这个表有个toast表, 如下 : |
| 35 | + |
| 36 | +``` |
| 37 | +digoal=> select relname from pg_class where oid=(select reltoastrelid from pg_class where relname='text'); |
| 38 | + relname |
| 39 | +------------------ |
| 40 | + pg_toast_1293339 |
| 41 | +``` |
| 42 | + |
| 43 | +还有个toast索引 : |
| 44 | + |
| 45 | +``` |
| 46 | +digoal=> select relname from pg_class where oid=(select reltoastidxid from pg_class where oid=(select reltoastrelid from pg_class where relname='text')); |
| 47 | + relname |
| 48 | +------------------------ |
| 49 | + pg_toast_1293339_index |
| 50 | +``` |
| 51 | + |
| 52 | +下面我想把text表的posix_fadvise修改一下 : |
| 53 | + |
| 54 | +``` |
| 55 | +digoal=> select * from pgfadvise_willneed('text'); |
| 56 | + relpath | os_page_size | rel_os_pages | os_pages_free |
| 57 | +------------------------------------------------+--------------+--------------+--------------- |
| 58 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124614 | 4096 | 64922 | 30319 |
| 59 | +digoal=> select * from pgfadvise_willneed('text_pkey'); |
| 60 | + relpath | os_page_size | rel_os_pages | os_pages_free |
| 61 | +------------------------------------------------+--------------+--------------+--------------- |
| 62 | + pg_tblspc/16393/PG_9.1_201105231/16394/6124616 | 4096 | 27424 | 31007 |
| 63 | +``` |
| 64 | + |
| 65 | +显然没有包含TOAST表的内容。 |
| 66 | + |
| 67 | +接下来看看如何包含TOAST表的内容 : |
| 68 | + |
| 69 | +首先要看看TOAST表放在哪个schema下面 : |
| 70 | + |
| 71 | +``` |
| 72 | +digoal=> select nspname from pg_namespace where oid=(select relnamespace from pg_class where oid=1293342); |
| 73 | + nspname |
| 74 | +---------- |
| 75 | + pg_toast |
| 76 | +``` |
| 77 | + |
| 78 | +pg_toast的owner是postgres, 因此需要使用超级用户 : |
| 79 | + |
| 80 | +``` |
| 81 | +digoal=> \dn *.* |
| 82 | + List of schemas |
| 83 | + Name | Owner |
| 84 | +--------------------+---------- |
| 85 | + digoal | digoal |
| 86 | + information_schema | postgres |
| 87 | + pg_catalog | postgres |
| 88 | + pg_temp_1 | postgres |
| 89 | + pg_toast | postgres |
| 90 | + pg_toast_temp_1 | postgres |
| 91 | + public | postgres |
| 92 | +``` |
| 93 | + |
| 94 | +接下来就可以把TOAST表和它的索引放入内存了 : |
| 95 | + |
| 96 | +``` |
| 97 | +digoal=# select * from pgfadvise_willneed('pg_toast.pg_toast_1293339'); |
| 98 | + relpath | os_page_size | rel_os_pages | os_pages_free |
| 99 | +---------------------------------------------------+--------------+--------------+--------------- |
| 100 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615 | 4096 | 262144 | 32027 |
| 101 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.1 | 4096 | 262144 | 30055 |
| 102 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.2 | 4096 | 262144 | 31436 |
| 103 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.3 | 4096 | 262144 | 30018 |
| 104 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.4 | 4096 | 262144 | 31654 |
| 105 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.5 | 4096 | 262144 | 29949 |
| 106 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.6 | 4096 | 262144 | 30010 |
| 107 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.7 | 4096 | 262144 | 31135 |
| 108 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.8 | 4096 | 262144 | 30281 |
| 109 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.9 | 4096 | 262144 | 31313 |
| 110 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.10 | 4096 | 262144 | 31253 |
| 111 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.11 | 4096 | 262144 | 31253 |
| 112 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.12 | 4096 | 262144 | 31253 |
| 113 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.13 | 4096 | 262144 | 31253 |
| 114 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.14 | 4096 | 262144 | 31253 |
| 115 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.15 | 4096 | 262144 | 31253 |
| 116 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.16 | 4096 | 262144 | 31253 |
| 117 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.17 | 4096 | 262144 | 31253 |
| 118 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.18 | 4096 | 262144 | 31253 |
| 119 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124615.19 | 4096 | 19264 | 31253 |
| 120 | +(20 rows) |
| 121 | +digoal=# select * from pgfadvise_willneed('pg_toast.pg_toast_1293339_index'); |
| 122 | + relpath | os_page_size | rel_os_pages | os_pages_free |
| 123 | +------------------------------------------------+--------------+--------------+--------------- |
| 124 | + pg_tblspc/16392/PG_9.1_201105231/16394/6124617 | 4096 | 54842 | 30332 |
| 125 | +(1 row) |
| 126 | +``` |
| 127 | + |
| 128 | +[Count](http://info.flagcounter.com/h9V1) |
| 129 | + |
| 130 | + |
0 commit comments