├── logical.conf ├── visibility.map ├── .gitignore ├── sql ├── full.sql ├── default.sql └── basic.sql ├── README.md ├── Makefile ├── make.sh ├── UNLICENSE ├── expected └── default.out └── decoder_json.c /logical.conf: -------------------------------------------------------------------------------- 1 | wal_level = logical 2 | max_replication_slots = 4 -------------------------------------------------------------------------------- /visibility.map: -------------------------------------------------------------------------------- 1 | PG 2 | { 3 | global: Pg_magic_func; _PG_output_plugin_init; 4 | local: *; 5 | }; 6 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # Object files 2 | *.o 3 | 4 | # Libraries 5 | *.lib 6 | *.a 7 | 8 | # Shared objects (inc. Windows DLLs) 9 | *.dll 10 | *.so 11 | *.so.* 12 | *.dylib 13 | 14 | /jansson-* 15 | 16 | # Regression output 17 | /regression.diffs 18 | /regression.out 19 | /results/ 20 | 21 | #qt creator files 22 | decoder_json.creator 23 | decoder_json.creator.user 24 | decoder_json.files 25 | decoder_json.includes 26 | decoder_json.config -------------------------------------------------------------------------------- /sql/full.sql: -------------------------------------------------------------------------------- 1 | SELECT slot_name FROM pg_create_logical_replication_slot('custom_slot', 'decoder_json'); 2 | 3 | -- FULL case with PRIMARY KEY 4 | DROP TABLE IF EXISTS AA; 5 | CREATE TABLE aa (a int primary key, b text NOT NULL); 6 | ALTER TABLE aa WITH REPLICA IDENTITY FULL; 7 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 8 | UPDATE aa SET b = 'aa1' where a = 1; -- Primary key not changed 9 | UPDATE aa SET a=3, b = 'aa2' where a = 1; -- Primary key changed 10 | UPDATE aa SET b='cc' WHERE a != 0; 11 | 12 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 13 | SELECT pg_drop_replication_slot('custom_slot'); -------------------------------------------------------------------------------- /README.md: -------------------------------------------------------------------------------- 1 | # decoder_json 2 | 3 | A PostgreSQL logical decoder output plugin to deliver data in JSON 4 | 5 | # Requirements: 6 | 7 | * PostgreSQL 9.4+ 8 | * libjansson (for JSON support) 9 | 10 | # Building 11 | 12 | ``` 13 | make deps 14 | make 15 | ``` 16 | 17 | # Testing 18 | 19 | Add to your postgresql.conf lines from logical.conf. Then run: 20 | 21 | ``` 22 | sudo chmod +x `pg_config --pkglibdir` 23 | make test 24 | ``` 25 | 26 | # TODO: 27 | 28 | Use built-in JSON from PostgreSQL for output generation. 29 | 30 | # Useful links 31 | 32 | * https://github.com/xstevens/decoderbufs - uses Protocol Buffers 33 | * https://github.com/michaelpq/pg_plugins/tree/master/decoder_raw - generates SQL queries 34 | * http://git.postgresql.org/gitweb/?p=postgresql.git;a=tree;f=contrib/test_decoding;h=ed74920f61b3440d2d880a8fdfc74ec8d12fcd35;hb=HEAD - sample decoder from postgresql sources -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | PG_CONFIG = pg_config 2 | PGXS := $(shell $(PG_CONFIG) --pgxs) 3 | MODULE_big = decoder_json 4 | OBJS = decoder_json.o 5 | JANSSON_VERSION = 2.7 6 | SHLIB_LINK = -Wl,--version-script,visibility.map ./jansson-${JANSSON_VERSION}/build/lib/libjansson.a 7 | PG_CPPFLAGS = -I./jansson-${JANSSON_VERSION}/build/include 8 | REGRESS = default 9 | 10 | include $(PGXS) 11 | 12 | deps: 13 | wget https://github.com/akheron/jansson/archive/v${JANSSON_VERSION}.tar.gz 14 | mv v${JANSSON_VERSION}.tar.gz jannson.tar.gz 15 | tar xzf jannson.tar.gz 16 | rm jannson.tar.gz 17 | echo "libjansson_a_CFLAGS = -fPIC" >> jansson-${JANSSON_VERSION}/src/Makefile.am 18 | cd jansson-${JANSSON_VERSION} && mkdir build && cd build && cmake .. && make 19 | 20 | test: 21 | - psql contrib_regression -c "SELECT pg_drop_replication_slot('custom_slot');" 22 | - rm `pg_config --pkglibdir`/decoder_json.so 23 | cp decoder_json.so `pg_config --pkglibdir`/ 24 | make installcheck 25 | -------------------------------------------------------------------------------- /make.sh: -------------------------------------------------------------------------------- 1 | gcc -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fexcess-precision=standard -g -g -O2 -fstack-protector --param=ssp-buffer-size=4 -Wformat -Werror=format-security -I/usr/include/mit-krb5 -fPIC -pie -DLINUX_OOM_SCORE_ADJ=0 -fno-omit-frame-pointer -fpic -I. -I./ -I/usr/include/postgresql/9.4/server -I/usr/include/postgresql/internal -D_FORTIFY_SOURCE=2 -D_GNU_SOURCE -I/usr/include/libxml2 -I/usr/include/tcl8.6 -c -o decoder_json.o decoder_json.c 2 | gcc -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fexcess-precision=standard -g -g -O2 -fstack-protector --param=ssp-buffer-size=4 -Wformat -Werror=format-security -I/usr/include/mit-krb5 -fPIC -pie -DLINUX_OOM_SCORE_ADJ=0 -fno-omit-frame-pointer -fpic -L/usr/lib/x86_64-linux-gnu -Wl,-Bsymbolic-functions -Wl,-z,relro -Wl,-z,now -Wl,--as-needed -L/usr/lib/mit-krb5 -L/usr/lib/x86_64-linux-gnu/mit-krb5 -Wl,--as-needed -shared -o decoder_json.so decoder_json.o /home/ildus/src/jansson-2.7/src/.libs/libjansson.a -------------------------------------------------------------------------------- /UNLICENSE: -------------------------------------------------------------------------------- 1 | This is free and unencumbered software released into the public domain. 2 | 3 | Anyone is free to copy, modify, publish, use, compile, sell, or 4 | distribute this software, either in source code form or as a compiled 5 | binary, for any purpose, commercial or non-commercial, and by any 6 | means. 7 | 8 | In jurisdictions that recognize copyright laws, the author or authors 9 | of this software dedicate any and all copyright interest in the 10 | software to the public domain. We make this dedication for the benefit 11 | of the public at large and to the detriment of our heirs and 12 | successors. We intend this dedication to be an overt act of 13 | relinquishment in perpetuity of all present and future rights to this 14 | software under copyright law. 15 | 16 | THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, 17 | EXPRESS OR IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF 18 | MERCHANTABILITY, FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. 19 | IN NO EVENT SHALL THE AUTHORS BE LIABLE FOR ANY CLAIM, DAMAGES OR 20 | OTHER LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, 21 | ARISING FROM, OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR 22 | OTHER DEALINGS IN THE SOFTWARE. 23 | 24 | For more information, please refer to 25 | -------------------------------------------------------------------------------- /sql/default.sql: -------------------------------------------------------------------------------- 1 | -- SET UP 2 | SELECT slot_name FROM pg_create_logical_replication_slot('custom_slot', 'decoder_json'); 3 | 4 | -- DEFAULT case with PRIMARY KEY 5 | CREATE TABLE aa (a int primary key, b text NOT NULL); 6 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 7 | UPDATE aa SET b = 'aa1' where a = 1; -- Primary key not changed 8 | UPDATE aa SET a=3, b = 'aa2' where a = 1; -- Primary key changed 9 | UPDATE aa SET b='cc' WHERE a != 0; 10 | 11 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 12 | DROP TABLE aa; 13 | 14 | -- DEFAULT case without PRIMARY KEY 15 | CREATE TABLE aa (a int, b text NOT NULL); 16 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 17 | UPDATE aa SET b = 'aa1' where a = 1; 18 | UPDATE aa SET a=3, b = 'aa2' where a = 1; 19 | UPDATE aa SET b='cc' WHERE a != 0; 20 | 21 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 22 | DROP TABLE aa; 23 | 24 | -- TESTING VARIOUS TYPES 25 | CREATE TABLE aa (a int primary key, b text, c int null, d numeric(6,2), e char, f varchar(10), g boolean, h text[], i varchar[], j int[]); 26 | INSERT INTO aa VALUES (1, 'aa', null, '1255.56', 'e', 'text1', true, array['one', 'two'], array['three', 'four'], array[1,2]); 27 | 28 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 29 | DROP TABLE aa; 30 | 31 | -- TEAR DOWN 32 | SELECT pg_drop_replication_slot('custom_slot'); -------------------------------------------------------------------------------- /expected/default.out: -------------------------------------------------------------------------------- 1 | -- SET UP 2 | SELECT slot_name FROM pg_create_logical_replication_slot('custom_slot', 'decoder_json'); 3 | slot_name 4 | ------------- 5 | custom_slot 6 | (1 row) 7 | 8 | -- DEFAULT case with PRIMARY KEY 9 | CREATE TABLE aa (a int primary key, b text NOT NULL); 10 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 11 | UPDATE aa SET b = 'aa1' where a = 1; -- Primary key not changed 12 | UPDATE aa SET a=3, b = 'aa2' where a = 1; -- Primary key changed 13 | UPDATE aa SET b='cc' WHERE a != 0; 14 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 15 | data 16 | ----------------------------------------------------------- 17 | {"a":0,"d":{"a":1,"b":"aa"},"r":"public.aa"} 18 | {"a":0,"d":{"a":2,"b":"bb"},"r":"public.aa"} 19 | {"a":1,"c":{"a":1},"d":{"a":1,"b":"aa1"},"r":"public.aa"} 20 | {"a":1,"c":{"a":1},"d":{"a":3,"b":"aa2"},"r":"public.aa"} 21 | {"a":1,"c":{"a":2},"d":{"a":2,"b":"cc"},"r":"public.aa"} 22 | {"a":1,"c":{"a":3},"d":{"a":3,"b":"cc"},"r":"public.aa"} 23 | (6 rows) 24 | 25 | DROP TABLE aa; 26 | -- DEFAULT case without PRIMARY KEY 27 | CREATE TABLE aa (a int, b text NOT NULL); 28 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 29 | UPDATE aa SET b = 'aa1' where a = 1; 30 | UPDATE aa SET a=3, b = 'aa2' where a = 1; 31 | UPDATE aa SET b='cc' WHERE a != 0; 32 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 33 | data 34 | ---------------------------------------------- 35 | {"a":0,"d":{"a":1,"b":"aa"},"r":"public.aa"} 36 | {"a":0,"d":{"a":2,"b":"bb"},"r":"public.aa"} 37 | (2 rows) 38 | 39 | DROP TABLE aa; 40 | -- TESTING VARIOUS TYPES 41 | CREATE TABLE aa (a int primary key, b text, c int null, d numeric(6,2), e char, f varchar(10), g boolean, h text[], i varchar[], j int[]); 42 | INSERT INTO aa VALUES (1, 'aa', null, '1255.56', 'e', 'text1', true, array['one', 'two'], array['three', 'four'], array[1,2]); 43 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'off', 'sort_keys', 'on'); 44 | data 45 | --------------------------------------------------------------------------------------------------------------------------------------------------- 46 | {"a":0,"d":{"a":1,"b":"aa","c":null,"d":"1255.56","e":"e","f":"text1","g":true,"h":["one","two"],"i":["three","four"],"j":[1,2]},"r":"public.aa"} 47 | (1 row) 48 | 49 | DROP TABLE aa; 50 | -- TEAR DOWN 51 | SELECT pg_drop_replication_slot('custom_slot'); 52 | pg_drop_replication_slot 53 | -------------------------- 54 | 55 | (1 row) 56 | 57 | -------------------------------------------------------------------------------- /sql/basic.sql: -------------------------------------------------------------------------------- 1 | -- 2 | -- Basic tests 3 | -- 4 | 5 | -- Create a replication slot 6 | SELECT slot_name FROM pg_create_logical_replication_slot('custom_slot', 'decoder_json'); 7 | 8 | -- DEFAULT case with PRIMARY KEY 9 | CREATE TABLE aa (a int primary key, b text NOT NULL); 10 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 11 | -- Update of Non-selective column 12 | UPDATE aa SET b = 'cc' WHERE a = 1; 13 | -- Update of only selective column 14 | UPDATE aa SET a = 3 WHERE a = 1; 15 | -- Update of both columns 16 | UPDATE aa SET a = 4, b = 'dd' WHERE a = 2; 17 | DELETE FROM aa WHERE a = 4; 18 | -- Have a look at changes with different modes. 19 | -- In the second call changes are consumed to not impact the next cases. 20 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 21 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 22 | DROP TABLE aa; 23 | 24 | -- DEFAULT case without PRIMARY KEY 25 | CREATE TABLE aa (a int, b text NOT NULL); 26 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 27 | -- Update of Non-selective column 28 | UPDATE aa SET b = 'cc' WHERE a = 1; 29 | -- Update of only selective column 30 | UPDATE aa SET a = 3 WHERE a = 1; 31 | -- Update of both columns 32 | UPDATE aa SET a = 4, b = 'dd' WHERE a = 2; 33 | DELETE FROM aa WHERE a = 4; 34 | -- Have a look at changes with different modes. 35 | -- In the second call changes are consumed to not impact the next cases. 36 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 37 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 38 | DROP TABLE aa; 39 | 40 | -- INDEX case 41 | CREATE TABLE aa (a int NOT NULL, b text); 42 | CREATE UNIQUE INDEX aai ON aa(a); 43 | ALTER TABLE aa REPLICA IDENTITY USING INDEX aai; 44 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 45 | -- Update of Non-selective column 46 | UPDATE aa SET b = 'cc' WHERE a = 1; 47 | -- Update of only selective column 48 | UPDATE aa SET a = 3 WHERE a = 1; 49 | -- Update of both columns 50 | UPDATE aa SET a = 4, b = 'dd' WHERE a = 2; 51 | DELETE FROM aa WHERE a = 4; 52 | -- Have a look at changes with different modes 53 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 54 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 55 | DROP TABLE aa; 56 | 57 | -- INDEX case using a second column 58 | CREATE TABLE aa (b text, a int NOT NULL); 59 | CREATE UNIQUE INDEX aai ON aa(a); 60 | ALTER TABLE aa REPLICA IDENTITY USING INDEX aai; 61 | INSERT INTO aa VALUES ('aa', 1), ('bb', 2); 62 | -- Update of Non-selective column 63 | UPDATE aa SET b = 'cc' WHERE a = 1; 64 | -- Update of only selective column 65 | UPDATE aa SET a = 3 WHERE a = 1; 66 | -- Update of both columns 67 | UPDATE aa SET a = 4, b = 'dd' WHERE a = 2; 68 | DELETE FROM aa WHERE a = 4; 69 | -- Have a look at changes with different modes 70 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 71 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 72 | DROP TABLE aa; 73 | 74 | -- FULL case 75 | CREATE TABLE aa (a int primary key, b text NOT NULL); 76 | ALTER TABLE aa REPLICA IDENTITY FULL; 77 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 78 | -- Update of Non-selective column 79 | UPDATE aa SET b = 'cc' WHERE a = 1; 80 | -- Update of only selective column 81 | UPDATE aa SET a = 3 WHERE a = 1; 82 | -- Update of both columns 83 | UPDATE aa SET a = 4, b = 'dd' WHERE a = 2; 84 | DELETE FROM aa WHERE a = 4; 85 | -- Have a look at changes with different modes 86 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 87 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 88 | DROP TABLE aa; 89 | 90 | -- NOTHING case 91 | CREATE TABLE aa (a int primary key, b text NOT NULL); 92 | ALTER TABLE aa REPLICA IDENTITY NOTHING; 93 | INSERT INTO aa VALUES (1, 'aa'), (2, 'bb'); 94 | UPDATE aa SET b = 'cc' WHERE a = 1; 95 | UPDATE aa SET a = 3 WHERE a = 1; 96 | DELETE FROM aa WHERE a = 4; 97 | -- Have a look at changes with different modes 98 | SELECT data FROM pg_logical_slot_peek_changes('custom_slot', NULL, NULL, 'include_transaction', 'off'); 99 | SELECT data FROM pg_logical_slot_get_changes('custom_slot', NULL, NULL, 'include_transaction', 'on'); 100 | DROP TABLE aa; 101 | 102 | -- Drop replication slot 103 | SELECT pg_drop_replication_slot('custom_slot'); 104 | -------------------------------------------------------------------------------- /decoder_json.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * decoder_json.c 4 | * Logical decoding output plugin generating JSON structures based 5 | * on things decoded. 6 | * 7 | * Author, Ildus Kurbangaliev 8 | * 9 | * IDENTIFICATION 10 | * decoder_json/decoder_json.c 11 | * 12 | * TODO: 13 | * 1) add detail logs for unsupported types and other cases (replica identity) 14 | * 2) use postgresql internal realization of json 15 | * 16 | *------------------------------------------------------------------------- 17 | */ 18 | 19 | #include "postgres.h" 20 | #include "access/genam.h" 21 | #include "access/sysattr.h" 22 | #include "catalog/pg_class.h" 23 | #include "catalog/pg_type.h" 24 | #include "nodes/parsenodes.h" 25 | #include "replication/output_plugin.h" 26 | #include "replication/logical.h" 27 | #include "utils/builtins.h" 28 | #include "utils/lsyscache.h" 29 | #include "utils/memutils.h" 30 | #include "utils/rel.h" 31 | #include "utils/relcache.h" 32 | #include "utils/syscache.h" 33 | #include "utils/typcache.h" 34 | #include "utils/array.h" 35 | #include 36 | #include 37 | 38 | PG_MODULE_MAGIC; 39 | 40 | /* These must be available to pg_dlsym() */ 41 | extern void _PG_init(void); 42 | extern void _PG_output_plugin_init(OutputPluginCallbacks *cb); 43 | 44 | /* 45 | * Structure storing the plugin specifications and options. 46 | */ 47 | typedef struct 48 | { 49 | MemoryContext context; 50 | bool include_transaction; 51 | bool sort_keys; 52 | } DecoderRawData; 53 | 54 | typedef struct 55 | { 56 | char *name; 57 | json_t *value; 58 | } Pair; 59 | 60 | static void decoder_json_startup(LogicalDecodingContext *ctx, 61 | OutputPluginOptions *opt, 62 | bool is_init); 63 | static void decoder_json_shutdown(LogicalDecodingContext *ctx); 64 | static void decoder_json_begin_txn(LogicalDecodingContext *ctx, 65 | ReorderBufferTXN *txn); 66 | static void decoder_json_commit_txn(LogicalDecodingContext *ctx, 67 | ReorderBufferTXN *txn, 68 | XLogRecPtr commit_lsn); 69 | static void decoder_json_change(LogicalDecodingContext *ctx, 70 | ReorderBufferTXN *txn, Relation rel, 71 | ReorderBufferChange *change); 72 | 73 | void 74 | _PG_init(void) 75 | { 76 | /* other plugins can perform things here */ 77 | } 78 | 79 | /* specify output plugin callbacks */ 80 | void 81 | _PG_output_plugin_init(OutputPluginCallbacks *cb) 82 | { 83 | AssertVariableIsOfType(&_PG_output_plugin_init, LogicalOutputPluginInit); 84 | 85 | cb->startup_cb = decoder_json_startup; 86 | cb->begin_cb = decoder_json_begin_txn; 87 | cb->change_cb = decoder_json_change; 88 | cb->commit_cb = decoder_json_commit_txn; 89 | cb->shutdown_cb = decoder_json_shutdown; 90 | } 91 | 92 | 93 | /* initialize this plugin */ 94 | static void 95 | decoder_json_startup(LogicalDecodingContext *ctx, 96 | OutputPluginOptions *opt, 97 | bool is_init) 98 | { 99 | ListCell *option; 100 | DecoderRawData *data; 101 | 102 | json_set_alloc_funcs(palloc,pfree); 103 | data = palloc(sizeof(DecoderRawData)); 104 | assert(data); 105 | data->context = AllocSetContextCreate(ctx->context, 106 | "Raw decoder context", 107 | ALLOCSET_DEFAULT_MINSIZE, 108 | ALLOCSET_DEFAULT_INITSIZE, 109 | ALLOCSET_DEFAULT_MAXSIZE); 110 | data->include_transaction = false; 111 | data->sort_keys = false; 112 | 113 | ctx->output_plugin_private = data; 114 | 115 | /* Default output format */ 116 | opt->output_type = OUTPUT_PLUGIN_TEXTUAL_OUTPUT; 117 | 118 | foreach(option, ctx->output_plugin_options) 119 | { 120 | DefElem *elem = lfirst(option); 121 | 122 | Assert(elem->arg == NULL || IsA(elem->arg, String)); 123 | 124 | if (strcmp(elem->defname, "include_transaction") == 0) 125 | { 126 | /* if option does not provide a value, it means its value is true */ 127 | if (elem->arg == NULL) 128 | data->include_transaction = true; 129 | else if (!parse_bool(strVal(elem->arg), &data->include_transaction)) 130 | ereport(ERROR, 131 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 132 | errmsg("could not parse value \"%s\" for parameter \"%s\"", 133 | strVal(elem->arg), elem->defname))); 134 | } 135 | else if (strcmp(elem->defname, "sort_keys") == 0) { 136 | /* if option does not provide a value, it means its value is true */ 137 | if (elem->arg == NULL) 138 | data->sort_keys = true; 139 | else if (!parse_bool(strVal(elem->arg), &data->sort_keys)) 140 | ereport(ERROR, 141 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 142 | errmsg("could not parse value \"%s\" for parameter \"%s\"", 143 | strVal(elem->arg), elem->defname))); 144 | } 145 | else 146 | { 147 | ereport(ERROR, 148 | (errcode(ERRCODE_INVALID_PARAMETER_VALUE), 149 | errmsg("option \"%s\" = \"%s\" is unknown", 150 | elem->defname, 151 | elem->arg ? strVal(elem->arg) : "(null)"))); 152 | } 153 | } 154 | } 155 | 156 | /* cleanup this plugin's resources */ 157 | static void 158 | decoder_json_shutdown(LogicalDecodingContext *ctx) 159 | { 160 | DecoderRawData *data = ctx->output_plugin_private; 161 | 162 | /* cleanup our own resources via memory context reset */ 163 | MemoryContextDelete(data->context); 164 | } 165 | 166 | /* BEGIN callback */ 167 | static void 168 | decoder_json_begin_txn(LogicalDecodingContext *ctx, 169 | ReorderBufferTXN *txn) 170 | { 171 | DecoderRawData *data = ctx->output_plugin_private; 172 | 173 | /* Write to the plugin only if there is */ 174 | if (data->include_transaction) 175 | { 176 | OutputPluginPrepareWrite(ctx, true); 177 | appendStringInfoString(ctx->out, "begin"); 178 | OutputPluginWrite(ctx, true); 179 | } 180 | } 181 | 182 | /* COMMIT callback */ 183 | static void 184 | decoder_json_commit_txn(LogicalDecodingContext *ctx, 185 | ReorderBufferTXN *txn, 186 | XLogRecPtr commit_lsn) 187 | { 188 | DecoderRawData *data = ctx->output_plugin_private; 189 | 190 | /* Write to the plugin only if there is */ 191 | if (data->include_transaction) 192 | { 193 | OutputPluginPrepareWrite(ctx, true); 194 | appendStringInfoString(ctx->out, "commit"); 195 | OutputPluginWrite(ctx, true); 196 | } 197 | } 198 | 199 | /* 200 | * Get a relation name. 201 | */ 202 | static char 203 | *get_relname(Relation rel) 204 | { 205 | Form_pg_class class_form = RelationGetForm(rel); 206 | return quote_qualified_identifier( 207 | get_namespace_name( 208 | get_rel_namespace(RelationGetRelid(rel))), 209 | NameStr(class_form->relname)); 210 | } 211 | 212 | static json_t *get_json_value(Datum, Oid, bool); 213 | 214 | static json_t 215 | *get_json_array(Datum array, Oid elmtype, int elmlen, bool elmbyval) { 216 | Datum *elems; 217 | int nelems, i; 218 | ArrayType *arr = DatumGetArrayTypeP(array); 219 | json_t *result = json_array(); 220 | 221 | if (ARR_NDIM(arr) != 1 || ARR_HASNULL(arr) || ARR_ELEMTYPE(arr) != elmtype) { 222 | elog(ERROR, "expected 1-D array"); 223 | return NULL; 224 | } 225 | 226 | deconstruct_array(arr, elmtype, elmlen, elmbyval, 'i', &elems, NULL, &nelems); 227 | for (i = 0; i < nelems; ++i) { 228 | json_array_append_new(result, get_json_value(elems[i], elmtype, false)); 229 | } 230 | 231 | pfree(elems); 232 | return result; 233 | } 234 | 235 | /* 236 | * Get json value for datum. 237 | */ 238 | static json_t 239 | *get_json_value(Datum origval, 240 | Oid typid, 241 | bool isnull) 242 | { 243 | Oid typoutput; 244 | bool typisvarlena; 245 | Datum val; 246 | 247 | /* Query output function */ 248 | getTypeOutputInfo(typid, &typoutput, &typisvarlena); 249 | 250 | if (isnull) 251 | return json_null(); 252 | else if (typisvarlena && VARATT_IS_EXTERNAL_ONDISK(origval)) 253 | return NULL; //unchanged-toast-datum 254 | else if (!typisvarlena) 255 | val = origval; 256 | else 257 | { 258 | /* Definitely detoasted Datum */ 259 | val = PointerGetDatum(PG_DETOAST_DATUM(origval)); 260 | } 261 | switch (typid) { 262 | case BOOLOID: 263 | return json_boolean(DatumGetBool(val)); 264 | case INT2OID: 265 | return json_integer(DatumGetInt16(val)); 266 | case INT4OID: 267 | return json_integer(DatumGetInt32(val)); 268 | case INT8OID: 269 | case OIDOID: 270 | return json_integer(DatumGetInt64(val)); 271 | case FLOAT4OID: 272 | return json_real(DatumGetFloat4(val)); 273 | case FLOAT8OID: 274 | return json_real(DatumGetFloat8(val)); 275 | case TIMESTAMPOID: 276 | case TIMESTAMPTZOID: 277 | return json_string(timestamptz_to_str(DatumGetTimestampTz(val))); 278 | case NUMERICOID: 279 | /* we send numeric as string for data safety */ 280 | case CHAROID: 281 | case VARCHAROID: 282 | case BPCHAROID: 283 | case TEXTOID: 284 | case JSONOID: 285 | case XMLOID: 286 | case UUIDOID: 287 | return json_string(OidOutputFunctionCall(typoutput, val)); 288 | case 1015: 289 | /* varchar array */ 290 | return get_json_array(val, VARCHAROID, -1, false); 291 | case TEXTARRAYOID: 292 | return get_json_array(val, TEXTOID, -1, false); 293 | case INT2ARRAYOID: 294 | return get_json_array(val, INT2OID, 2, true); 295 | case INT4ARRAYOID: 296 | return get_json_array(val, INT4OID, 4, true); 297 | case FLOAT4ARRAYOID: 298 | return get_json_array(val, FLOAT4OID, 4, true); 299 | case OIDARRAYOID: 300 | return get_json_array(val, OIDOID, 8, true); 301 | default: 302 | elog(ERROR, "Type %s is not supported, oid=%d", format_type_be(typid), typid); 303 | } 304 | return NULL; 305 | } 306 | 307 | /* 308 | * Get attr:value pair 309 | */ 310 | static Pair 311 | *get_pair(TupleDesc tupdesc, 312 | HeapTuple tuple, 313 | int natt) 314 | { 315 | Form_pg_attribute attr; 316 | Datum origval; 317 | bool isnull; 318 | Pair *pair; 319 | char *attname; 320 | json_t *val; 321 | 322 | attr = tupdesc->attrs[natt - 1]; 323 | 324 | /* Skip dropped columns and system columns */ 325 | if (attr->attisdropped || attr->attnum < 0) 326 | return NULL; 327 | 328 | /* Get attribute name */ 329 | attname = NameStr(attr->attname); 330 | 331 | /* Get Datum from tuple */ 332 | origval = fastgetattr(tuple, natt, tupdesc, &isnull); 333 | 334 | val = get_json_value(origval, attr->atttypid, isnull); 335 | //elog(LOG, "We got json val for: %s=%s", attname, json_dumps(val, JSON_ENCODE_ANY)); 336 | if (val == NULL) 337 | return NULL; 338 | 339 | pair = palloc(sizeof(Pair)); 340 | assert(pair); 341 | pair->value = val; 342 | pair->name = attname; 343 | return pair; 344 | } 345 | 346 | static json_t 347 | *get_pairs(TupleDesc tupdesc, 348 | HeapTuple tuple) 349 | { 350 | int natt; 351 | json_t *pairs = json_object(); 352 | 353 | for (natt = 0; natt < tupdesc->natts; natt++) { 354 | Pair *pair = get_pair(tupdesc, tuple, natt + 1); 355 | if (pair == NULL) 356 | continue; 357 | 358 | json_object_set_new(pairs, pair->name, pair->value); 359 | pfree(pair); 360 | } 361 | return pairs; 362 | } 363 | 364 | /* 365 | * Generate a WHERE clause for UPDATE or DELETE. 366 | */ 367 | static json_t 368 | *get_where_clause(Relation relation, 369 | HeapTuple oldtuple, 370 | HeapTuple newtuple) 371 | { 372 | TupleDesc tupdesc = RelationGetDescr(relation); 373 | int natt; 374 | json_t *allClauses = json_object(); 375 | 376 | Assert(relation->rd_rel->relreplident == REPLICA_IDENTITY_DEFAULT || 377 | relation->rd_rel->relreplident == REPLICA_IDENTITY_FULL || 378 | relation->rd_rel->relreplident == REPLICA_IDENTITY_INDEX); 379 | 380 | RelationGetIndexList(relation); 381 | /* Generate WHERE clause using new values of REPLICA IDENTITY */ 382 | if (OidIsValid(relation->rd_replidindex)) 383 | { 384 | Relation indexRel; 385 | int key; 386 | 387 | /* Use all the values associated with the index */ 388 | indexRel = index_open(relation->rd_replidindex, ShareLock); 389 | for (key = 0; key < indexRel->rd_index->indnatts; key++) 390 | { 391 | int relattr = indexRel->rd_index->indkey.values[key]; 392 | 393 | /* 394 | * For a relation having REPLICA IDENTITY set at DEFAULT 395 | * or INDEX, if one of the columns used for tuple selectivity 396 | * is changed, the old tuple data is not NULL and need to 397 | * be used for tuple selectivity. If no such columns are 398 | * updated, old tuple data is NULL. 399 | */ 400 | Pair *pair = get_pair(tupdesc, oldtuple ? oldtuple : newtuple, relattr); 401 | if (pair == NULL) 402 | continue; 403 | json_object_set_new(allClauses, pair->name, pair->value); 404 | pfree(pair); 405 | } 406 | index_close(indexRel, NoLock); 407 | return allClauses; 408 | } 409 | 410 | /* We need absolutely some values for tuple selectivity now */ 411 | Assert(oldtuple != NULL && 412 | relation->rd_rel->relreplident == REPLICA_IDENTITY_FULL); 413 | 414 | /* 415 | * Fallback to default case, use of old values and print WHERE clause 416 | * using all the columns. This is actually the code path for FULL. 417 | */ 418 | for (natt = 0; natt < tupdesc->natts; natt++) { 419 | Pair *pair = get_pair(tupdesc, oldtuple, natt + 1); 420 | if (pair == NULL) 421 | continue; 422 | 423 | json_object_set_new(allClauses, pair->name, pair->value); 424 | pfree(pair); 425 | } 426 | return allClauses; 427 | } 428 | 429 | static void 430 | write_struct(StringInfo s, 431 | int actionId, 432 | Relation relation, 433 | json_t *clause, 434 | json_t *data, 435 | bool sort_keys) 436 | { 437 | char *relname = get_relname(relation); 438 | char *result; 439 | size_t flags = JSON_COMPACT; 440 | json_t *action = json_object(); 441 | 442 | if (sort_keys) flags |= JSON_SORT_KEYS; 443 | 444 | /* Generate struct */ 445 | json_object_set_new(action, "a", json_integer(actionId)); 446 | json_object_set_new(action, "r", json_string(relname)); 447 | if (clause != NULL) 448 | json_object_set(action, "c", clause); 449 | if (data != NULL) 450 | json_object_set(action, "d", data); 451 | 452 | result = json_dumps(action, flags); 453 | json_decref(action); 454 | 455 | elog(LOG, "Struct:%s", result); 456 | 457 | appendStringInfoString(s, result); 458 | pfree(result); 459 | } 460 | 461 | /* 462 | * Decode an INSERT entry 463 | */ 464 | static void 465 | decoder_json_insert(StringInfo s, 466 | Relation relation, 467 | HeapTuple tuple, 468 | bool sort_keys) 469 | { 470 | TupleDesc tupdesc = RelationGetDescr(relation); 471 | json_t *data = get_pairs(tupdesc, tuple); 472 | write_struct(s, 0, relation, NULL, data, sort_keys); 473 | json_decref(data); 474 | } 475 | 476 | /* 477 | * Decode a DELETE entry 478 | * Append to output json structure like 479 | * {"a": 2, "r": "public.table_name", "c": "some_clause"} 480 | */ 481 | static void 482 | decoder_json_delete(StringInfo s, 483 | Relation relation, 484 | HeapTuple tuple, 485 | bool sort_keys) 486 | { 487 | /* 488 | * Here the same tuple is used as old and new values, selectivity will 489 | * be properly reduced by relation uses DEFAULT or INDEX as REPLICA 490 | * IDENTITY. 491 | */ 492 | json_t *clause = get_where_clause(relation, tuple, tuple); 493 | write_struct(s, 2, relation, clause, NULL, sort_keys); 494 | json_decref(clause); 495 | } 496 | 497 | 498 | /* 499 | * Decode an UPDATE entry 500 | */ 501 | static void 502 | decoder_json_update(StringInfo s, 503 | Relation relation, 504 | HeapTuple oldtuple, 505 | HeapTuple newtuple, 506 | bool sort_keys) 507 | { 508 | json_t *clause; 509 | json_t *data; 510 | TupleDesc tupdesc = RelationGetDescr(relation); 511 | 512 | /* If there are no new values, simply leave as there is nothing to do */ 513 | if (newtuple == NULL) 514 | return; 515 | 516 | clause = get_where_clause(relation, oldtuple, newtuple); 517 | data = get_pairs(tupdesc, newtuple); 518 | write_struct(s, 1, relation, clause, data, sort_keys); 519 | json_decref(clause); 520 | json_decref(data); 521 | } 522 | 523 | /* 524 | * Callback for individual changed tuples 525 | */ 526 | static void 527 | decoder_json_change(LogicalDecodingContext *ctx, 528 | ReorderBufferTXN *txn, 529 | Relation relation, 530 | ReorderBufferChange *change) 531 | { 532 | DecoderRawData *data; 533 | MemoryContext old; 534 | char replident = relation->rd_rel->relreplident; 535 | bool is_rel_non_selective; 536 | 537 | data = ctx->output_plugin_private; 538 | 539 | /* Avoid leaking memory by using and resetting our own context */ 540 | old = MemoryContextSwitchTo(data->context); 541 | 542 | /* 543 | * Determine if relation is selective enough for WHERE clause generation 544 | * in UPDATE and DELETE cases. A non-selective relation uses REPLICA 545 | * IDENTITY set as NOTHING, or DEFAULT without an available replica 546 | * identity index. 547 | */ 548 | RelationGetIndexList(relation); 549 | is_rel_non_selective = (replident == REPLICA_IDENTITY_NOTHING || 550 | (replident == REPLICA_IDENTITY_DEFAULT && 551 | !OidIsValid(relation->rd_replidindex))); 552 | 553 | /* Decode entry depending on its type */ 554 | switch (change->action) 555 | { 556 | case REORDER_BUFFER_CHANGE_INSERT: 557 | if (change->data.tp.newtuple != NULL) 558 | { 559 | OutputPluginPrepareWrite(ctx, true); 560 | decoder_json_insert(ctx->out, 561 | relation, 562 | &change->data.tp.newtuple->tuple, 563 | data->sort_keys); 564 | OutputPluginWrite(ctx, true); 565 | } 566 | break; 567 | case REORDER_BUFFER_CHANGE_UPDATE: 568 | if (!is_rel_non_selective) 569 | { 570 | HeapTuple oldtuple = change->data.tp.oldtuple != NULL ? 571 | &change->data.tp.oldtuple->tuple : NULL; 572 | HeapTuple newtuple = change->data.tp.newtuple != NULL ? 573 | &change->data.tp.newtuple->tuple : NULL; 574 | 575 | OutputPluginPrepareWrite(ctx, true); 576 | decoder_json_update(ctx->out, 577 | relation, 578 | oldtuple, 579 | newtuple, 580 | data->sort_keys); 581 | OutputPluginWrite(ctx, true); 582 | } 583 | break; 584 | case REORDER_BUFFER_CHANGE_DELETE: 585 | if (!is_rel_non_selective) 586 | { 587 | OutputPluginPrepareWrite(ctx, true); 588 | decoder_json_delete(ctx->out, 589 | relation, 590 | &change->data.tp.oldtuple->tuple, 591 | data->sort_keys); 592 | OutputPluginWrite(ctx, true); 593 | } 594 | break; 595 | default: 596 | /* Should not come here */ 597 | Assert(0); 598 | break; 599 | } 600 | 601 | MemoryContextSwitchTo(old); 602 | MemoryContextReset(data->context); 603 | } 604 | --------------------------------------------------------------------------------