|
| 1 | +## PostgreSQL schemaless 的实现(类mongodb collection) |
| 2 | + |
| 3 | +### 作者 |
| 4 | +digoal |
| 5 | + |
| 6 | +### 日期 |
| 7 | +2017-05-11 |
| 8 | + |
| 9 | +### 标签 |
| 10 | +PostgreSQL , schemaless , mongodb |
| 11 | + |
| 12 | +---- |
| 13 | + |
| 14 | +## 背景 |
| 15 | +使用mongodb时,并不需要先建表(collection),直接就可以往里面写,原因是collection本事就是固定的BSON结构。 |
| 16 | + |
| 17 | +所以当用户插入时,如果表不存在,建一个BSON结构的colleciton即可。 |
| 18 | + |
| 19 | +而关系数据库无法做到这一点,因为关系数据库的表结构都是事先构建,并且在写入数据时,是需要检查对应的类型,约束的。 |
| 20 | + |
| 21 | +那么有没有办法让PostgreSQL关系数据库也实现类似mongo这种schemaless的表呢? |
| 22 | + |
| 23 | +## 函数式写入 |
| 24 | +用户通过调用函数,写入数据。 |
| 25 | + |
| 26 | +在函数中处理并实现schemaless。 |
| 27 | + |
| 28 | +## 例子 |
| 29 | +创建一个自动建表的函数,用于自动创建目标表。 |
| 30 | + |
| 31 | +``` |
| 32 | +create or replace function create_schemaless(target name) returns void as $$ |
| 33 | +declare |
| 34 | +begin |
| 35 | + execute format('create table if not exists %I (content jsonb)', target); |
| 36 | +exception when others then |
| 37 | + return; |
| 38 | +end; |
| 39 | +$$ language plpgsql strict; |
| 40 | +``` |
| 41 | + |
| 42 | +创建一个插入数据的函数,使用动态SQL,如果遇到表不存在的错误,则调用建表函数进行建表。 |
| 43 | + |
| 44 | +``` |
| 45 | +create or replace function ins_schemaless(target name, content jsonb) returns void as $$ |
| 46 | +declare |
| 47 | +begin |
| 48 | + execute format('insert into %I values (%L)', target, content); |
| 49 | + exception |
| 50 | + WHEN SQLSTATE '42P01' THEN |
| 51 | + perform create_schemaless(target); |
| 52 | + execute format('insert into %I values (%L)', target, content); |
| 53 | +end; |
| 54 | +$$ language plpgsql strict; |
| 55 | +``` |
| 56 | + |
| 57 | +调用函数插入数据,不需要建表,会自动创建。 |
| 58 | + |
| 59 | +``` |
| 60 | +postgres=# select ins_schemaless('abcde','{"a":123.1}'); |
| 61 | + ins_schemaless |
| 62 | +---------------- |
| 63 | + |
| 64 | +(1 row) |
| 65 | + |
| 66 | +postgres=# select * from abcde; |
| 67 | + content |
| 68 | +-------------- |
| 69 | + {"a": 123.1} |
| 70 | +(1 row) |
| 71 | + |
| 72 | +postgres=# select ins_schemaless('abcde','{"a":123.1}'); |
| 73 | + ins_schemaless |
| 74 | +---------------- |
| 75 | + |
| 76 | +(1 row) |
| 77 | + |
| 78 | +postgres=# select * from abcde; |
| 79 | + content |
| 80 | +-------------- |
| 81 | + {"a": 123.1} |
| 82 | + {"a": 123.1} |
| 83 | +(2 rows) |
| 84 | + |
| 85 | +postgres=# select ins_schemaless('abcdefg','{"a":123.1}'); |
| 86 | + ins_schemaless |
| 87 | +---------------- |
| 88 | + |
| 89 | +(1 row) |
| 90 | + |
| 91 | +postgres=# select * from abcdefg; |
| 92 | + content |
| 93 | +-------------- |
| 94 | + {"a": 123.1} |
| 95 | +(1 row) |
| 96 | +``` |
| 97 | + |
| 98 | +函数支持并发插入,不会相互影响。 |
| 99 | + |
| 100 | + |
| 101 | +## 性能 |
| 102 | +由于使用了动态SQL,性能略差。 |
| 103 | + |
| 104 | +``` |
| 105 | +transaction type: ./test.sql |
| 106 | +scaling factor: 1 |
| 107 | +query mode: prepared |
| 108 | +number of clients: 32 |
| 109 | +number of threads: 32 |
| 110 | +duration: 120 s |
| 111 | +number of transactions actually processed: 26908558 |
| 112 | +latency average = 0.143 ms |
| 113 | +latency stddev = 1.397 ms |
| 114 | +tps = 224219.413026 (including connections establishing) |
| 115 | +tps = 224353.960206 (excluding connections establishing) |
| 116 | +script statistics: |
| 117 | + - statement latencies in milliseconds: |
| 118 | + 0.143 select ins_schemaless('c','{}'); |
| 119 | +``` |
| 120 | + |
| 121 | +使用绑定变量,性能如下。 |
| 122 | + |
| 123 | +``` |
| 124 | +transaction type: ./test.sql |
| 125 | +scaling factor: 1 |
| 126 | +query mode: prepared |
| 127 | +number of clients: 32 |
| 128 | +number of threads: 32 |
| 129 | +duration: 120 s |
| 130 | +number of transactions actually processed: 39684200 |
| 131 | +latency average = 0.097 ms |
| 132 | +latency stddev = 2.192 ms |
| 133 | +tps = 330698.368601 (including connections establishing) |
| 134 | +tps = 330708.294542 (excluding connections establishing) |
| 135 | +script statistics: |
| 136 | + - statement latencies in milliseconds: |
| 137 | + 0.097 insert into c values ('{}'); |
| 138 | +``` |
| 139 | + |
| 140 | +损失11万的QPS,获得schemaless的能力,要不要呢? |
| 141 | + |
| 142 | +当然,如果是从内核层面来支持就更爽了,性能问题可能也能得到解决,比如。 |
| 143 | + |
| 144 | +``` |
| 145 | +insert into schemaless tbl values (jsonb); |
| 146 | +``` |
0 commit comments