From f689ce4fc7e2cfcf73d92000d8b3ac751a51ce80 Mon Sep 17 00:00:00 2001 From: Konstantin Knizhnik Date: Wed, 19 Apr 2017 16:44:27 +0300 Subject: [PATCH 1/2] Add create_shards function --- Makefile | 2 +- hash.sql | 7 ++++++- shard.sql | 56 +++++++++++++++++++++++++++++++++++++++++++++++++++++++ 3 files changed, 63 insertions(+), 2 deletions(-) create mode 100644 shard.sql diff --git a/Makefile b/Makefile index b908802b..2a958e58 100644 --- a/Makefile +++ b/Makefile @@ -52,7 +52,7 @@ include $(top_builddir)/src/Makefile.global include $(top_srcdir)/contrib/contrib-global.mk endif -$(EXTENSION)--$(EXTVERSION).sql: init.sql hash.sql range.sql +$(EXTENSION)--$(EXTVERSION).sql: init.sql hash.sql range.sql shard.sql cat $^ > $@ ISOLATIONCHECKS=insert_nodes for_update rollback_on_create_partitions diff --git a/hash.sql b/hash.sql index 59a2ae64..207e4809 100644 --- a/hash.sql +++ b/hash.sql @@ -80,6 +80,7 @@ DECLARE old_constr_def TEXT; /* definition of old_partition's constraint */ rel_persistence CHAR; p_init_callback REGPROCEDURE; + derived BOOLEAN; BEGIN PERFORM @extschema@.validate_relname(old_partition); @@ -136,7 +137,11 @@ BEGIN old_constr_name); /* Attach the new one */ - EXECUTE format('ALTER TABLE %s INHERIT %s', new_partition, parent_relid); + SELECT EXISTS(SELECT 1 FROM pg_catalog.pg_inherits WHERE inhrelid = new_partition and inhparent = parent_relid) + INTO derived; + IF NOT derived THEN + EXECUTE format('ALTER TABLE %s INHERIT %s', new_partition, parent_relid); + END IF; EXECUTE format('ALTER TABLE %s ADD CONSTRAINT %s %s', new_partition, @extschema@.build_check_constraint_name(new_partition::REGCLASS, diff --git a/shard.sql b/shard.sql new file mode 100644 index 00000000..13f599a1 --- /dev/null +++ b/shard.sql @@ -0,0 +1,56 @@ +/* ------------------------------------------------------------------------ + * + * shard.sql + * Creates shards using postgtres_fdw and pg_tsdtm + * + * Copyright (c) 2015-2016, Postgres Professional + * + * ------------------------------------------------------------------------ + */ + +create extension if not exists postgres_fdw; + +/* + * Create partitions and foreign data table for the given parent table. + * It is necessary to create postgres_fdw foreign data servers for all shard nodes with some unique type. + * All foreign data servers with this types will be treated as sharding nodes. + * This function requires that the same database schema is replicated to all shards (i.e. replicated table defintion is present at all shards) + * + * @param partitioned_table reference to the existed parititioned table + * @param partition_key attribute for hash partitioning + * @param partitions_count number of partitions + * @param server_type some unieue name identifying servers for used for sharding of this table + * @return nubmer of sharding nodes + */ +create or replace function @extschema@.create_shards(partitioned_table regclass, partition_key text, partitions_count integer, server_type text) +returns integer as +$$ +declare + shards text[]; + table_name text := partitioned_table::text; + table_namespace text; + n_shards integer; + create_fdw_table text := 'create foreign table "%1$s_fdw_%2$s"() inherits (%1$I) server %3$s options(table_name ''%1$s_fdw_%2$s'')'; + local_partition regclass; + remote_partition regclass; + nsname text; + i integer; +begin + PERFORM @extschema@.create_hash_partitions(partitioned_table, partition_key, partitions_count, false); + + shards = array(select srvname FROM pg_catalog.pg_foreign_server WHERE srvtype = server_type); + n_shards := array_length(shards, 1); + + for i in 1..partitions_count loop + execute format(create_fdw_table, table_name, i, shards[1 + ((i-1) % n_shards)]); + local_partition := format('%s_%s', table_name, i-1)::regclass; + remote_partition := format('%s_fdw_%s', table_name, i)::regclass; + select nspname from pg_catalog.pg_namespace ns,pg_class c where c.oid = remote_partition and c.relnamespace=ns.oid into table_namespace; + perform postgres_fdw_exec(remote_partition::oid, format('create table %1$s.%2$s(like %1$s.%3$I INCLUDING ALL)', + table_namespace, remote_partition, table_name)::cstring); + perform @extschema@.replace_hash_partition(local_partition,remote_partition); + end loop; + + return n_shards; +end +$$ LANGUAGE plpgsql; From 2bd2e3e5dbd2f4f6a37a08b4f419435ecf2e79c5 Mon Sep 17 00:00:00 2001 From: Konstantin Knizhnik Date: Wed, 19 Apr 2017 18:13:38 +0300 Subject: [PATCH 2/2] Remove create extension from shard.sql --- shard.sql | 2 -- 1 file changed, 2 deletions(-) diff --git a/shard.sql b/shard.sql index 13f599a1..532a9e51 100644 --- a/shard.sql +++ b/shard.sql @@ -8,8 +8,6 @@ * ------------------------------------------------------------------------ */ -create extension if not exists postgres_fdw; - /* * Create partitions and foreign data table for the given parent table. * It is necessary to create postgres_fdw foreign data servers for all shard nodes with some unique type.