├── README.md ├── sql └── Makefile ├── pg_shard.control ├── test ├── Makefile ├── sql │ ├── 10-utilities.sql │ ├── 00-init.sql │ ├── 01-connection.sql │ ├── 06-prune_shard_list.sql │ ├── 12-create_insert_proxy.sql │ ├── 04-generate_ddl_commands.sql │ ├── 07-repair_shards.sql │ ├── 03-extend_ddl_commands.sql │ ├── 11-citus_metadata_sync.sql │ ├── 13-data_types.sql │ ├── 05-create_shards.sql │ ├── 08-modifications.sql │ ├── 02-distribution_metadata.sql │ └── 09-queries.sql ├── expected │ ├── 00-init.out │ ├── 10-utilities.out │ ├── 12-create_insert_proxy.out │ ├── 01-connection.out │ ├── 06-prune_shard_list.out │ ├── 07-repair_shards.out │ ├── 13-data_types.out │ ├── 11-citus_metadata_sync.out │ ├── 04-generate_ddl_commands.out │ ├── 04-generate_ddl_commands_1.out │ └── 03-extend_ddl_commands.out ├── launcher.sh ├── src │ ├── test_helper_functions.c │ ├── extend_ddl_commands.c │ ├── create_shards.c │ ├── generate_ddl_commands.c │ ├── connection.c │ ├── fake_fdw.c │ └── prune_shard_list.c └── include │ └── test_helper_functions.h ├── iwyu.imp ├── include ├── citus_metadata_sync.h ├── ruleutils.h ├── repair_shards.h ├── ddl_commands.h ├── prune_shard_list.h ├── create_shards.h ├── connection.h ├── pg_shard.h └── distribution_metadata.h ├── .gitignore ├── .travis.yml ├── META.json ├── CHANGELOG.md ├── Makefile ├── CONTRIBUTING.md ├── src └── citus_metadata_sync.c ├── bin └── copy_to_distributed_table ├── updates ├── pg_shard--1.0--1.1.sql └── pg_shard--1.1--1.2.sql └── LICENSE /README.md: -------------------------------------------------------------------------------- 1 | doc/README.md -------------------------------------------------------------------------------- /sql/Makefile: -------------------------------------------------------------------------------- 1 | DATA_built += sql/$(EXTENSION)--$(EXTVERSION).sql 2 | 3 | # define build process for latest install file 4 | sql/$(EXTENSION)--$(EXTVERSION).sql: sql/$(EXTENSION).sql 5 | cp $< $@ 6 | -------------------------------------------------------------------------------- /pg_shard.control: -------------------------------------------------------------------------------- 1 | # pg_shard extension 2 | comment = 'extension for sharding across remote PostgreSQL servers' 3 | default_version = '1.2' 4 | module_pathname = '$libdir/pg_shard' 5 | relocatable = true 6 | -------------------------------------------------------------------------------- /test/Makefile: -------------------------------------------------------------------------------- 1 | # add objects referenced by the test function headers 2 | PG_CPPFLAGS += -Itest/include 3 | OBJS += $(patsubst %.c,%.o,$(wildcard test/src/*.c)) 4 | EXTRA_CLEAN += $(addprefix test/src/,*.gcno *.gcda) 5 | -------------------------------------------------------------------------------- /iwyu.imp: -------------------------------------------------------------------------------- 1 | [ 2 | { include: [ "", private, "", public ] }, 3 | { include: [ "", private, "", public ] }, 4 | { include: [ "", private, "", public ] }, 5 | { include: [ "\"pg_config.h\"", private, "\"c.h\"", public ] }, 6 | { include: [ "\"pg_config_manual.h\"", private, "\"c.h\"", public ] }, 7 | { include: [ "\"postgres_ext.h\"", private, "\"c.h\"", public ] } 8 | ] 9 | -------------------------------------------------------------------------------- /test/sql/10-utilities.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test utility statement functionality 3 | -- =================================================================== 4 | 5 | CREATE TABLE sharded_table ( name text, id bigint ); 6 | SELECT master_create_distributed_table('sharded_table', 'id'); 7 | 8 | -- COPY is not supported with distributed tables 9 | COPY sharded_table TO STDOUT; 10 | COPY (SELECT COUNT(*) FROM sharded_table) TO STDOUT; 11 | COPY sharded_table FROM STDIN; 12 | 13 | -- cursors may not involve distributed tables 14 | DECLARE all_sharded_rows CURSOR FOR SELECT * FROM sharded_table; 15 | 16 | -- EXPLAIN support isn't implemented 17 | EXPLAIN SELECT * FROM sharded_table; 18 | 19 | -- PREPARE support isn't implemented 20 | PREPARE sharded_query (bigint) AS SELECT * FROM sharded_table WHERE id = $1; 21 | -------------------------------------------------------------------------------- /include/citus_metadata_sync.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/citus_metadata_sync.h 4 | * 5 | * Declarations for public functions and types related to syncing metadata with 6 | * CitusDB. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_CITUS_METADATA_SYNC_H 14 | #define PG_SHARD_CITUS_METADATA_SYNC_H 15 | 16 | #include "postgres.h" 17 | #include "fmgr.h" 18 | 19 | 20 | /* function declarations for syncing metadata with CitusDB */ 21 | extern Datum partition_column_to_node_string(PG_FUNCTION_ARGS); 22 | extern Datum column_name_to_column(PG_FUNCTION_ARGS); 23 | extern Datum column_to_column_name(PG_FUNCTION_ARGS); 24 | 25 | 26 | #endif /* PG_SHARD_CITUS_METADATA_SYNC_H */ 27 | -------------------------------------------------------------------------------- /.gitignore: -------------------------------------------------------------------------------- 1 | # ===== 2 | # = C = 3 | # ===== 4 | 5 | # Object files 6 | *.o 7 | *.ko 8 | *.obj 9 | *.elf 10 | 11 | # Precompiled Headers 12 | *.gch 13 | *.pch 14 | 15 | # Libraries 16 | *.lib 17 | *.a 18 | *.la 19 | *.lo 20 | 21 | # Shared objects (inc. Windows DLLs) 22 | *.dll 23 | *.so 24 | *.so.* 25 | *.dylib 26 | 27 | # Executables 28 | *.exe 29 | *.out 30 | *.app 31 | *.i*86 32 | *.x86_64 33 | *.hex 34 | 35 | # ======== 36 | # = Gcov = 37 | # ======== 38 | 39 | # gcc coverage testing tool files 40 | 41 | *.gcno 42 | *.gcda 43 | *.gcov 44 | 45 | # ==================== 46 | # = Project-Specific = 47 | # ==================== 48 | 49 | # regression test detritus 50 | /log/ 51 | /regression.diffs 52 | /regression.out 53 | /results/ 54 | /tmp_check* 55 | 56 | # keep expected output files 57 | !/test/expected/*.out 58 | 59 | # ignore latest install file 60 | sql/*--*.sql 61 | -------------------------------------------------------------------------------- /.travis.yml: -------------------------------------------------------------------------------- 1 | language: c 2 | cache: apt 3 | env: 4 | global: 5 | - enable_coverage=yes 6 | - PG_PRELOAD=pg_shard 7 | matrix: 8 | - PGVERSION=9.3 9 | - PGVERSION=9.4 10 | - PGVERSION=9.5 11 | before_install: 12 | - git clone -b v0.1.0 --depth 1 https://github.com/citusdata/tools.git 13 | - tools/travis/setup_apt.sh 14 | - tools/travis/nuke_pg.sh 15 | install: 16 | - sudo pip install cpp-coveralls 17 | - tools/travis/install_pg.sh 18 | - tools/travis/install_citus.sh 19 | before_script: tools/travis/config_and_start_cluster.sh 20 | script: tools/travis/pg_travis_test.sh 21 | after_success: 22 | - sudo chmod 666 *.gcda 23 | - coveralls --exclude test/include --exclude test/src --exclude src/ruleutils_93.c --exclude src/ruleutils_94.c --exclude src/ruleutils_95.c --gcov-options '\-lp' 24 | cache: 25 | directories: 26 | - $HOME/.cache/pip 27 | - $HOME/.cache/citusdb_pkgs 28 | -------------------------------------------------------------------------------- /include/ruleutils.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/ruleutils.h 4 | * 5 | * Declarations for public functions and types to produce an SQL string 6 | * targeting a particular shard based on an initial query and shard ID. 7 | * Depending upon the version of PostgreSQL in use, implementations of 8 | * this file's functions are found in ruleutils_93.c or ruleutils_94.c. 9 | * 10 | * Copyright (c) 2014-2015, Citus Data, Inc. 11 | * 12 | *------------------------------------------------------------------------- 13 | */ 14 | 15 | #ifndef PG_SHARD_RULEUTILS_H 16 | #define PG_SHARD_RULEUTILS_H 17 | 18 | #include "c.h" 19 | 20 | #include "lib/stringinfo.h" 21 | #include "nodes/parsenodes.h" 22 | 23 | 24 | /* function declarations for extending and deparsing a query */ 25 | extern void deparse_shard_query(Query *query, int64 shardid, StringInfo buffer); 26 | 27 | 28 | #endif /* PG_SHARD_RULEUTILS_H */ 29 | -------------------------------------------------------------------------------- /test/expected/00-init.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create extension 3 | -- =================================================================== 4 | CREATE EXTENSION pg_shard; 5 | -- ensure the test DB defaults to pg_shard select logic 6 | ALTER DATABASE :DBNAME SET pg_shard.use_citusdb_select_logic TO false; 7 | -- create fake fdw for use in tests 8 | CREATE FUNCTION fake_fdw_handler() 9 | RETURNS fdw_handler 10 | AS 'pg_shard' 11 | LANGUAGE C STRICT; 12 | CREATE FOREIGN DATA WRAPPER fake_fdw HANDLER fake_fdw_handler; 13 | CREATE SERVER fake_fdw_server FOREIGN DATA WRAPPER fake_fdw; 14 | -- Set pg_shard sequence to start at same number as that used by CitusDB. 15 | -- This makes testing easier, since shard IDs will match. 16 | DO $$ 17 | BEGIN 18 | BEGIN 19 | PERFORM setval('pgs_distribution_metadata.shard_id_sequence', 20 | 102008, false); 21 | EXCEPTION 22 | WHEN undefined_table THEN 23 | -- do nothing 24 | END; 25 | END; 26 | $$; 27 | -------------------------------------------------------------------------------- /test/sql/00-init.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create extension 3 | -- =================================================================== 4 | 5 | CREATE EXTENSION pg_shard; 6 | 7 | -- ensure the test DB defaults to pg_shard select logic 8 | ALTER DATABASE :DBNAME SET pg_shard.use_citusdb_select_logic TO false; 9 | 10 | -- create fake fdw for use in tests 11 | CREATE FUNCTION fake_fdw_handler() 12 | RETURNS fdw_handler 13 | AS 'pg_shard' 14 | LANGUAGE C STRICT; 15 | 16 | CREATE FOREIGN DATA WRAPPER fake_fdw HANDLER fake_fdw_handler; 17 | CREATE SERVER fake_fdw_server FOREIGN DATA WRAPPER fake_fdw; 18 | 19 | -- Set pg_shard sequence to start at same number as that used by CitusDB. 20 | -- This makes testing easier, since shard IDs will match. 21 | DO $$ 22 | BEGIN 23 | BEGIN 24 | PERFORM setval('pgs_distribution_metadata.shard_id_sequence', 25 | 102008, false); 26 | EXCEPTION 27 | WHEN undefined_table THEN 28 | -- do nothing 29 | END; 30 | END; 31 | $$; 32 | -------------------------------------------------------------------------------- /test/launcher.sh: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env bash 2 | 3 | # make bash behave 4 | set -euo pipefail 5 | IFS=$'\n\t' 6 | 7 | PGPORT=${PGPORT:-5432} 8 | PSQL=$1 9 | DATADIR=`$PSQL -p$PGPORT -AtXc 'SHOW data_directory' postgres` 10 | PG_WORKER_LIST_CONF=$DATADIR/pg_worker_list.conf 11 | 12 | function restore_worker_list { 13 | if [ -f $PG_WORKER_LIST_CONF.bak ] 14 | then 15 | mv -f $PG_WORKER_LIST_CONF.bak $PG_WORKER_LIST_CONF 16 | fi 17 | 18 | exit 19 | } 20 | 21 | trap restore_worker_list HUP INT TERM 22 | 23 | # ensure configuration file exists 24 | if [ ! -f $PG_WORKER_LIST_CONF ] 25 | then 26 | echo > $PG_WORKER_LIST_CONF 27 | fi 28 | 29 | if [ -f $PG_WORKER_LIST_CONF.bak ] 30 | then 31 | >&2 echo 'worker list backup file already present. Please inspect and remove' 32 | exit 70 33 | fi 34 | 35 | sed -i.bak -e's/^/#/g' -e"\$a\\ 36 | localhost # added by installcheck\\ 37 | adeadhost 5432 # added by installcheck" $PG_WORKER_LIST_CONF 38 | 39 | shift 40 | $PSQL -v worker_port=$PGPORT $* 41 | 42 | restore_worker_list 43 | -------------------------------------------------------------------------------- /include/repair_shards.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/repair_shards.h 4 | * 5 | * Declarations for public functions and types to implement shard repair 6 | * functionality. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_REPAIR_SHARDS_H 14 | #define PG_SHARD_REPAIR_SHARDS_H 15 | 16 | #include "postgres.h" 17 | #include "fmgr.h" 18 | 19 | 20 | /* templates for SQL commands used during shard placement repair */ 21 | #define DROP_REGULAR_TABLE_COMMAND "DROP TABLE IF EXISTS %s" 22 | #define DROP_FOREIGN_TABLE_COMMAND "DROP FOREIGN TABLE IF EXISTS %s" 23 | #define COPY_SHARD_PLACEMENT_COMMAND "SELECT worker_copy_shard_placement(%s, %s, %d)" 24 | #define SELECT_ALL_QUERY "SELECT * FROM %s" 25 | 26 | 27 | /* function declarations for shard repair functionality */ 28 | extern Datum master_copy_shard_placement(PG_FUNCTION_ARGS); 29 | extern Datum worker_copy_shard_placement(PG_FUNCTION_ARGS); 30 | 31 | 32 | #endif /* PG_SHARD_REPAIR_SHARDS_H */ 33 | -------------------------------------------------------------------------------- /test/src/test_helper_functions.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/test_helper_functions.c 4 | * 5 | * This file contains helper functions used in many pg_shard tests. 6 | * 7 | * Copyright (c) 2014-2015, Citus Data, Inc. 8 | * 9 | *------------------------------------------------------------------------- 10 | */ 11 | 12 | #include "postgres.h" 13 | #include "c.h" 14 | 15 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 16 | 17 | #include 18 | 19 | #include "utils/array.h" 20 | #include "utils/lsyscache.h" 21 | 22 | 23 | /* 24 | * DatumArrayToArrayType converts the provided Datum array (of the specified 25 | * length and type) into an ArrayType suitable for returning from a UDF. 26 | */ 27 | ArrayType * 28 | DatumArrayToArrayType(Datum *datumArray, int datumCount, Oid datumTypeId) 29 | { 30 | ArrayType *arrayObject = NULL; 31 | int16 typeLength = 0; 32 | bool typeByValue = false; 33 | char typeAlignment = 0; 34 | 35 | get_typlenbyvalalign(datumTypeId, &typeLength, &typeByValue, &typeAlignment); 36 | arrayObject = construct_array(datumArray, datumCount, datumTypeId, 37 | typeLength, typeByValue, typeAlignment); 38 | 39 | return arrayObject; 40 | } 41 | -------------------------------------------------------------------------------- /include/ddl_commands.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/ddl_commands.h 4 | * 5 | * Declarations for public functions related to generating and extending DDL 6 | * commands. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_DDL_COMMANDS_H 14 | #define PG_SHARD_DDL_COMMANDS_H 15 | 16 | #include "c.h" 17 | #include "fmgr.h" 18 | #include "postgres_ext.h" 19 | 20 | #include "lib/stringinfo.h" 21 | #include "nodes/pg_list.h" 22 | 23 | 24 | /* character for separating table name from shard ID in generated table names */ 25 | #define SHARD_NAME_SEPARATOR '_' 26 | 27 | 28 | /* function declarations to extend DDL commands with shard IDs */ 29 | extern List * TableDDLCommandList(Oid relationId); 30 | extern void AppendOptionListToString(StringInfo stringBuffer, List *optionList); 31 | extern List * ExtendedDDLCommandList(Oid masterRelationId, int64 shardId, 32 | List *sqlCommandList); 33 | extern void AppendShardIdToName(char **name, int64 shardId); 34 | extern bool ExecuteRemoteCommandList(char *nodeName, uint32 nodePort, 35 | List *sqlCommandList); 36 | 37 | 38 | #endif /* PG_SHARD_DDL_COMMANDS_H */ 39 | -------------------------------------------------------------------------------- /test/expected/10-utilities.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test utility statement functionality 3 | -- =================================================================== 4 | CREATE TABLE sharded_table ( name text, id bigint ); 5 | SELECT master_create_distributed_table('sharded_table', 'id'); 6 | master_create_distributed_table 7 | --------------------------------- 8 | 9 | (1 row) 10 | 11 | -- COPY is not supported with distributed tables 12 | COPY sharded_table TO STDOUT; 13 | ERROR: COPY commands on distributed tables are unsupported 14 | COPY (SELECT COUNT(*) FROM sharded_table) TO STDOUT; 15 | ERROR: COPY commands involving distributed tables are unsupported 16 | COPY sharded_table FROM STDIN; 17 | ERROR: COPY commands on distributed tables are unsupported 18 | -- cursors may not involve distributed tables 19 | DECLARE all_sharded_rows CURSOR FOR SELECT * FROM sharded_table; 20 | ERROR: cannot perform distributed planning for the given query 21 | DETAIL: Utility commands are not supported in distributed queries. 22 | -- EXPLAIN support isn't implemented 23 | EXPLAIN SELECT * FROM sharded_table; 24 | ERROR: EXPLAIN commands on distributed tables are unsupported 25 | -- PREPARE support isn't implemented 26 | PREPARE sharded_query (bigint) AS SELECT * FROM sharded_table WHERE id = $1; 27 | ERROR: PREPARE commands on distributed tables are unsupported 28 | -------------------------------------------------------------------------------- /include/prune_shard_list.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/prune_shard_list.h 4 | * 5 | * Declarations for public functions and types related to shard pruning 6 | * functionality. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_PRUNE_SHARD_LIST_H 14 | #define PG_SHARD_PRUNE_SHARD_LIST_H 15 | 16 | #include "c.h" 17 | 18 | #include "access/attnum.h" 19 | #include "nodes/pg_list.h" 20 | #include "nodes/primnodes.h" 21 | 22 | 23 | /* 24 | * Column ID used to signify that a partition column value has been replaced by 25 | * its hashed value. 26 | */ 27 | #define RESERVED_HASHED_COLUMN_ID MaxAttrNumber 28 | 29 | 30 | /* OperatorIdCacheEntry contains information for each element in OperatorIdCache */ 31 | typedef struct OperatorIdCacheEntry 32 | { 33 | /* cache key consists of typeId, accessMethodId and strategyNumber */ 34 | Oid typeId; 35 | Oid accessMethodId; 36 | int16 strategyNumber; 37 | Oid operatorId; 38 | } OperatorIdCacheEntry; 39 | 40 | 41 | /* function declarations for shard pruning */ 42 | extern List * PruneShardList(Oid relationId, List *whereClauseList, 43 | List *shardIntervalList); 44 | extern OpExpr * MakeOpExpression(Var *variable, int16 strategyNumber); 45 | extern Oid GetOperatorByType(Oid typeId, Oid accessMethodId, int16 strategyNumber); 46 | 47 | 48 | #endif /* PG_SHARD_PRUNE_SHARD_LIST_H */ 49 | -------------------------------------------------------------------------------- /include/create_shards.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/create_shards.h 4 | * 5 | * Declarations for public functions and types related to shard creation 6 | * functionality. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_CREATE_SHARDS_H 14 | #define PG_SHARD_CREATE_SHARDS_H 15 | 16 | #include "postgres.h" 17 | #include "c.h" 18 | #include "fmgr.h" 19 | 20 | #include "nodes/pg_list.h" 21 | 22 | 23 | /* total number of hash tokens (2^32) */ 24 | #define HASH_TOKEN_COUNT INT64CONST(4294967296UL) 25 | 26 | /* name for the file containing worker node and port information */ 27 | #define WORKER_LIST_FILENAME "pg_worker_list.conf" 28 | 29 | /* transaction related commands used in talking to the worker nodes */ 30 | #define BEGIN_COMMAND "BEGIN" 31 | #define COMMIT_COMMAND "COMMIT" 32 | #define ROLLBACK_COMMAND "ROLLBACK" 33 | 34 | 35 | /* in-memory representation of a worker node */ 36 | typedef struct WorkerNode 37 | { 38 | uint32 nodePort; 39 | char *nodeName; 40 | } WorkerNode; 41 | 42 | 43 | /* utility functions declaration shared within this module */ 44 | extern List * SortList(List *pointerList, 45 | int (*ComparisonFunction)(const void *, const void *)); 46 | extern Oid ResolveRelationId(text *relationName); 47 | 48 | /* function declarations for initializing a distributed table */ 49 | extern Datum master_create_distributed_table(PG_FUNCTION_ARGS); 50 | extern Datum master_create_worker_shards(PG_FUNCTION_ARGS); 51 | 52 | 53 | #endif /* PG_SHARD_CREATE_SHARDS_H */ 54 | -------------------------------------------------------------------------------- /META.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "pg_shard", 3 | "abstract": "Easy sharding for PostgreSQL", 4 | "description": "Shards and replicates PostgreSQL tables for horizontal scale and high availability. Seamlessly distributes SQL statements, without requiring any application changes.", 5 | "version": "1.2.3", 6 | "maintainer": "\"Jason Petersen\" ", 7 | "license": "lgpl_3_0", 8 | "prereqs": { 9 | "runtime": { 10 | "requires": { 11 | "PostgreSQL": "9.3.4" 12 | } 13 | } 14 | }, 15 | "provides": { 16 | "pg_shard": { 17 | "abstract": "Easy sharding for PostgreSQL", 18 | "file": "sql/pg_shard--1.2.sql", 19 | "docfile": "README.md", 20 | "version": "1.2.3" 21 | } 22 | }, 23 | "release_status": "stable", 24 | "resources": { 25 | "homepage": "https://citusdata.com/docs/pg-shard", 26 | "bugtracker": { 27 | "web": "https://github.com/citusdata/pg_shard/issues", 28 | "mailto": "support@citusdata.com" 29 | }, 30 | "repository": { 31 | "url": "git://github.com/citusdata/pg_shard.git", 32 | "web": "https://github.com/citusdata/pg_shard", 33 | "type": "git" 34 | } 35 | }, 36 | 37 | "generated_by": "\"Jason Petersen\" ", 38 | 39 | "tags": [ 40 | "sharding", 41 | "replication", 42 | "failover", 43 | "distribution", 44 | "scale", 45 | "cluster" 46 | ], 47 | 48 | "meta-spec": { 49 | "version": "1.0.0", 50 | "url": "http://pgxn.org/meta/spec.txt" 51 | } 52 | } 53 | -------------------------------------------------------------------------------- /include/connection.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/connection.h 4 | * 5 | * Declarations for public functions and types related to connection hash 6 | * functionality. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_CONNECTION_H 14 | #define PG_SHARD_CONNECTION_H 15 | 16 | #include "c.h" 17 | #include "libpq-fe.h" 18 | 19 | 20 | /* maximum duration to wait for connection */ 21 | #define CLIENT_CONNECT_TIMEOUT_SECONDS "5" 22 | 23 | /* maximum (textual) lengths of hostname and port */ 24 | #define MAX_NODE_LENGTH 255 25 | #define MAX_PORT_LENGTH 10 26 | 27 | /* times to attempt connection (or reconnection) */ 28 | #define MAX_CONNECT_ATTEMPTS 2 29 | 30 | /* SQL statement for testing */ 31 | #define TEST_SQL "DO $$ BEGIN RAISE EXCEPTION 'Raised remotely!'; END $$" 32 | 33 | 34 | /* 35 | * NodeConnectionKey acts as the key to index into the (process-local) hash 36 | * keeping track of open connections. Node name and port are sufficient. 37 | */ 38 | typedef struct NodeConnectionKey 39 | { 40 | char nodeName[MAX_NODE_LENGTH + 1]; /* hostname of host to connect to */ 41 | int32 nodePort; /* port of host to connect to */ 42 | } NodeConnectionKey; 43 | 44 | 45 | /* NodeConnectionEntry keeps track of connections themselves. */ 46 | typedef struct NodeConnectionEntry 47 | { 48 | NodeConnectionKey cacheKey; /* hash entry key */ 49 | PGconn *connection; /* connection to remote server, if any */ 50 | } NodeConnectionEntry; 51 | 52 | 53 | /* function declarations for obtaining and using a connection */ 54 | extern PGconn * GetConnection(char *nodeName, int32 nodePort); 55 | extern void PurgeConnection(PGconn *connection); 56 | extern void ReportRemoteError(PGconn *connection, PGresult *result); 57 | 58 | 59 | #endif /* PG_SHARD_CONNECTION_H */ 60 | -------------------------------------------------------------------------------- /test/src/extend_ddl_commands.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/extend_ddl_commands.c 4 | * 5 | * This file contains functions to exercise DDL extension functionality 6 | * within pg_shard. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "ddl_commands.h" 18 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 19 | 20 | #include "nodes/pg_list.h" 21 | #include "utils/builtins.h" 22 | #include "utils/elog.h" 23 | 24 | 25 | /* declarations for dynamic loading */ 26 | PG_FUNCTION_INFO_V1(extend_ddl_command); 27 | PG_FUNCTION_INFO_V1(extend_name); 28 | 29 | 30 | /* 31 | * extend_ddl_command expects a distributed table's OID, a shard identifier, 32 | * and a DDL command. It extends the DDL command using the specified shard 33 | * identifier and returns the result. 34 | */ 35 | Datum 36 | extend_ddl_command(PG_FUNCTION_ARGS) 37 | { 38 | Oid distributedTableId = PG_GETARG_OID(0); 39 | int64 shardId = PG_GETARG_INT64(1); 40 | 41 | /* using text instead of cstring to allow SQL use of || without casting */ 42 | text *ddlCommandText = PG_GETARG_TEXT_P(2); 43 | char *ddlCommand = text_to_cstring(ddlCommandText); 44 | 45 | List *extendedCommands = ExtendedDDLCommandList(distributedTableId, shardId, 46 | list_make1(ddlCommand)); 47 | 48 | if (list_length(extendedCommands) != 1) 49 | { 50 | ereport(ERROR, (errmsg("Expected single extended command"))); 51 | } 52 | 53 | PG_RETURN_CSTRING(linitial(extendedCommands)); 54 | } 55 | 56 | 57 | /* 58 | * extend_name accepts a name and shard identifier and returns an "extended" 59 | * name containing the shard identifier. 60 | */ 61 | Datum 62 | extend_name(PG_FUNCTION_ARGS) 63 | { 64 | char *name = PG_GETARG_CSTRING(0); 65 | int64 shardId = PG_GETARG_INT64(1); 66 | 67 | AppendShardIdToName(&name, shardId); 68 | 69 | PG_RETURN_CSTRING(name); 70 | } 71 | -------------------------------------------------------------------------------- /test/sql/01-connection.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION initialize_remote_temp_table(cstring, integer) 6 | RETURNS bool 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION count_remote_temp_table_rows(cstring, integer) 11 | RETURNS integer 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | 15 | CREATE FUNCTION get_and_purge_connection(cstring, integer) 16 | RETURNS bool 17 | AS 'pg_shard' 18 | LANGUAGE C STRICT; 19 | 20 | -- =================================================================== 21 | -- test connection hash functionality 22 | -- =================================================================== 23 | 24 | -- reduce verbosity to squelch chatty warnings 25 | \set VERBOSITY terse 26 | 27 | -- connect to non-existent host 28 | SELECT initialize_remote_temp_table('dummy-host-name', 12345); 29 | 30 | \set VERBOSITY default 31 | 32 | -- try to use hostname over 255 characters 33 | SELECT initialize_remote_temp_table(repeat('a', 256)::cstring, :worker_port); 34 | 35 | -- connect to localhost and build a temp table 36 | SELECT initialize_remote_temp_table('localhost', :worker_port); 37 | 38 | -- table should still be visible since session is reused 39 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 40 | 41 | -- purge existing connection to localhost 42 | SELECT get_and_purge_connection('localhost', :worker_port); 43 | 44 | -- squelch WARNINGs that contain worker_port 45 | SET client_min_messages TO ERROR; 46 | 47 | -- should not be able to see table anymore 48 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 49 | 50 | -- recreate once more 51 | SELECT initialize_remote_temp_table('localhost', :worker_port); 52 | 53 | -- kill backend to disconnect 54 | SELECT pg_terminate_backend(pid) 55 | FROM pg_stat_activity 56 | WHERE application_name = 'pg_shard'; 57 | 58 | -- should get connection failure (cached connection bad) 59 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 60 | 61 | -- should get result failure (reconnected, so no temp table) 62 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 63 | 64 | SET client_min_messages TO DEFAULT; 65 | -------------------------------------------------------------------------------- /CHANGELOG.md: -------------------------------------------------------------------------------- 1 | ### pg_shard v1.2.3 (October 28, 2015) ### 2 | 3 | * Addresses a performance regression by caching metadata plans 4 | 5 | ### pg_shard v1.2.2 (August 28, 2015) ### 6 | 7 | * Changes default planner when running within CitusDB 8 | 9 | ### pg_shard v1.2.1 (July 30, 2015) ### 10 | 11 | * Fixes update script bug triggered when running in CitusDB 12 | 13 | ### pg_shard v1.2.0 (July 28, 2015) ### 14 | 15 | * Distribution metadata stays continually in sync with CitusDB 16 | 17 | * Rejects VOLATILE and MUTABLE functions in modification commands 18 | 19 | * Adds support for partitioning by enumeration or composite types 20 | 21 | * Fixes deparsing of table constraints during shard creation 22 | 23 | * Improves error messages and user experience 24 | 25 | * Improves metadata locking behavior 26 | 27 | * Enhances project organization and build process 28 | 29 | ### pg_shard v1.1.1 (May 29, 2015) ### 30 | 31 | * Fixes shard repair bug triggered when indexes present 32 | 33 | ### pg_shard v1.1.0 (March 19, 2015) ### 34 | 35 | * Speeds up INSERTs by up to 300% 36 | 37 | * Adds function to repair inactive placements 38 | 39 | * Adds script to simplify copying data from files 40 | 41 | * Adds function to sync metadata to CitusDB catalogs 42 | 43 | * Fixes resource leaks that occurred during large queries 44 | 45 | * Improves error messages and user experience 46 | 47 | * Protects users from accidentally removing metadata 48 | 49 | * Optimizes columns fetched during SELECT queries 50 | 51 | * Brings full testing and continuous integration to the project 52 | 53 | ### pg_shard v1.0.2 (February 24, 2015) ### 54 | 55 | * Adds META.json file for PGXN 56 | 57 | ### pg_shard v1.0.1 (December 4, 2014) ### 58 | 59 | * Minor documentation fixes 60 | 61 | ### pg_shard v1.0.0 (December 4, 2014) ### 62 | 63 | * Public release under LGPLv3 64 | 65 | ### pg_shard v1.0.0-gm (December 3, 2014) ### 66 | 67 | * Adds support for PostgreSQL 9.4 in addition to 9.3 68 | 69 | * Rejects `PREPARE` or `COPY` statements involving distributed tables 70 | 71 | * Shard identifiers now begin at 10,000 rather than 1 72 | 73 | ### pg_shard v1.0.0-rc (November 21, 2014) ### 74 | 75 | * Initial release 76 | 77 | * Distributes a PostgreSQL table across many worker shards 78 | 79 | * Safely executes `INSERT`, `UPDATE`, and `DELETE` against single shards 80 | 81 | * Runs `SELECT` queries across many shards 82 | 83 | * `JOIN` unsupported 84 | 85 | * Rudimentary CitusDB compatibility 86 | 87 | * Requires PostgreSQL 9.3 88 | -------------------------------------------------------------------------------- /test/sql/06-prune_shard_list.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION prune_using_no_values(regclass) 6 | RETURNS text[] 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION prune_using_single_value(regclass, text) 11 | RETURNS text[] 12 | AS 'pg_shard' 13 | LANGUAGE C; 14 | 15 | CREATE FUNCTION prune_using_either_value(regclass, text, text) 16 | RETURNS text[] 17 | AS 'pg_shard' 18 | LANGUAGE C STRICT; 19 | 20 | CREATE FUNCTION prune_using_both_values(regclass, text, text) 21 | RETURNS text[] 22 | AS 'pg_shard' 23 | LANGUAGE C STRICT; 24 | 25 | CREATE FUNCTION debug_equality_expression(regclass) 26 | RETURNS cstring 27 | AS 'pg_shard' 28 | LANGUAGE C STRICT; 29 | 30 | -- =================================================================== 31 | -- test shard pruning functionality 32 | -- =================================================================== 33 | 34 | -- create distributed table metadata to observe shard pruning 35 | CREATE TABLE pruning ( species text, last_pruned date, plant_id integer ); 36 | 37 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 38 | VALUES 39 | ('pruning'::regclass, 'h', 'species'); 40 | 41 | INSERT INTO pgs_distribution_metadata.shard 42 | (id, relation_id, storage, min_value, max_value) 43 | VALUES 44 | (10, 'pruning'::regclass, 't', '-2147483648', '-1073741826'), 45 | (11, 'pruning'::regclass, 't', '-1073741825', '-3'), 46 | (12, 'pruning'::regclass, 't', '-2', '1073741820'), 47 | (13, 'pruning'::regclass, 't', '1073741821', '2147483647'); 48 | 49 | -- with no values, expect all shards 50 | SELECT prune_using_no_values('pruning'); 51 | 52 | -- with a single value, expect a single shard 53 | SELECT prune_using_single_value('pruning', 'tomato'); 54 | 55 | -- the above is true even if that value is null 56 | SELECT prune_using_single_value('pruning', NULL); 57 | 58 | -- build an OR clause and expect more than one sahrd 59 | SELECT prune_using_either_value('pruning', 'tomato', 'petunia'); 60 | 61 | -- an AND clause with incompatible values returns no shards 62 | SELECT prune_using_both_values('pruning', 'tomato', 'petunia'); 63 | 64 | -- but if both values are on the same shard, should get back that shard 65 | SELECT prune_using_both_values('pruning', 'tomato', 'rose'); 66 | 67 | -- unit test of the equality expression generation code 68 | SELECT debug_equality_expression('pruning'); 69 | -------------------------------------------------------------------------------- /test/sql/12-create_insert_proxy.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test INSERT proxy creation functionality 3 | -- =================================================================== 4 | 5 | -- use transaction to permit multiple calls to proxy function in one session 6 | BEGIN; 7 | 8 | -- use "unorthodox" object names to test quoting 9 | CREATE SCHEMA "A$AP Mob" 10 | CREATE TABLE "Dr. Bronner's ""Magic"" Soaps" ( 11 | id bigint PRIMARY KEY, 12 | data text NOT NULL DEFAULT 'lorem ipsum' 13 | ); 14 | 15 | \set insert_target '"A$AP Mob"."Dr. Bronner''s ""Magic"" Soaps"' 16 | 17 | -- create proxy and save proxy table name 18 | SELECT create_insert_proxy_for_table(:'insert_target') AS proxy_tablename 19 | \gset 20 | 21 | -- insert to proxy, relying on default value 22 | INSERT INTO pg_temp.:"proxy_tablename" (id) VALUES (1); 23 | 24 | -- copy some rows into the proxy 25 | COPY pg_temp.:"proxy_tablename" FROM stdin; 26 | 2 dolor sit amet 27 | 3 consectetur adipiscing elit 28 | 4 sed do eiusmod 29 | 5 tempor incididunt ut 30 | 6 labore et dolore 31 | \. 32 | 33 | -- verify rows were copied to target 34 | SELECT * FROM :insert_target ORDER BY id ASC; 35 | 36 | -- and not to proxy 37 | SELECT count(*) FROM pg_temp.:"proxy_tablename"; 38 | 39 | ROLLBACK; 40 | 41 | -- test behavior with distributed table, (so no transaction) 42 | CREATE TABLE insert_target ( 43 | id bigint PRIMARY KEY, 44 | data text NOT NULL DEFAULT 'lorem ipsum' 45 | ); 46 | 47 | -- squelch WARNINGs that contain worker_port 48 | SET client_min_messages TO ERROR; 49 | 50 | SELECT master_create_distributed_table('insert_target', 'id'); 51 | SELECT master_create_worker_shards('insert_target', 2, 1); 52 | 53 | CREATE TEMPORARY SEQUENCE rows_inserted; 54 | SELECT create_insert_proxy_for_table('insert_target', 'rows_inserted') AS proxy_tablename 55 | \gset 56 | 57 | -- insert to proxy, again relying on default value 58 | INSERT INTO pg_temp.:"proxy_tablename" (id) VALUES (1); 59 | 60 | -- test copy with bad row in middle 61 | \set VERBOSITY terse 62 | COPY pg_temp.:"proxy_tablename" FROM stdin; 63 | 2 dolor sit amet 64 | 3 consectetur adipiscing elit 65 | 4 sed do eiusmod 66 | 5 tempor incididunt ut 67 | 6 labore et dolore 68 | 7 \N 69 | 8 magna aliqua 70 | \. 71 | \set VERBOSITY default 72 | 73 | -- verify rows were copied to distributed table 74 | SELECT * FROM insert_target ORDER BY id ASC; 75 | 76 | -- the counter should match the number of rows stored 77 | SELECT currval('rows_inserted'); 78 | 79 | SET client_min_messages TO DEFAULT; 80 | -------------------------------------------------------------------------------- /Makefile: -------------------------------------------------------------------------------- 1 | #------------------------------------------------------------------------- 2 | # 3 | # Makefile for pg_shard 4 | # 5 | # Copyright (c) 2014-2015, Citus Data, Inc. 6 | # 7 | #------------------------------------------------------------------------- 8 | 9 | # grab name and version from META.json file 10 | EXTENSION = $(shell grep -m 1 '"name":' META.json | sed -e 's/[[:space:]]*"name":[[:space:]]*"\([^"]*\)",/\1/') 11 | EXTVERSION = $(shell grep default_version $(EXTENSION).control | sed -e "s/default_version[[:space:]]*=[[:space:]]*'\([^']*\)'/\1/") 12 | 13 | # installation scripts 14 | DATA = $(wildcard updates/*--*.sql) 15 | 16 | # documentation and executables 17 | DOCS = $(wildcard doc/*.md) 18 | SCRIPTS = $(wildcard bin/*) 19 | 20 | # compilation configuration 21 | MODULE_big = $(EXTENSION) 22 | OBJS = $(patsubst %.c,%.o,$(wildcard src/*.c)) 23 | PG_CPPFLAGS = -std=c99 -Wall -Wextra -Werror -Wno-unused-parameter -Iinclude -I$(libpq_srcdir) 24 | SHLIB_LINK = $(libpq) 25 | EXTRA_CLEAN += $(addprefix src/,*.gcno *.gcda) # clean up after profiling runs 26 | 27 | # test configuration 28 | TESTS = $(sort $(wildcard test/sql/*.sql)) 29 | REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS)) 30 | REGRESS_OPTS = --inputdir=test --load-language=plpgsql 31 | REGRESS_OPTS += --launcher=./test/launcher.sh # use custom launcher for tests 32 | 33 | # add coverage flags if requested 34 | ifeq ($(enable_coverage),yes) 35 | PG_CPPFLAGS += --coverage 36 | SHLIB_LINK += --coverage 37 | endif 38 | 39 | # Handle a Linux issue where the loader might resolve ambiguous symbols to 40 | # those within CitusDB rather than using those in pg_shard by ensuring the 41 | # linker must call the pg_shard functions instead. 42 | OS := $(shell uname) 43 | ifeq ($(OS), Linux) 44 | SHLIB_LINK += -Wl,-Bsymbolic 45 | endif 46 | 47 | # be explicit about the default target 48 | all: 49 | 50 | # delegate to subdirectory makefiles as needed 51 | include sql/Makefile 52 | include test/Makefile 53 | 54 | # detect whether to build with pgxs or build in-tree 55 | ifndef NO_PGXS 56 | PG_CONFIG = pg_config 57 | PGXS := $(shell $(PG_CONFIG) --pgxs) 58 | include $(PGXS) 59 | else 60 | SHLIB_PREREQS = submake-libpq 61 | subdir = contrib/pg_shard 62 | top_builddir = ../.. 63 | include $(top_builddir)/src/Makefile.global 64 | include $(top_srcdir)/contrib/contrib-global.mk 65 | endif 66 | 67 | # ensure MAJORVERSION is defined (missing in older versions) 68 | ifndef MAJORVERSION 69 | MAJORVERSION := $(basename $(VERSION)) 70 | endif 71 | 72 | # if using a version older than PostgreSQL 9.3, abort 73 | PG93 = $(shell echo $(MAJORVERSION) | grep -qE "8\.|9\.[012]" && echo no || echo yes) 74 | ifeq ($(PG93),no) 75 | $(error PostgreSQL 9.3 or higher is required to compile this extension) 76 | endif 77 | -------------------------------------------------------------------------------- /test/src/create_shards.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/create_shards.c 4 | * 5 | * This file contains functions to exercise shard creation functionality 6 | * within pg_shard. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "create_shards.h" 18 | #include "ddl_commands.h" 19 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 20 | 21 | #include 22 | 23 | #include "lib/stringinfo.h" 24 | #include "nodes/pg_list.h" 25 | 26 | 27 | /* local function forward declarations */ 28 | static int CompareStrings(const void *leftElement, const void *rightElement); 29 | 30 | 31 | /* declarations for dynamic loading */ 32 | PG_FUNCTION_INFO_V1(sort_names); 33 | PG_FUNCTION_INFO_V1(create_table_then_fail); 34 | 35 | 36 | /* 37 | * sort_names accepts three strings, places them in a list, then calls SortList 38 | * to test its sort functionality. Returns a string containing sorted lines. 39 | */ 40 | Datum 41 | sort_names(PG_FUNCTION_ARGS) 42 | { 43 | char *first = PG_GETARG_CSTRING(0); 44 | char *second = PG_GETARG_CSTRING(1); 45 | char *third = PG_GETARG_CSTRING(2); 46 | List *nameList = SortList(list_make3(first, second, third), 47 | (int (*)(const void *, const void *))(&CompareStrings)); 48 | StringInfo sortedNames = makeStringInfo(); 49 | 50 | ListCell *nameCell = NULL; 51 | foreach(nameCell, nameList) 52 | { 53 | char *name = lfirst(nameCell); 54 | appendStringInfo(sortedNames, "%s\n", name); 55 | } 56 | 57 | 58 | PG_RETURN_CSTRING(sortedNames->data); 59 | } 60 | 61 | 62 | /* 63 | * create_table_then_fail tests ExecuteRemoteCommandList's ability to rollback 64 | * after a failure by creating a table before issuing an unparsable command. 65 | * The entire transaction should roll back, so the table that was created will 66 | * no longer exist once control returns to the caller. Returns the same value 67 | * as the underlying ExecuteRemoteCommandList. 68 | */ 69 | Datum 70 | create_table_then_fail(PG_FUNCTION_ARGS) 71 | { 72 | char *nodeName = PG_GETARG_CSTRING(0); 73 | int32 nodePort = PG_GETARG_INT32(1); 74 | List *sqlCommandList = list_make2("CREATE TABLE throwaway()", "THIS WILL FAIL"); 75 | bool commandsExecuted = ExecuteRemoteCommandList(nodeName, nodePort, sqlCommandList); 76 | 77 | PG_RETURN_BOOL(commandsExecuted); 78 | } 79 | 80 | 81 | /* 82 | * A simple wrapper around strcmp suitable for use with SortList or qsort. 83 | */ 84 | static int 85 | CompareStrings(const void *leftElement, const void *rightElement) 86 | { 87 | const char *leftString = *((const char **) leftElement); 88 | const char *rightString = *((const char **) rightElement); 89 | 90 | return strcmp(leftString, rightString); 91 | } 92 | -------------------------------------------------------------------------------- /test/expected/12-create_insert_proxy.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test INSERT proxy creation functionality 3 | -- =================================================================== 4 | -- use transaction to permit multiple calls to proxy function in one session 5 | BEGIN; 6 | -- use "unorthodox" object names to test quoting 7 | CREATE SCHEMA "A$AP Mob" 8 | CREATE TABLE "Dr. Bronner's ""Magic"" Soaps" ( 9 | id bigint PRIMARY KEY, 10 | data text NOT NULL DEFAULT 'lorem ipsum' 11 | ); 12 | \set insert_target '"A$AP Mob"."Dr. Bronner''s ""Magic"" Soaps"' 13 | -- create proxy and save proxy table name 14 | SELECT create_insert_proxy_for_table(:'insert_target') AS proxy_tablename 15 | \gset 16 | -- insert to proxy, relying on default value 17 | INSERT INTO pg_temp.:"proxy_tablename" (id) VALUES (1); 18 | -- copy some rows into the proxy 19 | COPY pg_temp.:"proxy_tablename" FROM stdin; 20 | -- verify rows were copied to target 21 | SELECT * FROM :insert_target ORDER BY id ASC; 22 | id | data 23 | ----+----------------------------- 24 | 1 | lorem ipsum 25 | 2 | dolor sit amet 26 | 3 | consectetur adipiscing elit 27 | 4 | sed do eiusmod 28 | 5 | tempor incididunt ut 29 | 6 | labore et dolore 30 | (6 rows) 31 | 32 | -- and not to proxy 33 | SELECT count(*) FROM pg_temp.:"proxy_tablename"; 34 | count 35 | ------- 36 | 0 37 | (1 row) 38 | 39 | ROLLBACK; 40 | -- test behavior with distributed table, (so no transaction) 41 | CREATE TABLE insert_target ( 42 | id bigint PRIMARY KEY, 43 | data text NOT NULL DEFAULT 'lorem ipsum' 44 | ); 45 | -- squelch WARNINGs that contain worker_port 46 | SET client_min_messages TO ERROR; 47 | SELECT master_create_distributed_table('insert_target', 'id'); 48 | master_create_distributed_table 49 | --------------------------------- 50 | 51 | (1 row) 52 | 53 | SELECT master_create_worker_shards('insert_target', 2, 1); 54 | master_create_worker_shards 55 | ----------------------------- 56 | 57 | (1 row) 58 | 59 | CREATE TEMPORARY SEQUENCE rows_inserted; 60 | SELECT create_insert_proxy_for_table('insert_target', 'rows_inserted') AS proxy_tablename 61 | \gset 62 | -- insert to proxy, again relying on default value 63 | INSERT INTO pg_temp.:"proxy_tablename" (id) VALUES (1); 64 | -- test copy with bad row in middle 65 | \set VERBOSITY terse 66 | COPY pg_temp.:"proxy_tablename" FROM stdin; 67 | ERROR: could not modify any active placements 68 | \set VERBOSITY default 69 | -- verify rows were copied to distributed table 70 | SELECT * FROM insert_target ORDER BY id ASC; 71 | id | data 72 | ----+----------------------------- 73 | 1 | lorem ipsum 74 | 2 | dolor sit amet 75 | 3 | consectetur adipiscing elit 76 | 4 | sed do eiusmod 77 | 5 | tempor incididunt ut 78 | 6 | labore et dolore 79 | (6 rows) 80 | 81 | -- the counter should match the number of rows stored 82 | SELECT currval('rows_inserted'); 83 | currval 84 | --------- 85 | 6 86 | (1 row) 87 | 88 | SET client_min_messages TO DEFAULT; 89 | -------------------------------------------------------------------------------- /test/src/generate_ddl_commands.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/generate_ddl_commands.c 4 | * 5 | * This file contains functions to exercise DDL generation functionality 6 | * within pg_shard. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "ddl_commands.h" 18 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 19 | 20 | #include 21 | 22 | #include "catalog/pg_type.h" 23 | #include "lib/stringinfo.h" 24 | #include "nodes/makefuncs.h" 25 | #include "nodes/nodes.h" 26 | #include "nodes/parsenodes.h" 27 | #include "nodes/pg_list.h" 28 | #include "nodes/value.h" 29 | #include "utils/array.h" 30 | #include "utils/builtins.h" 31 | #include "utils/palloc.h" 32 | 33 | 34 | /* declarations for dynamic loading */ 35 | PG_FUNCTION_INFO_V1(table_ddl_command_array); 36 | PG_FUNCTION_INFO_V1(alter_server_host_and_port_command); 37 | 38 | 39 | /* 40 | * table_ddl_command_array returns an array of strings, each of which is a DDL 41 | * command required to recreate a table (specified by OID). 42 | */ 43 | Datum 44 | table_ddl_command_array(PG_FUNCTION_ARGS) 45 | { 46 | Oid distributedTableId = PG_GETARG_OID(0); 47 | ArrayType *ddlCommandArrayType = NULL; 48 | List *ddlCommandList = TableDDLCommandList(distributedTableId); 49 | int ddlCommandCount = list_length(ddlCommandList); 50 | Datum *ddlCommandDatumArray = palloc0(ddlCommandCount * sizeof(Datum)); 51 | 52 | ListCell *ddlCommandCell = NULL; 53 | int ddlCommandIndex = 0; 54 | Oid ddlCommandTypeId = TEXTOID; 55 | 56 | foreach(ddlCommandCell, ddlCommandList) 57 | { 58 | char *ddlCommand = (char *) lfirst(ddlCommandCell); 59 | Datum ddlCommandDatum = CStringGetTextDatum(ddlCommand); 60 | 61 | ddlCommandDatumArray[ddlCommandIndex] = ddlCommandDatum; 62 | ddlCommandIndex++; 63 | } 64 | 65 | ddlCommandArrayType = DatumArrayToArrayType(ddlCommandDatumArray, ddlCommandCount, 66 | ddlCommandTypeId); 67 | 68 | PG_RETURN_ARRAYTYPE_P(ddlCommandArrayType); 69 | } 70 | 71 | 72 | /* 73 | * alter_server_host_and_port_command is used to test foreign server OPTION 74 | * generation. When provided with a foreign server name, hostname and port, 75 | * the function will return an ALTER SERVER command to set the server's host 76 | * and port options to the provided values. 77 | */ 78 | Datum 79 | alter_server_host_and_port_command(PG_FUNCTION_ARGS) 80 | { 81 | char *serverName = PG_GETARG_CSTRING(0); 82 | char *newHost = PG_GETARG_CSTRING(1); 83 | char *newPort = PG_GETARG_CSTRING(2); 84 | StringInfo alterCommand = makeStringInfo(); 85 | 86 | DefElem *hostElem = makeDefElem("host", (Node *) makeString(newHost)); 87 | DefElem *portElem = makeDefElem("port", (Node *) makeString(newPort)); 88 | 89 | appendStringInfo(alterCommand, "ALTER SERVER %s", quote_identifier(serverName)); 90 | AppendOptionListToString(alterCommand, list_make2(hostElem, portElem)); 91 | 92 | PG_RETURN_TEXT_P(CStringGetTextDatum(alterCommand->data)); 93 | } 94 | -------------------------------------------------------------------------------- /CONTRIBUTING.md: -------------------------------------------------------------------------------- 1 | # Contributing to `pg_shard` 2 | 3 | Following these guidelines helps to facilitate relevant discussion in pull 4 | requests and issues so the developers managing and developing this open source 5 | project can address patches and bugs as efficiently as possible. 6 | 7 | ## Using Issues 8 | 9 | `pg_shard`'s maintainers prefer that bug reports, feature requests, and pull 10 | requests are submitted as [GitHub Issues][issues]. If you think you require personal 11 | assistance, please **do not** open an issue: email [the pg_shard Google Group][group] 12 | instead. 13 | 14 | ## Bug Reports 15 | 16 | Before opening a bug report: 17 | 18 | 1. Search for a duplicate issue using GitHub's issue search 19 | 2. Check whether the bug remains in the latest `master` or `develop` commit 20 | 3. Create a reduced test case: remove code and data not relevant to the bug 21 | 22 | A contributor should be able to begin work on your bug without asking too many 23 | followup questions. If you include the following information, your bug will be 24 | serviced more quickly: 25 | 26 | * Short, descriptive title 27 | * Your OS 28 | * Versions of dependencies 29 | * Any custom modifications 30 | 31 | Once the background information is out of the way, you are free to present the 32 | bug itself. You should explain: 33 | 34 | * Steps you took to exercise the bug 35 | * The expected outcome 36 | * What actually occurred 37 | 38 | ## Feature Requests 39 | 40 | We are open to adding features but ultimately control the scope and aims of the 41 | project. If a proposed feature is likely to incur high testing, maintenance, or 42 | performance costs it is also unlikely to be accepted. If a _strong_ case exists 43 | for a given feature, we may be persuaded on merit. Be specific. 44 | 45 | ## Pull Requests 46 | 47 | Well-constructed pull requests are very welcome. By _well-constructed_, we mean 48 | they do not introduce unrelated changes or break backwards compatibility. Just 49 | fork this repo and open a request against `develop`. 50 | 51 | Some examples of things likely to increase the likelihood a pull request is 52 | rejected: 53 | 54 | * Large structural changes, including: 55 | * Refactoring for its own sake 56 | * Adding languages to the project 57 | * Unnecesary whitespace changes 58 | * Deviation from obvious conventions 59 | * Introduction of incompatible intellectual property 60 | 61 | Please do not change version numbers in your pull request: they will be updated 62 | by the project owners prior to the next release. 63 | 64 | ## License 65 | 66 | By submitting a patch, you agree to allow the project owners to license your 67 | work under the terms of the [`LICENSE`][license]. Additionally, you grant the project 68 | owners a license under copyright covering your contribution to the extent 69 | permitted by law. Finally, you confirm that you own said copyright, have the 70 | legal authority to grant said license, and in doing so are not violating any 71 | grant of rights you have made to third parties, including your employer. 72 | 73 | [issues]: https://github.com/citusdata/pg_shard/issues 74 | [group]: https://groups.google.com/forum/#!forum/pg_shard-users 75 | [license]: LICENSE 76 | -------------------------------------------------------------------------------- /test/expected/01-connection.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | CREATE FUNCTION initialize_remote_temp_table(cstring, integer) 5 | RETURNS bool 6 | AS 'pg_shard' 7 | LANGUAGE C STRICT; 8 | CREATE FUNCTION count_remote_temp_table_rows(cstring, integer) 9 | RETURNS integer 10 | AS 'pg_shard' 11 | LANGUAGE C STRICT; 12 | CREATE FUNCTION get_and_purge_connection(cstring, integer) 13 | RETURNS bool 14 | AS 'pg_shard' 15 | LANGUAGE C STRICT; 16 | -- =================================================================== 17 | -- test connection hash functionality 18 | -- =================================================================== 19 | -- reduce verbosity to squelch chatty warnings 20 | \set VERBOSITY terse 21 | -- connect to non-existent host 22 | SELECT initialize_remote_temp_table('dummy-host-name', 12345); 23 | WARNING: Connection failed to dummy-host-name:12345 24 | initialize_remote_temp_table 25 | ------------------------------ 26 | f 27 | (1 row) 28 | 29 | \set VERBOSITY default 30 | -- try to use hostname over 255 characters 31 | SELECT initialize_remote_temp_table(repeat('a', 256)::cstring, :worker_port); 32 | ERROR: hostname exceeds the maximum length of 255 33 | -- connect to localhost and build a temp table 34 | SELECT initialize_remote_temp_table('localhost', :worker_port); 35 | initialize_remote_temp_table 36 | ------------------------------ 37 | t 38 | (1 row) 39 | 40 | -- table should still be visible since session is reused 41 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 42 | count_remote_temp_table_rows 43 | ------------------------------ 44 | 100 45 | (1 row) 46 | 47 | -- purge existing connection to localhost 48 | SELECT get_and_purge_connection('localhost', :worker_port); 49 | get_and_purge_connection 50 | -------------------------- 51 | t 52 | (1 row) 53 | 54 | -- squelch WARNINGs that contain worker_port 55 | SET client_min_messages TO ERROR; 56 | -- should not be able to see table anymore 57 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 58 | count_remote_temp_table_rows 59 | ------------------------------ 60 | -1 61 | (1 row) 62 | 63 | -- recreate once more 64 | SELECT initialize_remote_temp_table('localhost', :worker_port); 65 | initialize_remote_temp_table 66 | ------------------------------ 67 | t 68 | (1 row) 69 | 70 | -- kill backend to disconnect 71 | SELECT pg_terminate_backend(pid) 72 | FROM pg_stat_activity 73 | WHERE application_name = 'pg_shard'; 74 | pg_terminate_backend 75 | ---------------------- 76 | t 77 | (1 row) 78 | 79 | -- should get connection failure (cached connection bad) 80 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 81 | count_remote_temp_table_rows 82 | ------------------------------ 83 | -1 84 | (1 row) 85 | 86 | -- should get result failure (reconnected, so no temp table) 87 | SELECT count_remote_temp_table_rows('localhost', :worker_port); 88 | count_remote_temp_table_rows 89 | ------------------------------ 90 | -1 91 | (1 row) 92 | 93 | SET client_min_messages TO DEFAULT; 94 | -------------------------------------------------------------------------------- /test/include/test_helper_functions.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/include/test_helper_functions.h 4 | * 5 | * Declarations for public functions and types related to unit testing 6 | * functionality. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #ifndef PG_SHARD_TEST_HELPER_FUNCTIONS_H 14 | #define PG_SHARD_TEST_HELPER_FUNCTIONS_H 15 | 16 | #include "postgres.h" 17 | #include "c.h" 18 | #include "fmgr.h" 19 | 20 | #include "utils/array.h" 21 | 22 | 23 | /* SQL statements for testing */ 24 | #define POPULATE_TEMP_TABLE "CREATE TEMPORARY TABLE numbers " \ 25 | "AS SELECT * FROM generate_series(1, 100);" 26 | #define COUNT_TEMP_TABLE "SELECT COUNT(*) FROM numbers;" 27 | 28 | 29 | /* function declarations for generic test functions */ 30 | extern ArrayType * DatumArrayToArrayType(Datum *datumArray, int datumCount, 31 | Oid datumTypeId); 32 | 33 | /* fake FDW for use in tests */ 34 | extern Datum fake_fdw_handler(PG_FUNCTION_ARGS); 35 | 36 | /* function declarations for exercising connection functions */ 37 | extern Datum initialize_remote_temp_table(PG_FUNCTION_ARGS); 38 | extern Datum count_remote_temp_table_rows(PG_FUNCTION_ARGS); 39 | extern Datum get_and_purge_connection(PG_FUNCTION_ARGS); 40 | 41 | /* function declarations for exercising metadata functions */ 42 | extern Datum load_shard_id_array(PG_FUNCTION_ARGS); 43 | extern Datum load_shard_interval_array(PG_FUNCTION_ARGS); 44 | extern Datum load_shard_placement_array(PG_FUNCTION_ARGS); 45 | extern Datum partition_column_id(PG_FUNCTION_ARGS); 46 | extern Datum partition_type(PG_FUNCTION_ARGS); 47 | extern Datum is_distributed_table(PG_FUNCTION_ARGS); 48 | extern Datum distributed_tables_exist(PG_FUNCTION_ARGS); 49 | extern Datum column_name_to_column_id(PG_FUNCTION_ARGS); 50 | extern Datum insert_hash_partition_row(PG_FUNCTION_ARGS); 51 | extern Datum create_monolithic_shard_row(PG_FUNCTION_ARGS); 52 | extern Datum create_healthy_local_shard_placement_row(PG_FUNCTION_ARGS); 53 | extern Datum delete_shard_placement_row(PG_FUNCTION_ARGS); 54 | extern Datum update_shard_placement_row_state(PG_FUNCTION_ARGS); 55 | extern Datum next_shard_id(PG_FUNCTION_ARGS); 56 | extern Datum acquire_shared_shard_lock(PG_FUNCTION_ARGS); 57 | 58 | /* function declarations for exercising ddl generation functions */ 59 | extern Datum table_ddl_command_array(PG_FUNCTION_ARGS); 60 | extern Datum alter_server_host_and_port_command(PG_FUNCTION_ARGS); 61 | 62 | /* function declarations for exercising ddl extension functions */ 63 | extern Datum extend_ddl_command(PG_FUNCTION_ARGS); 64 | extern Datum extend_name(PG_FUNCTION_ARGS); 65 | 66 | /* function declarations for exercising shard creation functions */ 67 | extern Datum sort_names(PG_FUNCTION_ARGS); 68 | extern Datum create_table_then_fail(PG_FUNCTION_ARGS); 69 | 70 | /* function declarations for exercising shard pruning functions */ 71 | extern Datum prune_using_no_values(PG_FUNCTION_ARGS); 72 | extern Datum prune_using_single_value(PG_FUNCTION_ARGS); 73 | extern Datum prune_using_either_value(PG_FUNCTION_ARGS); 74 | extern Datum prune_using_both_values(PG_FUNCTION_ARGS); 75 | extern Datum debug_equality_expression(PG_FUNCTION_ARGS); 76 | 77 | 78 | #endif /* PG_SHARD_TEST_HELPER_FUNCTIONS_H */ 79 | -------------------------------------------------------------------------------- /include/pg_shard.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/pg_shard.h 4 | * 5 | * Declarations for public functions and types needed by the pg_shard extension. 6 | * 7 | * Copyright (c) 2014-2015, Citus Data, Inc. 8 | * 9 | *------------------------------------------------------------------------- 10 | */ 11 | 12 | #ifndef PG_SHARD_H 13 | #define PG_SHARD_H 14 | 15 | #include "c.h" 16 | 17 | #include "access/tupdesc.h" 18 | #include "catalog/indexing.h" 19 | #include "nodes/parsenodes.h" 20 | #include "nodes/pg_list.h" 21 | #include "nodes/plannodes.h" 22 | #include "lib/stringinfo.h" 23 | #include "utils/tuplestore.h" 24 | 25 | 26 | /* detect when building against CitusDB */ 27 | #ifdef DistPartitionLogicalRelidIndexId 28 | #define BUILT_AGAINST_CITUSDB true 29 | #else 30 | #define BUILT_AGAINST_CITUSDB false 31 | #endif 32 | 33 | /* prefix used for temporary tables created on the master node */ 34 | #define TEMPORARY_TABLE_PREFIX "pg_shard_temp_table" 35 | 36 | /* extension name used to determine if extension has been created */ 37 | #define PG_SHARD_EXTENSION_NAME "pg_shard" 38 | 39 | 40 | /* 41 | * DistributedNodeTag identifies nodes used in the planning and execution of 42 | * queries interacting with distributed tables. 43 | */ 44 | typedef enum DistributedNodeTag 45 | { 46 | /* Tags for distributed planning begin a safe distance after all other tags. */ 47 | T_DistributedPlan = 2100, /* plan to be built and passed to executor */ 48 | } DistributedNodeTag; 49 | 50 | 51 | /* 52 | * PlannerType identifies the type of planner which should be used for a given 53 | * query. 54 | */ 55 | typedef enum PlannerType 56 | { 57 | PLANNER_INVALID_FIRST = 0, 58 | PLANNER_TYPE_CITUSDB = 1, 59 | PLANNER_TYPE_PG_SHARD = 2, 60 | PLANNER_TYPE_POSTGRES = 3 61 | } PlannerType; 62 | 63 | 64 | /* 65 | * DistributedPlan contains a set of tasks to be executed remotely as part of a 66 | * distributed query. 67 | */ 68 | typedef struct DistributedPlan 69 | { 70 | Plan plan; /* this is a "subclass" of Plan */ 71 | Plan *originalPlan; /* we save a copy of standard_planner's output */ 72 | List *taskList; /* list of tasks to run as part of this plan */ 73 | List *targetList; /* copy of the target list for remote SELECT queries only */ 74 | 75 | bool selectFromMultipleShards; /* does the select run across multiple shards? */ 76 | CreateStmt *createTemporaryTableStmt; /* valid for multiple shard selects */ 77 | } DistributedPlan; 78 | 79 | 80 | /* 81 | * Tasks just bundle a query string (already ready for execution) with a list of 82 | * placements on which that string could be executed. The semantics of a task 83 | * will vary based on the type of statement being executed: an INSERT must be 84 | * executed on all placements, but a SELECT might view subsequent placements as 85 | * fallbacks to be used only if the first placement fails to respond. 86 | */ 87 | typedef struct Task 88 | { 89 | StringInfo queryString; /* SQL string suitable for immediate remote execution */ 90 | List *taskPlacementList; /* ShardPlacements on which the task can be executed */ 91 | int64 shardId; /* Denormalized shardId of tasks for convenience */ 92 | } Task; 93 | 94 | 95 | /* function declarations for extension loading and unloading */ 96 | extern void _PG_init(void); 97 | extern void _PG_fini(void); 98 | extern bool ExecuteTaskAndStoreResults(Task *task, TupleDesc tupleDescriptor, 99 | Tuplestorestate *tupleStore); 100 | 101 | 102 | #endif /* PG_SHARD_H */ 103 | -------------------------------------------------------------------------------- /test/expected/06-prune_shard_list.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | CREATE FUNCTION prune_using_no_values(regclass) 5 | RETURNS text[] 6 | AS 'pg_shard' 7 | LANGUAGE C STRICT; 8 | CREATE FUNCTION prune_using_single_value(regclass, text) 9 | RETURNS text[] 10 | AS 'pg_shard' 11 | LANGUAGE C; 12 | CREATE FUNCTION prune_using_either_value(regclass, text, text) 13 | RETURNS text[] 14 | AS 'pg_shard' 15 | LANGUAGE C STRICT; 16 | CREATE FUNCTION prune_using_both_values(regclass, text, text) 17 | RETURNS text[] 18 | AS 'pg_shard' 19 | LANGUAGE C STRICT; 20 | CREATE FUNCTION debug_equality_expression(regclass) 21 | RETURNS cstring 22 | AS 'pg_shard' 23 | LANGUAGE C STRICT; 24 | -- =================================================================== 25 | -- test shard pruning functionality 26 | -- =================================================================== 27 | -- create distributed table metadata to observe shard pruning 28 | CREATE TABLE pruning ( species text, last_pruned date, plant_id integer ); 29 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 30 | VALUES 31 | ('pruning'::regclass, 'h', 'species'); 32 | INSERT INTO pgs_distribution_metadata.shard 33 | (id, relation_id, storage, min_value, max_value) 34 | VALUES 35 | (10, 'pruning'::regclass, 't', '-2147483648', '-1073741826'), 36 | (11, 'pruning'::regclass, 't', '-1073741825', '-3'), 37 | (12, 'pruning'::regclass, 't', '-2', '1073741820'), 38 | (13, 'pruning'::regclass, 't', '1073741821', '2147483647'); 39 | -- with no values, expect all shards 40 | SELECT prune_using_no_values('pruning'); 41 | prune_using_no_values 42 | ----------------------- 43 | {10,11,12,13} 44 | (1 row) 45 | 46 | -- with a single value, expect a single shard 47 | SELECT prune_using_single_value('pruning', 'tomato'); 48 | prune_using_single_value 49 | -------------------------- 50 | {12} 51 | (1 row) 52 | 53 | -- the above is true even if that value is null 54 | SELECT prune_using_single_value('pruning', NULL); 55 | prune_using_single_value 56 | -------------------------- 57 | {12} 58 | (1 row) 59 | 60 | -- build an OR clause and expect more than one sahrd 61 | SELECT prune_using_either_value('pruning', 'tomato', 'petunia'); 62 | prune_using_either_value 63 | -------------------------- 64 | {11,12} 65 | (1 row) 66 | 67 | -- an AND clause with incompatible values returns no shards 68 | SELECT prune_using_both_values('pruning', 'tomato', 'petunia'); 69 | prune_using_both_values 70 | ------------------------- 71 | {} 72 | (1 row) 73 | 74 | -- but if both values are on the same shard, should get back that shard 75 | SELECT prune_using_both_values('pruning', 'tomato', 'rose'); 76 | prune_using_both_values 77 | ------------------------- 78 | {12} 79 | (1 row) 80 | 81 | -- unit test of the equality expression generation code 82 | SELECT debug_equality_expression('pruning'); 83 | debug_equality_expression 84 | -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 85 | {OPEXPR :opno 98 :opfuncid 67 :opresulttype 16 :opretset false :opcollid 0 :inputcollid 100 :args ({VAR :varno 1 :varattno 1 :vartype 25 :vartypmod -1 :varcollid 100 :varlevelsup 0 :varnoold 1 :varoattno 1 :location -1} {CONST :consttype 25 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull true :location -1 :constvalue <>}) :location -1} 86 | (1 row) 87 | 88 | -------------------------------------------------------------------------------- /test/src/connection.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/connection.c 4 | * 5 | * This file contains functions to exercise pg_shard's connection hash 6 | * functionality for purposes of unit testing. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | #include "libpq-fe.h" 17 | 18 | #include "connection.h" 19 | #include "test_helper_functions.h" 20 | 21 | #include 22 | #include 23 | 24 | #include "catalog/pg_type.h" 25 | #include "utils/lsyscache.h" 26 | 27 | 28 | /* local function forward declarations */ 29 | static Datum ExtractIntegerDatum(char *input); 30 | 31 | 32 | /* declarations for dynamic loading */ 33 | PG_FUNCTION_INFO_V1(initialize_remote_temp_table); 34 | PG_FUNCTION_INFO_V1(count_remote_temp_table_rows); 35 | PG_FUNCTION_INFO_V1(get_and_purge_connection); 36 | 37 | 38 | /* 39 | * initialize_remote_temp_table connects to a specified host on a specified 40 | * port and creates a temporary table with 100 rows. Because the table is 41 | * temporary, it will be visible if a connection is reused but not if a new 42 | * connection is opened to the node. 43 | */ 44 | Datum 45 | initialize_remote_temp_table(PG_FUNCTION_ARGS) 46 | { 47 | char *nodeName = PG_GETARG_CSTRING(0); 48 | int32 nodePort = PG_GETARG_INT32(1); 49 | PGresult *result = NULL; 50 | 51 | PGconn *connection = GetConnection(nodeName, nodePort); 52 | if (connection == NULL) 53 | { 54 | PG_RETURN_BOOL(false); 55 | } 56 | 57 | result = PQexec(connection, POPULATE_TEMP_TABLE); 58 | if (PQresultStatus(result) != PGRES_COMMAND_OK) 59 | { 60 | ReportRemoteError(connection, result); 61 | } 62 | 63 | PQclear(result); 64 | 65 | PG_RETURN_BOOL(true); 66 | } 67 | 68 | 69 | /* 70 | * count_remote_temp_table_rows just returns the integer count of rows in the 71 | * table created by initialize_remote_temp_table. If no such table exists, this 72 | * function emits a warning and returns -1. 73 | */ 74 | Datum 75 | count_remote_temp_table_rows(PG_FUNCTION_ARGS) 76 | { 77 | char *nodeName = PG_GETARG_CSTRING(0); 78 | int32 nodePort = PG_GETARG_INT32(1); 79 | Datum count = Int32GetDatum(-1); 80 | PGresult *result = NULL; 81 | 82 | PGconn *connection = GetConnection(nodeName, nodePort); 83 | if (connection == NULL) 84 | { 85 | PG_RETURN_DATUM(count); 86 | } 87 | 88 | result = PQexec(connection, COUNT_TEMP_TABLE); 89 | if (PQresultStatus(result) != PGRES_TUPLES_OK) 90 | { 91 | ReportRemoteError(connection, result); 92 | } 93 | else 94 | { 95 | char *countText = PQgetvalue(result, 0, 0); 96 | count = ExtractIntegerDatum(countText); 97 | } 98 | 99 | PQclear(result); 100 | 101 | PG_RETURN_DATUM(count); 102 | } 103 | 104 | 105 | /* 106 | * get_and_purge_connection first gets a connection using the provided hostname 107 | * and port before immediately passing that connection to PurgeConnection. 108 | * Simply a wrapper around PurgeConnection that uses hostname/port rather than 109 | * PGconn. 110 | */ 111 | Datum 112 | get_and_purge_connection(PG_FUNCTION_ARGS) 113 | { 114 | char *nodeName = PG_GETARG_CSTRING(0); 115 | int32 nodePort = PG_GETARG_INT32(1); 116 | 117 | PGconn *connection = GetConnection(nodeName, nodePort); 118 | if (connection == NULL) 119 | { 120 | PG_RETURN_BOOL(false); 121 | } 122 | 123 | PurgeConnection(connection); 124 | 125 | PG_RETURN_BOOL(true); 126 | } 127 | 128 | 129 | /* 130 | * ExtractIntegerDatum transforms an integer in textual form into a Datum. 131 | */ 132 | static Datum 133 | ExtractIntegerDatum(char *input) 134 | { 135 | Oid typIoFunc = InvalidOid; 136 | Oid typIoParam = InvalidOid; 137 | Datum intDatum = 0; 138 | FmgrInfo fmgrInfo; 139 | memset(&fmgrInfo, 0, sizeof(fmgrInfo)); 140 | 141 | getTypeInputInfo(INT4OID, &typIoFunc, &typIoParam); 142 | fmgr_info(typIoFunc, &fmgrInfo); 143 | 144 | intDatum = InputFunctionCall(&fmgrInfo, input, typIoFunc, -1); 145 | 146 | return intDatum; 147 | } 148 | -------------------------------------------------------------------------------- /test/sql/04-generate_ddl_commands.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION table_ddl_command_array(regclass) 6 | RETURNS text[] 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION alter_server_host_and_port_command(server_name cstring, 11 | host cstring, 12 | port cstring) 13 | RETURNS text 14 | AS 'pg_shard' 15 | LANGUAGE C STRICT; 16 | 17 | -- =================================================================== 18 | -- test ddl command generation functionality 19 | -- =================================================================== 20 | 21 | -- first make sure a simple table works 22 | CREATE TABLE simple_table ( 23 | first_name text, 24 | last_name text, 25 | id bigint 26 | ); 27 | 28 | SELECT table_ddl_command_array('simple_table'); 29 | 30 | -- ensure not-null constraints are propagated 31 | CREATE TABLE not_null_table ( 32 | city text, 33 | id bigint not null 34 | ); 35 | 36 | SELECT table_ddl_command_array('not_null_table'); 37 | 38 | -- even more complex constraints should be preserved... 39 | CREATE TABLE column_constraint_table ( 40 | first_name text, 41 | last_name text, 42 | age int CONSTRAINT non_negative_age CHECK (age >= 0) 43 | ); 44 | 45 | SELECT table_ddl_command_array('column_constraint_table'); 46 | 47 | -- including table constraints 48 | CREATE TABLE table_constraint_table ( 49 | bid_item_id bigint, 50 | min_bid decimal not null, 51 | max_bid decimal not null, 52 | CONSTRAINT bids_ordered CHECK (min_bid > max_bid) 53 | ); 54 | 55 | SELECT table_ddl_command_array('table_constraint_table'); 56 | 57 | -- default values are supported 58 | CREATE TABLE default_value_table ( 59 | name text, 60 | price decimal default 0.00 61 | ); 62 | 63 | SELECT table_ddl_command_array('default_value_table'); 64 | 65 | -- of course primary keys work... 66 | CREATE TABLE pkey_table ( 67 | first_name text, 68 | last_name text, 69 | id bigint PRIMARY KEY 70 | ); 71 | 72 | SELECT table_ddl_command_array('pkey_table'); 73 | 74 | -- as do unique indexes... 75 | CREATE TABLE unique_table ( 76 | user_id bigint not null, 77 | username text UNIQUE not null 78 | ); 79 | 80 | SELECT table_ddl_command_array('unique_table'); 81 | 82 | -- and indexes used for clustering 83 | CREATE TABLE clustered_table ( 84 | data json not null, 85 | received_at timestamp not null 86 | ); 87 | 88 | CREATE INDEX clustered_time_idx ON clustered_table (received_at); 89 | 90 | CLUSTER clustered_table USING clustered_time_idx; 91 | 92 | SELECT table_ddl_command_array('clustered_table'); 93 | 94 | -- fiddly things like storage type and statistics also work 95 | CREATE TABLE fiddly_table ( 96 | hostname char(255) not null, 97 | os char(255) not null, 98 | ip_addr inet not null, 99 | traceroute text not null 100 | ); 101 | 102 | ALTER TABLE fiddly_table 103 | ALTER hostname SET STORAGE PLAIN, 104 | ALTER os SET STORAGE MAIN, 105 | ALTER ip_addr SET STORAGE EXTENDED, 106 | ALTER traceroute SET STORAGE EXTERNAL, 107 | ALTER ip_addr SET STATISTICS 500; 108 | 109 | SELECT table_ddl_command_array('fiddly_table'); 110 | 111 | -- test foreign tables using fake FDW 112 | CREATE FOREIGN TABLE foreign_table ( 113 | id bigint not null, 114 | full_name text not null default '' 115 | ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); 116 | 117 | SELECT table_ddl_command_array('foreign_table'); 118 | 119 | -- propagating views is not supported 120 | CREATE VIEW local_view AS SELECT * FROM simple_table; 121 | 122 | SELECT table_ddl_command_array('local_view'); 123 | 124 | -- independently test option-generation code 125 | SELECT alter_server_host_and_port_command('fake_fdw_server', 'localhost', '5432'); 126 | 127 | -- clean up 128 | DROP VIEW IF EXISTS local_view; 129 | DROP FOREIGN TABLE IF EXISTS foreign_table; 130 | DROP TABLE IF EXISTS simple_table, not_null_table, column_constraint_table, 131 | table_constraint_table, default_value_table, pkey_table, 132 | unique_table, clustered_table, fiddly_table; 133 | -------------------------------------------------------------------------------- /test/sql/07-repair_shards.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test shard repair functionality 3 | -- =================================================================== 4 | 5 | -- create a table and create its distribution metadata 6 | CREATE TABLE customer_engagements ( id integer, created_at date, event_data text ); 7 | 8 | -- add some indexes 9 | CREATE INDEX ON customer_engagements (id); 10 | CREATE INDEX ON customer_engagements (created_at); 11 | CREATE INDEX ON customer_engagements (event_data); 12 | 13 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 14 | VALUES 15 | ('customer_engagements'::regclass, 'h', 'id'); 16 | 17 | INSERT INTO pgs_distribution_metadata.shard 18 | (id, relation_id, storage, min_value, max_value) 19 | VALUES 20 | (20, 'customer_engagements'::regclass, 't', '-2147483648', '2147483647'); 21 | 22 | -- Note we are "distributing" this table on localhost and 127.0.0.1, i.e. two 23 | -- hostnames for the same machine. This is a hack to get the pg_shard master to 24 | -- connect back to itself (most we can hope for with installcheck). The other 25 | -- entries are to test input parameter validation. 26 | INSERT INTO pgs_distribution_metadata.shard_placement 27 | (id, node_name, node_port, shard_id, shard_state) 28 | VALUES 29 | (200, 'localhost', :worker_port, 20, 1), 30 | (201, '127.0.0.1', :worker_port, 20, 3), 31 | (202, 'dummyhost', :worker_port, 20, 1), 32 | (203, 'otherhost', :worker_port, 20, 3); 33 | 34 | -- first, test input checking by trying to copy into a finalized placement 35 | SELECT master_copy_shard_placement(20, 'localhost', :worker_port, 'dummyhost', :worker_port); 36 | 37 | -- also try to copy from an inactive placement 38 | SELECT master_copy_shard_placement(20, 'otherhost', :worker_port, '127.0.0.1', :worker_port); 39 | 40 | -- next, create an empty "shard" for the table 41 | CREATE TABLE customer_engagements_20 ( LIKE customer_engagements ); 42 | 43 | -- capture its current object identifier 44 | \o /dev/null 45 | SELECT 'customer_engagements_20'::regclass::oid AS shardoid; 46 | \gset 47 | \o 48 | 49 | -- "copy" this shard from localhost to 127.0.0.1 50 | SELECT master_copy_shard_placement(20, 'localhost', :worker_port, '127.0.0.1', :worker_port); 51 | 52 | -- the table was recreated, so capture the new object identifier 53 | \o /dev/null 54 | SELECT 'customer_engagements_20'::regclass::oid AS repairedoid; 55 | \gset 56 | \o 57 | 58 | -- the recreated table should have a new oid 59 | SELECT :shardoid != :repairedoid AS shard_recreated; 60 | 61 | -- now do the same test over again with a foreign table 62 | CREATE FOREIGN TABLE remote_engagements ( 63 | id integer, 64 | created_at date, 65 | event_data text 66 | ) SERVER fake_fdw_server; 67 | 68 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 69 | VALUES 70 | ('remote_engagements'::regclass, 'h', 'id'); 71 | 72 | INSERT INTO pgs_distribution_metadata.shard 73 | (id, relation_id, storage, min_value, max_value) 74 | VALUES 75 | (30, 'remote_engagements'::regclass, 'f', '-2147483648', '2147483647'); 76 | 77 | INSERT INTO pgs_distribution_metadata.shard_placement 78 | (id, node_name, node_port, shard_id, shard_state) 79 | VALUES 80 | (300, 'localhost', :worker_port, 30, 1), 81 | (301, '127.0.0.1', :worker_port, 30, 3); 82 | 83 | CREATE FOREIGN TABLE remote_engagements_30 ( 84 | id integer, 85 | created_at date, 86 | event_data text 87 | ) SERVER fake_fdw_server; 88 | 89 | -- oops! we don't support repairing shards backed by foreign tables 90 | SELECT master_copy_shard_placement(30, 'localhost', :worker_port, '127.0.0.1', :worker_port); 91 | 92 | -- At this point, we've tested recreating a shard's table, but haven't seen 93 | -- whether the rows themselves are correctly copied. We'll insert a few rows 94 | -- into our "shard" and use our hack to get the pg_shard worker to connect back 95 | -- to itself and copy the rows back into their own shard, i.e. doubling rows. 96 | INSERT INTO customer_engagements_20 DEFAULT VALUES; 97 | 98 | -- call the copy UDF directly to just copy the rows without recreating table 99 | SELECT worker_copy_shard_placement('customer_engagements_20', 'localhost', :worker_port); 100 | 101 | -- should expect twice as many rows as we put in 102 | SELECT COUNT(*) FROM customer_engagements_20; 103 | -------------------------------------------------------------------------------- /test/expected/07-repair_shards.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test shard repair functionality 3 | -- =================================================================== 4 | -- create a table and create its distribution metadata 5 | CREATE TABLE customer_engagements ( id integer, created_at date, event_data text ); 6 | -- add some indexes 7 | CREATE INDEX ON customer_engagements (id); 8 | CREATE INDEX ON customer_engagements (created_at); 9 | CREATE INDEX ON customer_engagements (event_data); 10 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 11 | VALUES 12 | ('customer_engagements'::regclass, 'h', 'id'); 13 | INSERT INTO pgs_distribution_metadata.shard 14 | (id, relation_id, storage, min_value, max_value) 15 | VALUES 16 | (20, 'customer_engagements'::regclass, 't', '-2147483648', '2147483647'); 17 | -- Note we are "distributing" this table on localhost and 127.0.0.1, i.e. two 18 | -- hostnames for the same machine. This is a hack to get the pg_shard master to 19 | -- connect back to itself (most we can hope for with installcheck). The other 20 | -- entries are to test input parameter validation. 21 | INSERT INTO pgs_distribution_metadata.shard_placement 22 | (id, node_name, node_port, shard_id, shard_state) 23 | VALUES 24 | (200, 'localhost', :worker_port, 20, 1), 25 | (201, '127.0.0.1', :worker_port, 20, 3), 26 | (202, 'dummyhost', :worker_port, 20, 1), 27 | (203, 'otherhost', :worker_port, 20, 3); 28 | -- first, test input checking by trying to copy into a finalized placement 29 | SELECT master_copy_shard_placement(20, 'localhost', :worker_port, 'dummyhost', :worker_port); 30 | ERROR: target placement must be in inactive state 31 | -- also try to copy from an inactive placement 32 | SELECT master_copy_shard_placement(20, 'otherhost', :worker_port, '127.0.0.1', :worker_port); 33 | ERROR: source placement must be in finalized state 34 | -- next, create an empty "shard" for the table 35 | CREATE TABLE customer_engagements_20 ( LIKE customer_engagements ); 36 | -- capture its current object identifier 37 | \o /dev/null 38 | SELECT 'customer_engagements_20'::regclass::oid AS shardoid; 39 | \gset 40 | \o 41 | -- "copy" this shard from localhost to 127.0.0.1 42 | SELECT master_copy_shard_placement(20, 'localhost', :worker_port, '127.0.0.1', :worker_port); 43 | master_copy_shard_placement 44 | ----------------------------- 45 | 46 | (1 row) 47 | 48 | -- the table was recreated, so capture the new object identifier 49 | \o /dev/null 50 | SELECT 'customer_engagements_20'::regclass::oid AS repairedoid; 51 | \gset 52 | \o 53 | -- the recreated table should have a new oid 54 | SELECT :shardoid != :repairedoid AS shard_recreated; 55 | shard_recreated 56 | ----------------- 57 | t 58 | (1 row) 59 | 60 | -- now do the same test over again with a foreign table 61 | CREATE FOREIGN TABLE remote_engagements ( 62 | id integer, 63 | created_at date, 64 | event_data text 65 | ) SERVER fake_fdw_server; 66 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 67 | VALUES 68 | ('remote_engagements'::regclass, 'h', 'id'); 69 | INSERT INTO pgs_distribution_metadata.shard 70 | (id, relation_id, storage, min_value, max_value) 71 | VALUES 72 | (30, 'remote_engagements'::regclass, 'f', '-2147483648', '2147483647'); 73 | INSERT INTO pgs_distribution_metadata.shard_placement 74 | (id, node_name, node_port, shard_id, shard_state) 75 | VALUES 76 | (300, 'localhost', :worker_port, 30, 1), 77 | (301, '127.0.0.1', :worker_port, 30, 3); 78 | CREATE FOREIGN TABLE remote_engagements_30 ( 79 | id integer, 80 | created_at date, 81 | event_data text 82 | ) SERVER fake_fdw_server; 83 | -- oops! we don't support repairing shards backed by foreign tables 84 | SELECT master_copy_shard_placement(30, 'localhost', :worker_port, '127.0.0.1', :worker_port); 85 | ERROR: cannot repair shard 86 | DETAIL: Repairing shards backed by foreign tables is not supported. 87 | -- At this point, we've tested recreating a shard's table, but haven't seen 88 | -- whether the rows themselves are correctly copied. We'll insert a few rows 89 | -- into our "shard" and use our hack to get the pg_shard worker to connect back 90 | -- to itself and copy the rows back into their own shard, i.e. doubling rows. 91 | INSERT INTO customer_engagements_20 DEFAULT VALUES; 92 | -- call the copy UDF directly to just copy the rows without recreating table 93 | SELECT worker_copy_shard_placement('customer_engagements_20', 'localhost', :worker_port); 94 | worker_copy_shard_placement 95 | ----------------------------- 96 | 97 | (1 row) 98 | 99 | -- should expect twice as many rows as we put in 100 | SELECT COUNT(*) FROM customer_engagements_20; 101 | count 102 | ------- 103 | 2 104 | (1 row) 105 | 106 | -------------------------------------------------------------------------------- /src/citus_metadata_sync.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * src/citus_metadata_sync.c 4 | * 5 | * This file contains functions to sync pg_shard metadata to the CitusDB 6 | * metadata tables. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "citus_metadata_sync.h" /* IWYU pragma: keep */ 18 | #include "distribution_metadata.h" 19 | 20 | #include 21 | 22 | #include "access/attnum.h" 23 | #include "nodes/nodes.h" 24 | #include "nodes/primnodes.h" 25 | #include "utils/builtins.h" 26 | #include "utils/elog.h" 27 | #include "utils/errcodes.h" 28 | #include "utils/lsyscache.h" 29 | 30 | 31 | /* declarations for dynamic loading */ 32 | PG_FUNCTION_INFO_V1(partition_column_to_node_string); 33 | PG_FUNCTION_INFO_V1(column_name_to_column); 34 | PG_FUNCTION_INFO_V1(column_to_column_name); 35 | 36 | 37 | /* 38 | * partition_column_to_node_string is an internal UDF to obtain the textual 39 | * representation of a partition column node (Var), suitable for use within 40 | * CitusDB's metadata tables. This function expects an Oid identifying a table 41 | * previously distributed using pg_shard and will raise an ERROR if the Oid 42 | * is NULL, or does not identify a pg_shard-distributed table. 43 | */ 44 | Datum 45 | partition_column_to_node_string(PG_FUNCTION_ARGS) 46 | { 47 | Oid distributedTableId = InvalidOid; 48 | Var *partitionColumn = NULL; 49 | char *partitionColumnString = NULL; 50 | text *partitionColumnText = NULL; 51 | 52 | if (PG_ARGISNULL(0)) 53 | { 54 | ereport(ERROR, (errcode(ERRCODE_NULL_VALUE_NOT_ALLOWED), 55 | errmsg("table_oid must not be null"))); 56 | } 57 | 58 | distributedTableId = PG_GETARG_OID(0); 59 | partitionColumn = PartitionColumn(distributedTableId); 60 | partitionColumnString = nodeToString(partitionColumn); 61 | partitionColumnText = cstring_to_text(partitionColumnString); 62 | 63 | PG_RETURN_TEXT_P(partitionColumnText); 64 | } 65 | 66 | 67 | /* 68 | * column_name_to_column is an internal UDF to obtain a textual representation 69 | * of a particular column node (Var), given a relation identifier and column 70 | * name. There is no requirement that the table be distributed; this function 71 | * simply returns the textual representation of a Var representing a column. 72 | * This function will raise an ERROR if no such column can be found or if the 73 | * provided name refers to a system column. 74 | */ 75 | Datum 76 | column_name_to_column(PG_FUNCTION_ARGS) 77 | { 78 | Oid relationId = PG_GETARG_OID(0); 79 | text *columnText = PG_GETARG_TEXT_P(1); 80 | char *columnName = text_to_cstring(columnText); 81 | Var *column = NULL; 82 | char *columnNodeString = NULL; 83 | text *columnNodeText = NULL; 84 | 85 | column = ColumnNameToColumn(relationId, columnName); 86 | columnNodeString = nodeToString(column); 87 | columnNodeText = cstring_to_text(columnNodeString); 88 | 89 | PG_RETURN_TEXT_P(columnNodeText); 90 | } 91 | 92 | 93 | /* 94 | * column_to_column_name is an internal UDF to obtain the human-readable name 95 | * of a column given a relation identifier and the column's internal textual 96 | * (Var) representation. This function will raise an ERROR if no such column 97 | * can be found or if the provided Var refers to a system column. 98 | */ 99 | Datum 100 | column_to_column_name(PG_FUNCTION_ARGS) 101 | { 102 | Oid relationId = PG_GETARG_OID(0); 103 | text *columnNodeText = PG_GETARG_TEXT_P(1); 104 | char *columnNodeString = text_to_cstring(columnNodeText); 105 | Node *columnNode = NULL; 106 | Var *column = NULL; 107 | AttrNumber columnNumber = InvalidAttrNumber; 108 | char *columnName = NULL; 109 | text *columnText = NULL; 110 | 111 | columnNode = stringToNode(columnNodeString); 112 | 113 | Assert(IsA(columnNode, Var)); 114 | column = (Var *) columnNode; 115 | 116 | columnNumber = column->varattno; 117 | if (!AttrNumberIsForUserDefinedAttr(columnNumber)) 118 | { 119 | char *relationName = get_rel_name(relationId); 120 | 121 | ereport(ERROR, (errcode(ERRCODE_INVALID_COLUMN_REFERENCE), 122 | errmsg("attribute %d of relation \"%s\" is a system column", 123 | columnNumber, relationName))); 124 | } 125 | 126 | columnName = get_attname(relationId, column->varattno); 127 | if (columnName == NULL) 128 | { 129 | char *relationName = get_rel_name(relationId); 130 | 131 | ereport(ERROR, (errcode(ERRCODE_UNDEFINED_COLUMN), 132 | errmsg("attribute %d of relation \"%s\" does not exist", 133 | columnNumber, relationName))); 134 | } 135 | 136 | columnText = cstring_to_text(columnName); 137 | 138 | PG_RETURN_TEXT_P(columnText); 139 | } 140 | -------------------------------------------------------------------------------- /test/sql/03-extend_ddl_commands.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION extend_ddl_command(regclass, shard_id bigint, command text) 6 | RETURNS cstring 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION extend_name(name cstring, shard_id bigint) 11 | RETURNS cstring 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | 15 | -- =================================================================== 16 | -- test ddl command extension functionality 17 | -- =================================================================== 18 | 19 | -- command extension requires a valid table 20 | CREATE TABLE employees ( 21 | first_name text not null, 22 | last_name text not null, 23 | id bigint PRIMARY KEY, 24 | salary decimal default 0.00 CHECK (salary >= 0.00), 25 | start_date timestamp, 26 | resume text, 27 | mentor_id bigint UNIQUE 28 | ); 29 | 30 | -- generate a command to create a regular table on a shard 31 | SELECT extend_ddl_command('employees', 12345, 'CREATE TABLE employees (first_name ' || 32 | 'text NOT NULL, last_name text NOT NULL, id bigint NOT ' || 33 | 'NULL, salary numeric DEFAULT 0.00, start_date timestamp ' || 34 | 'without time zone, resume text, CONSTRAINT sal_check ' || 35 | 'CHECK (salary >= 0.00))'); 36 | 37 | -- generate a command to alter a column storage on a shard 38 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ALTER ' || 39 | 'COLUMN resume SET STORAGE EXTERNAL, ALTER COLUMN last_name ' || 40 | 'SET STORAGE EXTERNAL'); 41 | 42 | -- generate a command to alter a column's statistics target on a shard 43 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ALTER ' || 44 | 'COLUMN resume SET STATISTICS 500'); 45 | 46 | -- generate a command to create a simple index on a shard 47 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 48 | '(first_name)'); 49 | 50 | -- generate a command to create an index using a function call on a shard 51 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 52 | '(lower(first_name))'); 53 | 54 | -- generate a command to create an index using an expression on a shard 55 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 56 | '((first_name || '' '' || last_name))'); 57 | 58 | -- generate a command to create an compound index with special ordering on a shard 59 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 60 | '(first_name DESC NULLS FIRST, last_name ASC NULLS LAST)'); 61 | 62 | -- generate a command to create an index with specific collation on a shard 63 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 64 | '(first_name COLLATE "C")'); 65 | 66 | -- generate a command to create an index with specific options on a shard 67 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 68 | '(first_name) WITH (fillfactor = 70, fastupdate = off)'); 69 | 70 | -- generate a command to cluster a shard's table on a named index 71 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE employees CLUSTER ' || 72 | 'ON start_idx'); 73 | 74 | -- generate a command to add a unique constraint on a shard 75 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ADD ' || 76 | 'CONSTRAINT employees_mentor_id_key UNIQUE (mentor_id)'); 77 | 78 | -- generate a command to add a primary key on a shard 79 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ADD ' || 80 | 'CONSTRAINT employees_pkey PRIMARY KEY (id)'); 81 | 82 | -- generate a command to re-cluster a shard's table on a specific index 83 | SELECT extend_ddl_command('employees', 12345, 'CLUSTER employees USING start_time_idx'); 84 | 85 | -- command extension also works with foreign table creation 86 | CREATE FOREIGN TABLE telecommuters ( 87 | id bigint not null, 88 | full_name text not null default '' 89 | ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); 90 | 91 | -- generate a command to create a foreign table on a shard 92 | SELECT extend_ddl_command('telecommuters', 54321, 'CREATE FOREIGN TABLE telecommuters ' || 93 | '(id bigint, full_name text) SERVER fake_fdw_server OPTIONS ' || 94 | '(encoding ''utf-8'', compression ''true'')'); 95 | 96 | -- independently test code to append shard identifiers 97 | SELECT extend_name('base_name', 12345678); 98 | SELECT extend_name('long_long_long_relation_name_that_could_have_problems_extending', 1); 99 | SELECT extend_name('medium_relation_name_that_only_has_problems_with_large_ids', 1); 100 | SELECT extend_name('medium_relation_name_that_onlyhas_problems_with_large_ids', 12345678); 101 | 102 | -- clean up 103 | DROP FOREIGN TABLE IF EXISTS telecommuters; 104 | DROP TABLE IF EXISTS employees; 105 | -------------------------------------------------------------------------------- /test/sql/11-citus_metadata_sync.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test metadata sync functionality 3 | -- =================================================================== 4 | 5 | -- declare some variables for clarity 6 | \set finalized 1 7 | \set inactive 3 8 | 9 | -- set up a table and "distribute" it manually 10 | CREATE TABLE set_of_ids ( id bigint ); 11 | 12 | INSERT INTO pgs_distribution_metadata.shard 13 | (id, relation_id, storage, min_value, max_value) 14 | VALUES 15 | (1, 'set_of_ids'::regclass, 't', '0', '10'), 16 | (2, 'set_of_ids'::regclass, 't', '10', '20'); 17 | 18 | -- two shards, replication factor two 19 | INSERT INTO pgs_distribution_metadata.shard_placement 20 | (id, node_name, node_port, shard_id, shard_state) 21 | VALUES 22 | (101, 'cluster-worker-01', 5432, 1, :finalized), 23 | (102, 'cluster-worker-02', 5433, 2, :finalized), 24 | (103, 'cluster-worker-03', 5434, 1, :finalized), 25 | (104, 'cluster-worker-04', 5435, 2, :finalized); 26 | 27 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 28 | VALUES 29 | ('set_of_ids'::regclass, 'h', 'id'); 30 | 31 | -- should get ERROR for NULL, non-existent, or non-distributed table 32 | SELECT partition_column_to_node_string(NULL); 33 | SELECT partition_column_to_node_string(0); 34 | SELECT partition_column_to_node_string('pg_class'::regclass); 35 | 36 | -- should get node representation for distributed table 37 | SELECT partition_column_to_node_string('set_of_ids'::regclass); 38 | 39 | -- should get error for column names that are too long 40 | SELECT column_name_to_column('set_of_ids'::regclass, repeat('a', 1024)); 41 | 42 | -- should get error for system or non-existent column 43 | SELECT column_name_to_column('set_of_ids'::regclass, 'ctid'); 44 | SELECT column_name_to_column('set_of_ids'::regclass, 'non_existent'); 45 | 46 | -- should get node representation for valid column 47 | SELECT column_name_to_column('set_of_ids'::regclass, 'id') AS column_var 48 | \gset 49 | 50 | SELECT replace(:'column_var', ':varattno 1', ':varattno -1') AS ctid_var, 51 | replace(:'column_var', ':varattno 1', ':varattno 2') AS non_ext_var 52 | \gset 53 | 54 | -- should get error for system or non-existent column 55 | SELECT column_to_column_name('set_of_ids'::regclass, :'ctid_var'); 56 | SELECT column_to_column_name('set_of_ids'::regclass, :'non_ext_var'); 57 | 58 | -- should get node representation for valid column 59 | SELECT column_to_column_name('set_of_ids'::regclass, :'column_var'); 60 | 61 | -- create subset of CitusDB metadata schema 62 | CREATE TABLE pg_dist_partition ( 63 | logicalrelid oid NOT NULL, 64 | partmethod "char" NOT NULL, 65 | partkey text 66 | ); 67 | 68 | CREATE TABLE pg_dist_shard ( 69 | logicalrelid oid NOT NULL, 70 | shardid bigint NOT NULL, 71 | shardstorage "char" NOT NULL, 72 | shardalias text, 73 | shardminvalue text, 74 | shardmaxvalue text 75 | ); 76 | 77 | CREATE TABLE pg_dist_shard_placement ( 78 | shardid bigint NOT NULL, 79 | shardstate integer NOT NULL, 80 | shardlength bigint NOT NULL, 81 | nodename text, 82 | nodeport integer 83 | ) WITH OIDS; 84 | 85 | -- sync metadata and verify it has transferred 86 | SELECT sync_table_metadata_to_citus('set_of_ids'); 87 | 88 | SELECT partmethod, partkey 89 | FROM pg_dist_partition 90 | WHERE logicalrelid = 'set_of_ids'::regclass; 91 | 92 | SELECT shardid, shardstorage, shardalias, shardminvalue, shardmaxvalue 93 | FROM pg_dist_shard 94 | WHERE logicalrelid = 'set_of_ids'::regclass 95 | ORDER BY shardid; 96 | 97 | SELECT * FROM pg_dist_shard_placement 98 | WHERE shardid IN (SELECT shardid 99 | FROM pg_dist_shard 100 | WHERE logicalrelid = 'set_of_ids'::regclass) 101 | ORDER BY nodename; 102 | 103 | -- subsequent sync should have no effect 104 | SELECT sync_table_metadata_to_citus('set_of_ids'); 105 | 106 | SELECT partmethod, partkey 107 | FROM pg_dist_partition 108 | WHERE logicalrelid = 'set_of_ids'::regclass; 109 | 110 | SELECT shardid, shardstorage, shardalias, shardminvalue, shardmaxvalue 111 | FROM pg_dist_shard 112 | WHERE logicalrelid = 'set_of_ids'::regclass 113 | ORDER BY shardid; 114 | 115 | SELECT * FROM pg_dist_shard_placement 116 | WHERE shardid IN (SELECT shardid 117 | FROM pg_dist_shard 118 | WHERE logicalrelid = 'set_of_ids'::regclass) 119 | ORDER BY nodename; 120 | 121 | -- mark a placement as unhealthy and add a new one 122 | UPDATE pgs_distribution_metadata.shard_placement 123 | SET shard_state = :inactive 124 | WHERE node_name = 'cluster-worker-02'; 125 | 126 | INSERT INTO pgs_distribution_metadata.shard_placement 127 | (id, node_name, node_port, shard_id, shard_state) 128 | VALUES 129 | (105, 'cluster-worker-05', 5436, 1, :finalized); 130 | 131 | -- write latest changes to CitusDB tables 132 | SELECT sync_table_metadata_to_citus('set_of_ids'); 133 | 134 | -- should see updated state and new placement 135 | SELECT * FROM pg_dist_shard_placement 136 | WHERE shardid IN (SELECT shardid 137 | FROM pg_dist_shard 138 | WHERE logicalrelid = 'set_of_ids'::regclass) 139 | ORDER BY nodename; 140 | -------------------------------------------------------------------------------- /test/sql/13-data_types.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test composite type, varchar and enum types 3 | -- create, distribute, INSERT, SELECT and UPDATE 4 | -- =================================================================== 5 | 6 | -- create a custom type... 7 | CREATE TYPE test_composite_type AS ( 8 | i integer, 9 | i2 integer 10 | ); 11 | 12 | -- ... as well as a function to use as its comparator... 13 | CREATE FUNCTION equal_test_composite_type_function(test_composite_type, test_composite_type) RETURNS boolean 14 | AS 'select $1.i = $2.i AND $1.i2 = $2.i2;' 15 | LANGUAGE SQL 16 | IMMUTABLE 17 | RETURNS NULL ON NULL INPUT; 18 | 19 | -- ... use that function to create a custom equality operator... 20 | CREATE OPERATOR = ( 21 | LEFTARG = test_composite_type, 22 | RIGHTARG = test_composite_type, 23 | PROCEDURE = equal_test_composite_type_function, 24 | HASHES 25 | ); 26 | 27 | -- ... and create a custom operator family for hash indexes... 28 | CREATE OPERATOR FAMILY cats_op_fam USING hash; 29 | 30 | -- ... create a test HASH function. Though it is a poor hash function, 31 | -- it is acceptable for our tests 32 | CREATE FUNCTION test_composite_type_hash(test_composite_type) RETURNS int 33 | AS 'SELECT hashtext( ($1.i + $1.i2)::text);' 34 | LANGUAGE SQL 35 | IMMUTABLE 36 | RETURNS NULL ON NULL INPUT; 37 | 38 | 39 | -- We need to define two different operator classes for the composite types 40 | -- One uses BTREE the other uses HASH 41 | CREATE OPERATOR CLASS cats_op_fam_clas3 42 | DEFAULT FOR TYPE test_composite_type USING BTREE AS 43 | OPERATOR 3 = (test_composite_type, test_composite_type); 44 | 45 | CREATE OPERATOR CLASS cats_op_fam_class 46 | DEFAULT FOR TYPE test_composite_type USING HASH AS 47 | OPERATOR 1 = (test_composite_type, test_composite_type), 48 | FUNCTION 1 test_composite_type_hash(test_composite_type); 49 | 50 | -- create and distribute a table on composite type column 51 | CREATE TABLE composite_type_partitioned_table 52 | ( 53 | id integer, 54 | col test_composite_type 55 | ); 56 | 57 | SELECT master_create_distributed_table('composite_type_partitioned_table', 'col'); 58 | 59 | -- squelch noisy warnings when creating shards 60 | \set VERBOSITY terse 61 | SELECT master_create_worker_shards('composite_type_partitioned_table', 4, 1); 62 | \set VERBOSITY default 63 | 64 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 65 | INSERT INTO composite_type_partitioned_table VALUES (1, '(1, 2)'::test_composite_type); 66 | INSERT INTO composite_type_partitioned_table VALUES (2, '(3, 4)'::test_composite_type); 67 | INSERT INTO composite_type_partitioned_table VALUES (3, '(5, 6)'::test_composite_type); 68 | INSERT INTO composite_type_partitioned_table VALUES (4, '(7, 8)'::test_composite_type); 69 | INSERT INTO composite_type_partitioned_table VALUES (5, '(9, 10)'::test_composite_type); 70 | 71 | SELECT * FROM composite_type_partitioned_table WHERE col = '(7, 8)'::test_composite_type; 72 | 73 | UPDATE composite_type_partitioned_table SET id = 6 WHERE col = '(7, 8)'::test_composite_type; 74 | 75 | SELECT * FROM composite_type_partitioned_table WHERE col = '(7, 8)'::test_composite_type; 76 | 77 | 78 | -- create and distribute a table on enum type column 79 | CREATE TYPE bug_status AS ENUM ('new', 'open', 'closed'); 80 | 81 | CREATE TABLE bugs ( 82 | id integer, 83 | status bug_status 84 | ); 85 | 86 | SELECT master_create_distributed_table('bugs', 'status'); 87 | 88 | -- squelch noisy warnings when creating shards 89 | \set VERBOSITY terse 90 | SELECT master_create_worker_shards('bugs', 4, 1); 91 | \set VERBOSITY default 92 | 93 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 94 | INSERT INTO bugs VALUES (1, 'new'); 95 | INSERT INTO bugs VALUES (2, 'open'); 96 | INSERT INTO bugs VALUES (3, 'closed'); 97 | INSERT INTO bugs VALUES (4, 'closed'); 98 | INSERT INTO bugs VALUES (5, 'open'); 99 | 100 | SELECT * FROM bugs WHERE status = 'closed'::bug_status; 101 | 102 | UPDATE bugs SET status = 'closed'::bug_status WHERE id = 2; 103 | 104 | SELECT * FROM bugs WHERE status = 'open'::bug_status; 105 | 106 | -- create and distribute a table on varchar column 107 | CREATE TABLE varchar_partitioned_table 108 | ( 109 | id int, 110 | name varchar 111 | ); 112 | 113 | SELECT master_create_distributed_table('varchar_partitioned_table', 'c1'); 114 | SELECT master_create_worker_shards('varchar_partitioned_table', 4, 1); 115 | 116 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 117 | INSERT INTO varchar_partitioned_table VALUES (1, 'Jason'); 118 | INSERT INTO varchar_partitioned_table VALUES (2, 'Ozgun'); 119 | INSERT INTO varchar_partitioned_table VALUES (3, 'Onder'); 120 | INSERT INTO varchar_partitioned_table VALUES (4, 'Sumedh'); 121 | INSERT INTO varchar_partitioned_table VALUES (5, 'Marco'); 122 | 123 | SELECT * FROM varchar_partitioned_table WHERE name = 'Onder'; 124 | 125 | UPDATE varchar_partitioned_table SET name = 'Samay' WHERE id = 5; 126 | 127 | SELECT * FROM varchar_partitioned_table WHERE name = 'Samay'; -------------------------------------------------------------------------------- /bin/copy_to_distributed_table: -------------------------------------------------------------------------------- 1 | #!/usr/bin/env bash 2 | 3 | # make bash behave 4 | set -euo pipefail 5 | IFS=$'\n\t' 6 | 7 | # constants 8 | stdout=1 9 | stderr=2 10 | success=0 11 | badusage=64 12 | noinput=66 13 | 14 | # default values for certain options 15 | format='text' 16 | schema='public' 17 | 18 | # we'll append to this string to build options list 19 | options='OIDS false, FREEZE false' 20 | 21 | # outputs usage message on specified device before exiting with provided status 22 | usage() { 23 | cat << 'E_O_USAGE' >&"$1" 24 | usage: copy_to_distributed_table [-BCTHh] [-c encoding] [-d delimiter] 25 | [-e escape] [-n null] [-q quote] [-s schema] filename tablename 26 | 27 | B : use binary format for input 28 | C : use CSV format for input 29 | T : use text format for input 30 | H : specifies file contains header line to be ignored 31 | h : print this help message 32 | 33 | c : specifies file is encoded using `encoding` 34 | Default: the current client encoding 35 | d : specifies the character used to separate columns 36 | Default: a tab character in text format, a comma in CSV format 37 | e : specifies the character used to escape quotes 38 | Default: the same as the `quote` value (quotes within data are doubled) 39 | n : specifies the string that represents a null value 40 | Default: \N in text format, an unquoted empty string in CSV format 41 | q : specifies the quoting character to be used when a data value is quoted 42 | Default: double-quote 43 | s : specifies the schema in which the target table resides 44 | Default: 'public' 45 | 46 | copy_to_distributed_table outputs the total number of rows successfully copied 47 | to the distributed table, counted from the beginning of the input file. 48 | E_O_USAGE 49 | 50 | exit $2; 51 | } 52 | 53 | # process flags 54 | while getopts ':BCc:d:e:Hhn:q:s:T' o; do 55 | case "${o}" in 56 | B) 57 | format='binary' 58 | ;; 59 | C) 60 | format='csv' 61 | ;; 62 | c) 63 | encoding=`echo ${OPTARG} | sed s/\'/\'\'/g` 64 | options="${options}, ENCODING '${encoding}'" 65 | ;; 66 | d) 67 | delimiter=`echo ${OPTARG} | sed s/\'/\'\'/g` 68 | options="${options}, DELIMITER '${delimiter}'" 69 | ;; 70 | e) 71 | escape=`echo ${OPTARG} | sed s/\'/\'\'/g` 72 | options="${options}, ESCAPE '${escape}'" 73 | ;; 74 | H) 75 | options="${options}, HEADER true" 76 | ;; 77 | h) 78 | usage $stdout $success 79 | ;; 80 | n) 81 | null=`echo ${OPTARG} | sed s/\'/\'\'/g` 82 | options="${options}, NULL '${null}'" 83 | ;; 84 | q) 85 | quote=`echo ${OPTARG} | sed s/\'/\'\'/g` 86 | options="${options}, QUOTE '${quote}'" 87 | ;; 88 | s) 89 | # we'll escape schema in psql itself 90 | schema=${OPTARG} 91 | ;; 92 | T) 93 | format='text' 94 | ;; 95 | *) 96 | echo "$0: illegal option -- ${OPTARG}" >&2 97 | usage $stderr $badusage 98 | ;; 99 | esac 100 | done 101 | shift $((OPTIND-1)) 102 | 103 | if [ "$#" -ne 2 ]; then 104 | usage $stderr $badusage 105 | fi 106 | 107 | # append format to options and extract file/table names 108 | options="${options}, FORMAT ${format}" 109 | filename=$1 110 | tablename=$2 111 | 112 | # validate inputs 113 | if [ -d "${filename}" ]; then 114 | echo "$0: ${filename}: Is a directory" >&2 115 | exit $noinput 116 | elif [ ! -e "${filename}" ]; then 117 | echo "$0: ${filename}: No such file" >&2 118 | exit $noinput 119 | elif [ ! -r "${filename}" ]; then 120 | echo "$0: ${filename}: Permission denied" >&2 121 | exit $noinput 122 | fi 123 | 124 | # invoke psql, ignoring .psqlrc and passing the following heredoc 125 | psql -X -vtable="${tablename}" -vfile="${filename}" \ 126 | -vschema="${schema}" -voptions="${options}" << 'E_O_SQL' 127 | -- only print values, left-align them, and don't rollback or stop on error 128 | \set QUIET on 129 | \set ON_ERROR_ROLLBACK off 130 | \pset format unaligned 131 | \pset tuples_only on 132 | \set ON_ERROR_STOP on 133 | 134 | -- squelch all output until COPY completes 135 | \o /dev/null 136 | 137 | -- Use a session-bound counter to keep track of the number of rows inserted: we 138 | -- can't roll back so we need to tell the user how many rows were inserted. Due 139 | -- to the trigger implementation, the COPY will report zero rows, so we count 140 | -- them manually for a better experience. 141 | CREATE TEMPORARY SEQUENCE rows_inserted MINVALUE 0 CACHE 100000; 142 | 143 | -- initialize counter to zero 144 | SELECT nextval('rows_inserted'); 145 | 146 | -- get qualified table name 147 | SELECT format('%I.%I', :'schema', :'table') AS target 148 | \gset 149 | 150 | -- create insert proxy and save name; pass in sequence 151 | SELECT create_insert_proxy_for_table(:'target', 'rows_inserted') AS proxy 152 | \gset 153 | 154 | -- don't stop if copy errors out: continue to print file name and row count 155 | \set ON_ERROR_STOP off 156 | 157 | -- \copy doesn't allow variable substitution, so do it ourselves... 158 | SELECT format('\copy pg_temp.%I from %L with (%s)', 159 | :'proxy', :'file', :'options') AS copy_cmd 160 | \gset 161 | 162 | -- ... then execute the result 163 | :copy_cmd 164 | 165 | -- reconnect STDOUT to display row count 166 | \o 167 | 168 | SELECT currval('rows_inserted'); 169 | E_O_SQL 170 | -------------------------------------------------------------------------------- /test/src/fake_fdw.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/fake_fdw.c 4 | * 5 | * This file contains a barebones FDW implementation, suitable for use in 6 | * test code. Inspired by Andrew Dunstan's blackhole_fdw. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 18 | 19 | #include 20 | 21 | #include "executor/tuptable.h" 22 | #include "foreign/fdwapi.h" 23 | #include "nodes/execnodes.h" 24 | #include "nodes/nodes.h" 25 | #include "nodes/pg_list.h" 26 | #include "nodes/plannodes.h" 27 | #include "nodes/relation.h" 28 | #include "optimizer/pathnode.h" 29 | #include "optimizer/planmain.h" 30 | #include "optimizer/restrictinfo.h" 31 | #include "utils/palloc.h" 32 | 33 | /* local function forward declarations */ 34 | static void FakeGetForeignRelSize(PlannerInfo *root, RelOptInfo *baserel, 35 | Oid foreigntableid); 36 | static void FakeGetForeignPaths(PlannerInfo *root, RelOptInfo *baserel, 37 | Oid foreigntableid); 38 | #if (PG_VERSION_NUM >= 90300 && PG_VERSION_NUM < 90500) 39 | static ForeignScan * FakeGetForeignPlan(PlannerInfo *root, RelOptInfo *baserel, 40 | Oid foreigntableid, ForeignPath *best_path, 41 | List *tlist, List *scan_clauses); 42 | #else 43 | static ForeignScan * FakeGetForeignPlan(PlannerInfo *root, RelOptInfo *baserel, 44 | Oid foreigntableid, ForeignPath *best_path, 45 | List *tlist, List *scan_clauses, 46 | Plan *outer_plan); 47 | #endif 48 | static void FakeBeginForeignScan(ForeignScanState *node, int eflags); 49 | static TupleTableSlot * FakeIterateForeignScan(ForeignScanState *node); 50 | static void FakeReScanForeignScan(ForeignScanState *node); 51 | static void FakeEndForeignScan(ForeignScanState *node); 52 | 53 | 54 | /* declarations for dynamic loading */ 55 | PG_FUNCTION_INFO_V1(fake_fdw_handler); 56 | 57 | 58 | /* 59 | * fake_fdw_handler populates an FdwRoutine with pointers to the functions 60 | * implemented within this file. 61 | */ 62 | Datum 63 | fake_fdw_handler(PG_FUNCTION_ARGS) 64 | { 65 | FdwRoutine *fdwroutine = makeNode(FdwRoutine); 66 | 67 | fdwroutine->GetForeignRelSize = FakeGetForeignRelSize; 68 | fdwroutine->GetForeignPaths = FakeGetForeignPaths; 69 | fdwroutine->GetForeignPlan = FakeGetForeignPlan; 70 | fdwroutine->BeginForeignScan = FakeBeginForeignScan; 71 | fdwroutine->IterateForeignScan = FakeIterateForeignScan; 72 | fdwroutine->ReScanForeignScan = FakeReScanForeignScan; 73 | fdwroutine->EndForeignScan = FakeEndForeignScan; 74 | 75 | PG_RETURN_POINTER(fdwroutine); 76 | } 77 | 78 | 79 | /* 80 | * FakeGetForeignRelSize populates baserel with a fake relation size. 81 | */ 82 | static void 83 | FakeGetForeignRelSize(PlannerInfo *root, RelOptInfo *baserel, Oid foreigntableid) 84 | { 85 | baserel->rows = 0; 86 | baserel->fdw_private = (void *) palloc0(1); 87 | } 88 | 89 | 90 | /* 91 | * FakeGetForeignPaths adds a single fake foreign path to baserel. 92 | */ 93 | static void 94 | FakeGetForeignPaths(PlannerInfo *root, RelOptInfo *baserel, Oid foreigntableid) 95 | { 96 | Cost startup_cost = 0; 97 | Cost total_cost = startup_cost + baserel->rows; 98 | 99 | #if (PG_VERSION_NUM >= 90300 && PG_VERSION_NUM < 90500) 100 | add_path(baserel, (Path *) create_foreignscan_path(root, baserel, baserel->rows, 101 | startup_cost, total_cost, NIL, 102 | NULL, NIL)); 103 | #else 104 | add_path(baserel, (Path *) create_foreignscan_path(root, baserel, baserel->rows, 105 | startup_cost, total_cost, NIL, 106 | NULL, NULL, NIL)); 107 | #endif 108 | } 109 | 110 | 111 | /* 112 | * FakeGetForeignPlan builds a fake foreign plan. 113 | */ 114 | #if (PG_VERSION_NUM >= 90300 && PG_VERSION_NUM < 90500) 115 | static ForeignScan * 116 | FakeGetForeignPlan(PlannerInfo *root, RelOptInfo *baserel, Oid foreigntableid, 117 | ForeignPath *best_path, List *tlist, List *scan_clauses) 118 | #else 119 | static ForeignScan * 120 | FakeGetForeignPlan(PlannerInfo *root, RelOptInfo *baserel, Oid foreigntableid, 121 | ForeignPath *best_path, List *tlist, List *scan_clauses, 122 | Plan *outer_plan) 123 | #endif 124 | { 125 | Index scan_relid = baserel->relid; 126 | scan_clauses = extract_actual_clauses(scan_clauses, false); 127 | 128 | /* make_foreignscan has a different signature in 9.3 and 9.4 than in 9.5 */ 129 | #if (PG_VERSION_NUM >= 90300 && PG_VERSION_NUM < 90500) 130 | return make_foreignscan(tlist, scan_clauses, scan_relid, NIL, NIL); 131 | #else 132 | return make_foreignscan(tlist, scan_clauses, scan_relid, NIL, NIL, NIL, NIL, 133 | outer_plan); 134 | #endif 135 | } 136 | 137 | 138 | /* 139 | * FakeBeginForeignScan begins the fake plan (i.e. does nothing). 140 | */ 141 | static void 142 | FakeBeginForeignScan(ForeignScanState *node, int eflags) { } 143 | 144 | 145 | /* 146 | * FakeIterateForeignScan continues the fake plan (i.e. does nothing). 147 | */ 148 | static TupleTableSlot * 149 | FakeIterateForeignScan(ForeignScanState *node) 150 | { 151 | TupleTableSlot *slot = node->ss.ss_ScanTupleSlot; 152 | ExecClearTuple(slot); 153 | 154 | return slot; 155 | } 156 | 157 | 158 | /* 159 | * FakeReScanForeignScan restarts the fake plan (i.e. does nothing). 160 | */ 161 | static void 162 | FakeReScanForeignScan(ForeignScanState *node) { } 163 | 164 | 165 | /* 166 | * FakeEndForeignScan ends the fake plan (i.e. does nothing). 167 | */ 168 | static void 169 | FakeEndForeignScan(ForeignScanState *node) { } 170 | -------------------------------------------------------------------------------- /include/distribution_metadata.h: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * include/distribution_metadata.h 4 | * 5 | * Declarations for public functions and types related to metadata handling. 6 | * 7 | * Copyright (c) 2014-2015, Citus Data, Inc. 8 | * 9 | *------------------------------------------------------------------------- 10 | */ 11 | 12 | #ifndef PG_SHARD_DISTRIBUTION_METADATA_H 13 | #define PG_SHARD_DISTRIBUTION_METADATA_H 14 | 15 | #include "postgres.h" 16 | #include "c.h" 17 | 18 | #include "nodes/pg_list.h" 19 | #include "nodes/primnodes.h" 20 | #include "storage/lock.h" 21 | 22 | 23 | /* query prefix (target list and joins) for shard interval information */ 24 | #define SHARD_QUERY_PREFIX "SELECT s.id, s.relation_id, s.min_value, s.max_value, " \ 25 | "p.partition_method, p.key " \ 26 | "FROM pgs_distribution_metadata.shard AS s " \ 27 | "JOIN pgs_distribution_metadata.partition AS p " \ 28 | "ON s.relation_id = p.relation_id" 29 | 30 | /* denotes storage type of the underlying shard */ 31 | #define SHARD_STORAGE_TABLE 't' 32 | #define SHARD_STORAGE_FOREIGN 'f' 33 | 34 | /* human-readable names for addressing columns of shard queries */ 35 | #define TLIST_NUM_SHARD_ID 1 36 | #define TLIST_NUM_SHARD_RELATION_ID 2 37 | #define TLIST_NUM_SHARD_MIN_VALUE 3 38 | #define TLIST_NUM_SHARD_MAX_VALUE 4 39 | #define TLIST_NUM_SHARD_PARTITION_METHOD 5 40 | #define TLIST_NUM_SHARD_KEY 6 41 | 42 | #define SHARD_PLACEMENT_QUERY "SELECT id, shard_id, shard_state, node_name, node_port " \ 43 | "FROM pgs_distribution_metadata.shard_placement " \ 44 | "WHERE shard_id = $1" 45 | 46 | /* human-readable names for addressing columns of shard placement queries */ 47 | #define TLIST_NUM_SHARD_PLACEMENT_ID 1 48 | #define TLIST_NUM_SHARD_PLACEMENT_SHARD_ID 2 49 | #define TLIST_NUM_SHARD_PLACEMENT_SHARD_STATE 3 50 | #define TLIST_NUM_SHARD_PLACEMENT_NODE_NAME 4 51 | #define TLIST_NUM_SHARD_PLACEMENT_NODE_PORT 5 52 | 53 | /* denotes partition type of the distributed table */ 54 | #define APPEND_PARTITION_TYPE 'a' 55 | #define HASH_PARTITION_TYPE 'h' 56 | #define RANGE_PARTITION_TYPE 'r' 57 | 58 | 59 | /* ShardState represents the last known state of a shard on a given node */ 60 | typedef enum 61 | { 62 | STATE_INVALID_FIRST = 0, 63 | STATE_FINALIZED = 1, 64 | STATE_CACHED = 2, 65 | STATE_INACTIVE = 3, 66 | STATE_TO_DELETE = 4 67 | } ShardState; 68 | 69 | 70 | /* 71 | * ShardInterval contains information about a particular shard in a distributed 72 | * table. ShardIntervals have a unique identifier, a reference back to the table 73 | * they distribute, and min and max values for the partition column of rows that 74 | * are contained within the shard (this range is inclusive). 75 | * 76 | * All fields are required. 77 | */ 78 | typedef struct ShardInterval 79 | { 80 | int64 id; /* unique identifier for the shard */ 81 | Oid relationId; /* id of the shard's distributed table */ 82 | Datum minValue; /* a shard's typed min value datum */ 83 | Datum maxValue; /* a shard's typed max value datum */ 84 | Oid valueTypeId; /* typeId for minValue and maxValue Datums */ 85 | } ShardInterval; 86 | 87 | 88 | /* 89 | * ShardPlacement represents information about the placement of a shard in a 90 | * distributed table. ShardPlacements have a unique identifier, a reference to 91 | * the shard they place, a textual hostname to identify the host on which the 92 | * shard resides, and a port number to use when connecting to that host. 93 | * 94 | * All fields are required. 95 | */ 96 | typedef struct ShardPlacement 97 | { 98 | int64 id; /* unique identifier for the shard placement */ 99 | int64 shardId; /* identifies shard for this shard placement */ 100 | ShardState shardState; /* represents last known state of this placement */ 101 | char *nodeName; /* hostname of machine hosting this shard */ 102 | int32 nodePort; /* port number for connecting to host */ 103 | } ShardPlacement; 104 | 105 | 106 | /* 107 | * ShardIntervalListCacheEntry contains the information for a cache entry in 108 | * shard interval list cache entry. 109 | */ 110 | typedef struct ShardIntervalListCacheEntry 111 | { 112 | Oid distributedTableId; /* cache key */ 113 | List *shardIntervalList; 114 | } ShardIntervalListCacheEntry; 115 | 116 | 117 | /* 118 | * ShardLockType specifies the kinds of locks that can be acquired for a given 119 | * shard, i.e. one to change data in that shard or a lock to change placements 120 | * of the shard itself (the shard's metadata). 121 | */ 122 | typedef enum 123 | { 124 | SHARD_LOCK_INVALID_FIRST = 0, 125 | SHARD_LOCK_DATA = 3, 126 | SHARD_LOCK_METADATA = 4 127 | } ShardLockType; 128 | 129 | /* function declarations to access and manipulate the metadata */ 130 | extern List * LookupShardIntervalList(Oid distributedTableId); 131 | extern List * LoadShardIntervalList(Oid distributedTableId); 132 | extern ShardInterval * LoadShardInterval(int64 shardId); 133 | extern List * LoadFinalizedShardPlacementList(int64 shardId); 134 | extern List * LoadShardPlacementList(int64 shardId); 135 | extern Var * PartitionColumn(Oid distributedTableId); 136 | extern char PartitionType(Oid distributedTableId); 137 | extern bool IsDistributedTable(Oid tableId); 138 | extern bool DistributedTablesExist(void); 139 | extern Var * ColumnNameToColumn(Oid relationId, char *columnName); 140 | extern void InsertPartitionRow(Oid distributedTableId, char partitionType, 141 | text *partitionKeyText); 142 | extern int64 CreateShardRow(Oid distributedTableId, char shardStorage, 143 | text *shardMinValue, text *shardMaxValue); 144 | extern int64 CreateShardPlacementRow(int64 shardId, ShardState shardState, 145 | char *nodeName, uint32 nodePort); 146 | extern void DeleteShardPlacementRow(int64 shardPlacementId); 147 | extern void UpdateShardPlacementRowState(int64 shardPlacementId, ShardState newState); 148 | extern void LockShardData(int64 shardId, LOCKMODE lockMode); 149 | extern void LockShardDistributionMetadata(int64 shardId, LOCKMODE lockMode); 150 | extern void LockRelationDistributionMetadata(Oid relationId, LOCKMODE lockMode); 151 | 152 | #endif /* PG_SHARD_DISTRIBUTION_METADATA_H */ 153 | -------------------------------------------------------------------------------- /test/expected/13-data_types.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test composite type, varchar and enum types 3 | -- create, distribute, INSERT, SELECT and UPDATE 4 | -- =================================================================== 5 | -- create a custom type... 6 | CREATE TYPE test_composite_type AS ( 7 | i integer, 8 | i2 integer 9 | ); 10 | -- ... as well as a function to use as its comparator... 11 | CREATE FUNCTION equal_test_composite_type_function(test_composite_type, test_composite_type) RETURNS boolean 12 | AS 'select $1.i = $2.i AND $1.i2 = $2.i2;' 13 | LANGUAGE SQL 14 | IMMUTABLE 15 | RETURNS NULL ON NULL INPUT; 16 | -- ... use that function to create a custom equality operator... 17 | CREATE OPERATOR = ( 18 | LEFTARG = test_composite_type, 19 | RIGHTARG = test_composite_type, 20 | PROCEDURE = equal_test_composite_type_function, 21 | HASHES 22 | ); 23 | -- ... and create a custom operator family for hash indexes... 24 | CREATE OPERATOR FAMILY cats_op_fam USING hash; 25 | -- ... create a test HASH function. Though it is a poor hash function, 26 | -- it is acceptable for our tests 27 | CREATE FUNCTION test_composite_type_hash(test_composite_type) RETURNS int 28 | AS 'SELECT hashtext( ($1.i + $1.i2)::text);' 29 | LANGUAGE SQL 30 | IMMUTABLE 31 | RETURNS NULL ON NULL INPUT; 32 | -- We need to define two different operator classes for the composite types 33 | -- One uses BTREE the other uses HASH 34 | CREATE OPERATOR CLASS cats_op_fam_clas3 35 | DEFAULT FOR TYPE test_composite_type USING BTREE AS 36 | OPERATOR 3 = (test_composite_type, test_composite_type); 37 | CREATE OPERATOR CLASS cats_op_fam_class 38 | DEFAULT FOR TYPE test_composite_type USING HASH AS 39 | OPERATOR 1 = (test_composite_type, test_composite_type), 40 | FUNCTION 1 test_composite_type_hash(test_composite_type); 41 | -- create and distribute a table on composite type column 42 | CREATE TABLE composite_type_partitioned_table 43 | ( 44 | id integer, 45 | col test_composite_type 46 | ); 47 | SELECT master_create_distributed_table('composite_type_partitioned_table', 'col'); 48 | master_create_distributed_table 49 | --------------------------------- 50 | 51 | (1 row) 52 | 53 | -- squelch noisy warnings when creating shards 54 | \set VERBOSITY terse 55 | SELECT master_create_worker_shards('composite_type_partitioned_table', 4, 1); 56 | WARNING: Connection failed to adeadhost:5432 57 | WARNING: could not create shard on "adeadhost:5432" 58 | WARNING: Connection failed to adeadhost:5432 59 | WARNING: could not create shard on "adeadhost:5432" 60 | master_create_worker_shards 61 | ----------------------------- 62 | 63 | (1 row) 64 | 65 | \set VERBOSITY default 66 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 67 | INSERT INTO composite_type_partitioned_table VALUES (1, '(1, 2)'::test_composite_type); 68 | INSERT INTO composite_type_partitioned_table VALUES (2, '(3, 4)'::test_composite_type); 69 | INSERT INTO composite_type_partitioned_table VALUES (3, '(5, 6)'::test_composite_type); 70 | INSERT INTO composite_type_partitioned_table VALUES (4, '(7, 8)'::test_composite_type); 71 | INSERT INTO composite_type_partitioned_table VALUES (5, '(9, 10)'::test_composite_type); 72 | SELECT * FROM composite_type_partitioned_table WHERE col = '(7, 8)'::test_composite_type; 73 | id | col 74 | ----+------- 75 | 4 | (7,8) 76 | (1 row) 77 | 78 | UPDATE composite_type_partitioned_table SET id = 6 WHERE col = '(7, 8)'::test_composite_type; 79 | SELECT * FROM composite_type_partitioned_table WHERE col = '(7, 8)'::test_composite_type; 80 | id | col 81 | ----+------- 82 | 6 | (7,8) 83 | (1 row) 84 | 85 | -- create and distribute a table on enum type column 86 | CREATE TYPE bug_status AS ENUM ('new', 'open', 'closed'); 87 | CREATE TABLE bugs ( 88 | id integer, 89 | status bug_status 90 | ); 91 | SELECT master_create_distributed_table('bugs', 'status'); 92 | master_create_distributed_table 93 | --------------------------------- 94 | 95 | (1 row) 96 | 97 | -- squelch noisy warnings when creating shards 98 | \set VERBOSITY terse 99 | SELECT master_create_worker_shards('bugs', 4, 1); 100 | WARNING: Connection failed to adeadhost:5432 101 | WARNING: could not create shard on "adeadhost:5432" 102 | WARNING: Connection failed to adeadhost:5432 103 | WARNING: could not create shard on "adeadhost:5432" 104 | master_create_worker_shards 105 | ----------------------------- 106 | 107 | (1 row) 108 | 109 | \set VERBOSITY default 110 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 111 | INSERT INTO bugs VALUES (1, 'new'); 112 | INSERT INTO bugs VALUES (2, 'open'); 113 | INSERT INTO bugs VALUES (3, 'closed'); 114 | INSERT INTO bugs VALUES (4, 'closed'); 115 | INSERT INTO bugs VALUES (5, 'open'); 116 | SELECT * FROM bugs WHERE status = 'closed'::bug_status; 117 | id | status 118 | ----+-------- 119 | 3 | closed 120 | 4 | closed 121 | (2 rows) 122 | 123 | UPDATE bugs SET status = 'closed'::bug_status WHERE id = 2; 124 | ERROR: modifying the partition value of rows is not allowed 125 | SELECT * FROM bugs WHERE status = 'open'::bug_status; 126 | id | status 127 | ----+-------- 128 | 2 | open 129 | 5 | open 130 | (2 rows) 131 | 132 | -- create and distribute a table on varchar column 133 | CREATE TABLE varchar_partitioned_table 134 | ( 135 | id int, 136 | name varchar 137 | ); 138 | SELECT master_create_distributed_table('varchar_partitioned_table', 'c1'); 139 | ERROR: column "c1" of relation "varchar_partitioned_table" does not exist 140 | SELECT master_create_worker_shards('varchar_partitioned_table', 4, 1); 141 | ERROR: no partition column is defined for relation "varchar_partitioned_table" 142 | -- execute INSERT, SELECT and UPDATE queries on composite_type_partitioned_table 143 | INSERT INTO varchar_partitioned_table VALUES (1, 'Jason'); 144 | INSERT INTO varchar_partitioned_table VALUES (2, 'Ozgun'); 145 | INSERT INTO varchar_partitioned_table VALUES (3, 'Onder'); 146 | INSERT INTO varchar_partitioned_table VALUES (4, 'Sumedh'); 147 | INSERT INTO varchar_partitioned_table VALUES (5, 'Marco'); 148 | SELECT * FROM varchar_partitioned_table WHERE name = 'Onder'; 149 | id | name 150 | ----+------- 151 | 3 | Onder 152 | (1 row) 153 | 154 | UPDATE varchar_partitioned_table SET name = 'Samay' WHERE id = 5; 155 | SELECT * FROM varchar_partitioned_table WHERE name = 'Samay'; 156 | id | name 157 | ----+------- 158 | 5 | Samay 159 | (1 row) 160 | 161 | -------------------------------------------------------------------------------- /test/sql/05-create_shards.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions and types needed for tests 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION sort_names(cstring, cstring, cstring) 6 | RETURNS cstring 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION create_table_then_fail(cstring, integer) 11 | RETURNS bool 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | 15 | -- create a custom type... 16 | CREATE TYPE dummy_type AS ( 17 | i integer 18 | ); 19 | 20 | -- ... as well as a function to use as its comparator... 21 | CREATE FUNCTION dummy_type_function(dummy_type, dummy_type) RETURNS boolean 22 | AS 'SELECT TRUE;' 23 | LANGUAGE SQL 24 | IMMUTABLE 25 | RETURNS NULL ON NULL INPUT; 26 | 27 | -- ... use that function to create a custom operator... 28 | CREATE OPERATOR = ( 29 | LEFTARG = dummy_type, 30 | RIGHTARG = dummy_type, 31 | PROCEDURE = dummy_type_function 32 | ); 33 | 34 | -- ... and create a custom operator family for hash indexes... 35 | CREATE OPERATOR FAMILY dummy_op_family USING hash; 36 | 37 | -- ... finally, build an operator class, designate it as the default operator 38 | -- class for the type, but only specify an equality operator. So the type will 39 | -- have a default op class but no hash operator in that class. 40 | CREATE OPERATOR CLASS dummy_op_family_class 41 | DEFAULT FOR TYPE dummy_type USING hash FAMILY dummy_op_family AS 42 | OPERATOR 1 =; 43 | 44 | -- =================================================================== 45 | -- test shard creation functionality 46 | -- =================================================================== 47 | 48 | CREATE TABLE table_to_distribute ( 49 | name text, 50 | id bigint PRIMARY KEY, 51 | json_data json, 52 | test_type_data dummy_type 53 | ); 54 | 55 | -- use an index instead of table name 56 | SELECT master_create_distributed_table('table_to_distribute_pkey', 'id'); 57 | 58 | -- use a bad column name 59 | SELECT master_create_distributed_table('table_to_distribute', 'bad_column'); 60 | 61 | -- use unsupported partition type 62 | SELECT master_create_distributed_table('table_to_distribute', 'name', 'r'); 63 | 64 | -- use unrecognized partition type 65 | SELECT master_create_distributed_table('table_to_distribute', 'name', 'z'); 66 | 67 | -- use a partition column of a type lacking any default operator class 68 | SELECT master_create_distributed_table('table_to_distribute', 'json_data'); 69 | 70 | -- use a partition column of type lacking the required support function (hash) 71 | SELECT master_create_distributed_table('table_to_distribute', 'test_type_data'); 72 | 73 | -- distribute table and inspect side effects 74 | SELECT master_create_distributed_table('table_to_distribute', 'name'); 75 | SELECT partition_method, key FROM pgs_distribution_metadata.partition 76 | WHERE relation_id = 'table_to_distribute'::regclass; 77 | 78 | -- use a bad shard count 79 | SELECT master_create_worker_shards('table_to_distribute', 0, 1); 80 | 81 | -- use a bad replication factor 82 | SELECT master_create_worker_shards('table_to_distribute', 16, 0); 83 | 84 | -- use a replication factor higher than shard count 85 | SELECT master_create_worker_shards('table_to_distribute', 16, 3); 86 | 87 | \set VERBOSITY terse 88 | 89 | -- use a replication factor higher than healthy node count 90 | -- this will create a shard on the healthy node but fail right after 91 | SELECT master_create_worker_shards('table_to_distribute', 16, 2); 92 | 93 | -- finally, create shards and inspect metadata 94 | SELECT master_create_worker_shards('table_to_distribute', 16, 1); 95 | 96 | \set VERBOSITY default 97 | 98 | SELECT storage, min_value, max_value FROM pgs_distribution_metadata.shard 99 | WHERE relation_id = 'table_to_distribute'::regclass 100 | ORDER BY (min_value::integer) ASC; 101 | 102 | -- all shards should have the same size (16 divides evenly into the hash space) 103 | SELECT count(*) AS shard_count, 104 | max_value::integer - min_value::integer AS shard_size 105 | FROM pgs_distribution_metadata.shard 106 | WHERE relation_id='table_to_distribute'::regclass 107 | GROUP BY shard_size; 108 | 109 | -- all shards should be on a single node 110 | WITH unique_nodes AS ( 111 | SELECT DISTINCT ON (node_name, node_port) node_name, node_port 112 | FROM pgs_distribution_metadata.shard_placement, pgs_distribution_metadata.shard 113 | WHERE shard_placement.shard_id = shard.id 114 | ) 115 | SELECT COUNT(*) FROM unique_nodes; 116 | 117 | SELECT COUNT(*) FROM pg_class WHERE relname LIKE 'table_to_distribute%' AND relkind = 'r'; 118 | 119 | -- try to create them again 120 | SELECT master_create_worker_shards('table_to_distribute', 16, 1); 121 | 122 | -- test list sorting 123 | SELECT sort_names('sumedh', 'jason', 'ozgun'); 124 | 125 | -- squelch WARNINGs that contain worker_port 126 | SET client_min_messages TO ERROR; 127 | 128 | -- test remote command execution 129 | SELECT create_table_then_fail('localhost', :worker_port); 130 | 131 | SET client_min_messages TO DEFAULT; 132 | 133 | SELECT COUNT(*) FROM pg_class WHERE relname LIKE 'throwaway%' AND relkind = 'r'; 134 | 135 | \set VERBOSITY terse 136 | 137 | -- test foreign table creation 138 | CREATE FOREIGN TABLE foreign_table_to_distribute 139 | ( 140 | name text, 141 | id bigint 142 | ) 143 | SERVER fake_fdw_server; 144 | 145 | SELECT master_create_distributed_table('foreign_table_to_distribute', 'id'); 146 | SELECT master_create_worker_shards('foreign_table_to_distribute', 16, 1); 147 | 148 | \set VERBOSITY default 149 | SELECT storage, min_value, max_value FROM pgs_distribution_metadata.shard 150 | WHERE relation_id = 'foreign_table_to_distribute'::regclass 151 | ORDER BY (min_value::integer) ASC; 152 | 153 | -- test shard creation using weird shard count 154 | CREATE TABLE weird_shard_count 155 | ( 156 | name text, 157 | id bigint 158 | ); 159 | 160 | \set VERBOSITY terse 161 | 162 | SELECT master_create_distributed_table('weird_shard_count', 'id'); 163 | SELECT master_create_worker_shards('weird_shard_count', 7, 1); 164 | 165 | \set VERBOSITY default 166 | 167 | -- pg_shard ensures all shards are roughly the same size 168 | SELECT max_value::integer - min_value::integer AS shard_size 169 | FROM pgs_distribution_metadata.shard 170 | WHERE relation_id = 'weird_shard_count'::regclass 171 | ORDER BY min_value::integer ASC; 172 | 173 | -- cleanup foreign table, related shards and shard placements 174 | DELETE FROM pgs_distribution_metadata.shard_placement 175 | WHERE shard_id IN (SELECT shard_id FROM pgs_distribution_metadata.shard 176 | WHERE relation_id = 'foreign_table_to_distribute'::regclass); 177 | 178 | DELETE FROM pgs_distribution_metadata.shard 179 | WHERE relation_id = 'foreign_table_to_distribute'::regclass; 180 | 181 | DELETE FROM pgs_distribution_metadata.partition 182 | WHERE relation_id = 'foreign_table_to_distribute'::regclass; 183 | -------------------------------------------------------------------------------- /test/src/prune_shard_list.c: -------------------------------------------------------------------------------- 1 | /*------------------------------------------------------------------------- 2 | * 3 | * test/src/create_shards.c 4 | * 5 | * This file contains functions to exercise shard creation functionality 6 | * within pg_shard. 7 | * 8 | * Copyright (c) 2014-2015, Citus Data, Inc. 9 | * 10 | *------------------------------------------------------------------------- 11 | */ 12 | 13 | #include "postgres.h" 14 | #include "c.h" 15 | #include "fmgr.h" 16 | 17 | #include "distribution_metadata.h" 18 | #include "prune_shard_list.h" 19 | #include "test_helper_functions.h" /* IWYU pragma: keep */ 20 | 21 | #include 22 | 23 | #if (PG_VERSION_NUM >= 90500 && PG_VERSION_NUM < 90600) 24 | #include "access/stratnum.h" 25 | #else 26 | #include "access/skey.h" 27 | #endif 28 | #include "catalog/pg_type.h" 29 | #include "nodes/pg_list.h" 30 | #include "nodes/primnodes.h" 31 | #include "nodes/nodes.h" 32 | #include "optimizer/clauses.h" 33 | #include "utils/array.h" 34 | #include "utils/palloc.h" 35 | 36 | 37 | /* local function forward declarations */ 38 | static Expr * MakeTextPartitionExpression(Oid distributedTableId, text *value); 39 | static ArrayType * PrunedShardIdsForTable(Oid distributedTableId, List *whereClauseList); 40 | 41 | 42 | /* declarations for dynamic loading */ 43 | PG_FUNCTION_INFO_V1(prune_using_no_values); 44 | PG_FUNCTION_INFO_V1(prune_using_single_value); 45 | PG_FUNCTION_INFO_V1(prune_using_either_value); 46 | PG_FUNCTION_INFO_V1(prune_using_both_values); 47 | PG_FUNCTION_INFO_V1(debug_equality_expression); 48 | 49 | 50 | /* 51 | * prune_using_no_values returns the shards for the specified distributed table 52 | * after pruning using an empty clause list. 53 | */ 54 | Datum 55 | prune_using_no_values(PG_FUNCTION_ARGS) 56 | { 57 | Oid distributedTableId = PG_GETARG_OID(0); 58 | List *whereClauseList = NIL; 59 | ArrayType *shardIdArrayType = PrunedShardIdsForTable(distributedTableId, 60 | whereClauseList); 61 | 62 | PG_RETURN_ARRAYTYPE_P(shardIdArrayType); 63 | } 64 | 65 | 66 | /* 67 | * prune_using_single_value returns the shards for the specified distributed 68 | * table after pruning using a single value provided by the caller. 69 | */ 70 | Datum 71 | prune_using_single_value(PG_FUNCTION_ARGS) 72 | { 73 | Oid distributedTableId = PG_GETARG_OID(0); 74 | text *value = (PG_ARGISNULL(1)) ? NULL : PG_GETARG_TEXT_P(1); 75 | Expr *equalityExpr = MakeTextPartitionExpression(distributedTableId, value); 76 | List *whereClauseList = list_make1(equalityExpr); 77 | ArrayType *shardIdArrayType = PrunedShardIdsForTable(distributedTableId, 78 | whereClauseList); 79 | 80 | PG_RETURN_ARRAYTYPE_P(shardIdArrayType); 81 | } 82 | 83 | 84 | /* 85 | * prune_using_either_value returns the shards for the specified distributed 86 | * table after pruning using either of two values provided by the caller (OR). 87 | */ 88 | Datum 89 | prune_using_either_value(PG_FUNCTION_ARGS) 90 | { 91 | Oid distributedTableId = PG_GETARG_OID(0); 92 | text *firstValue = PG_GETARG_TEXT_P(1); 93 | text *secondValue = PG_GETARG_TEXT_P(2); 94 | Expr *firstQual = MakeTextPartitionExpression(distributedTableId, firstValue); 95 | Expr *secondQual = MakeTextPartitionExpression(distributedTableId, secondValue); 96 | Expr *orClause = make_orclause(list_make2(firstQual, secondQual)); 97 | List *whereClauseList = list_make1(orClause); 98 | ArrayType *shardIdArrayType = PrunedShardIdsForTable(distributedTableId, 99 | whereClauseList); 100 | 101 | PG_RETURN_ARRAYTYPE_P(shardIdArrayType); 102 | } 103 | 104 | 105 | /* 106 | * prune_using_both_values returns the shards for the specified distributed 107 | * table after pruning using both of the values provided by the caller (AND). 108 | */ 109 | Datum 110 | prune_using_both_values(PG_FUNCTION_ARGS) 111 | { 112 | Oid distributedTableId = PG_GETARG_OID(0); 113 | text *firstValue = PG_GETARG_TEXT_P(1); 114 | text *secondValue = PG_GETARG_TEXT_P(2); 115 | Expr *firstQual = MakeTextPartitionExpression(distributedTableId, firstValue); 116 | Expr *secondQual = MakeTextPartitionExpression(distributedTableId, secondValue); 117 | 118 | List *whereClauseList = list_make2(firstQual, secondQual); 119 | ArrayType *shardIdArrayType = PrunedShardIdsForTable(distributedTableId, 120 | whereClauseList); 121 | 122 | PG_RETURN_ARRAYTYPE_P(shardIdArrayType); 123 | } 124 | 125 | 126 | /* 127 | * debug_equality_expression returns the textual representation of an equality 128 | * expression generated by a call to MakeOpExpression. 129 | */ 130 | Datum 131 | debug_equality_expression(PG_FUNCTION_ARGS) 132 | { 133 | Oid distributedTableId = PG_GETARG_OID(0); 134 | Var *partitionColumn = PartitionColumn(distributedTableId); 135 | OpExpr *equalityExpression = MakeOpExpression(partitionColumn, BTEqualStrategyNumber); 136 | 137 | PG_RETURN_CSTRING(nodeToString(equalityExpression)); 138 | } 139 | 140 | 141 | /* 142 | * MakeTextPartitionExpression returns an equality expression between the 143 | * specified table's partition column and the provided values. 144 | */ 145 | static Expr * 146 | MakeTextPartitionExpression(Oid distributedTableId, text *value) 147 | { 148 | Var *partitionColumn = PartitionColumn(distributedTableId); 149 | Expr *partitionExpression = NULL; 150 | 151 | if (value != NULL) 152 | { 153 | OpExpr *equalityExpr = MakeOpExpression(partitionColumn, BTEqualStrategyNumber); 154 | Const *rightConst = (Const *) get_rightop((Expr *) equalityExpr); 155 | 156 | rightConst->constvalue = (Datum) value; 157 | rightConst->constisnull = false; 158 | rightConst->constbyval = false; 159 | 160 | partitionExpression = (Expr *) equalityExpr; 161 | } 162 | else 163 | { 164 | NullTest *nullTest = makeNode(NullTest); 165 | nullTest->arg = (Expr *) partitionColumn; 166 | nullTest->nulltesttype = IS_NULL; 167 | 168 | partitionExpression = (Expr *) nullTest; 169 | } 170 | 171 | return partitionExpression; 172 | } 173 | 174 | 175 | /* 176 | * PrunedShardIdsForTable loads the shard intervals for the specified table, 177 | * prunes them using the provided clauses. It returns an ArrayType containing 178 | * the shard identifiers, suitable for return from an SQL-facing function. 179 | */ 180 | static ArrayType * 181 | PrunedShardIdsForTable(Oid distributedTableId, List *whereClauseList) 182 | { 183 | ArrayType *shardIdArrayType = NULL; 184 | ListCell *shardCell = NULL; 185 | int shardIdIndex = 0; 186 | Oid shardIdTypeId = INT8OID; 187 | 188 | List *shardList = LoadShardIntervalList(distributedTableId); 189 | int shardIdCount = -1; 190 | Datum *shardIdDatumArray = NULL; 191 | 192 | shardList = PruneShardList(distributedTableId, whereClauseList, shardList); 193 | 194 | shardIdCount = list_length(shardList); 195 | shardIdDatumArray = palloc0(shardIdCount * sizeof(Datum)); 196 | 197 | foreach(shardCell, shardList) 198 | { 199 | ShardInterval *shardId = (ShardInterval *) lfirst(shardCell); 200 | Datum shardIdDatum = Int64GetDatum(shardId->id); 201 | 202 | shardIdDatumArray[shardIdIndex] = shardIdDatum; 203 | shardIdIndex++; 204 | } 205 | 206 | shardIdArrayType = DatumArrayToArrayType(shardIdDatumArray, shardIdCount, 207 | shardIdTypeId); 208 | 209 | return shardIdArrayType; 210 | } 211 | -------------------------------------------------------------------------------- /updates/pg_shard--1.0--1.1.sql: -------------------------------------------------------------------------------- 1 | CREATE FUNCTION partition_column_to_node_string(table_oid oid) 2 | RETURNS text 3 | AS 'MODULE_PATHNAME' 4 | LANGUAGE C; 5 | 6 | COMMENT ON FUNCTION partition_column_to_node_string(oid) 7 | IS 'return textual form of distributed table''s partition column'; 8 | 9 | -- Syncs rows from the pg_shard distribution metadata related to the specified 10 | -- table name into the metadata tables used by CitusDB. After a call to this 11 | -- function for a particular pg_shard table, that table will become usable for 12 | -- queries within CitusDB. If placement health has changed for given pg_shard 13 | -- table, calling this function an additional time will propagate those health 14 | -- changes to the CitusDB metadata tables. 15 | CREATE FUNCTION sync_table_metadata_to_citus(table_name text) 16 | RETURNS void 17 | AS $sync_table_metadata_to_citus$ 18 | DECLARE 19 | table_relation_id CONSTANT oid NOT NULL := table_name::regclass::oid; 20 | dummy_shard_length CONSTANT bigint := 0; 21 | BEGIN 22 | -- grab lock to ensure single writer for upsert 23 | LOCK TABLE pg_dist_shard_placement IN EXCLUSIVE MODE; 24 | 25 | -- First, update the health of shard placement rows already copied 26 | -- from pg_shard to CitusDB. Health is the only mutable attribute, 27 | -- so it is presently the only one needing the UPDATE treatment. 28 | UPDATE pg_dist_shard_placement 29 | SET shardstate = shard_placement.shard_state 30 | FROM pgs_distribution_metadata.shard_placement 31 | WHERE shardid = shard_placement.shard_id AND 32 | nodename = shard_placement.node_name AND 33 | nodeport = shard_placement.node_port AND 34 | shardid IN (SELECT shardid 35 | FROM pg_dist_shard 36 | WHERE logicalrelid = table_relation_id); 37 | 38 | -- copy pg_shard placement rows not yet in CitusDB's metadata tables 39 | INSERT INTO pg_dist_shard_placement 40 | (shardid, 41 | shardstate, 42 | shardlength, 43 | nodename, 44 | nodeport) 45 | SELECT shard_id, 46 | shard_state, 47 | dummy_shard_length, 48 | node_name, 49 | node_port 50 | FROM pgs_distribution_metadata.shard_placement 51 | LEFT OUTER JOIN pg_dist_shard_placement 52 | ON ( shardid = shard_placement.shard_id AND 53 | nodename = shard_placement.node_name AND 54 | nodeport = shard_placement.node_port ) 55 | WHERE shardid IS NULL AND 56 | shard_id IN (SELECT id 57 | FROM pgs_distribution_metadata.shard 58 | WHERE relation_id = table_relation_id); 59 | 60 | -- copy pg_shard shard rows not yet in CitusDB's metadata tables 61 | INSERT INTO pg_dist_shard 62 | (shardid, 63 | logicalrelid, 64 | shardstorage, 65 | shardminvalue, 66 | shardmaxvalue) 67 | SELECT id, 68 | relation_id, 69 | storage, 70 | min_value, 71 | max_value 72 | FROM pgs_distribution_metadata.shard 73 | LEFT OUTER JOIN pg_dist_shard 74 | ON ( shardid = shard.id ) 75 | WHERE shardid IS NULL AND 76 | relation_id = table_relation_id; 77 | 78 | -- Finally, copy pg_shard partition rows not yet in CitusDB's metadata 79 | -- tables. CitusDB uses a textual form of a Var node representing the 80 | -- partition column, so we must use a special function to transform the 81 | -- representation used by pg_shard (which is just the column name). 82 | INSERT INTO pg_dist_partition 83 | (logicalrelid, 84 | partmethod, 85 | partkey) 86 | SELECT relation_id, 87 | partition_method, 88 | partition_column_to_node_string(table_relation_id) 89 | FROM pgs_distribution_metadata.partition 90 | LEFT OUTER JOIN pg_dist_partition 91 | ON ( logicalrelid = partition.relation_id ) 92 | WHERE logicalrelid IS NULL AND 93 | relation_id = table_relation_id; 94 | END; 95 | $sync_table_metadata_to_citus$ LANGUAGE 'plpgsql'; 96 | 97 | COMMENT ON FUNCTION sync_table_metadata_to_citus(text) 98 | IS 'synchronize a distributed table''s pg_shard metadata to CitusDB'; 99 | 100 | -- Creates a temporary table exactly like the specified target table along with 101 | -- a trigger to redirect any INSERTed rows from the proxy to the underlying 102 | -- table. Users may optionally provide a sequence which will be incremented 103 | -- after each row that has been successfully proxied (useful for counting rows 104 | -- processed). Returns the name of the proxy table that was created. 105 | CREATE FUNCTION create_insert_proxy_for_table(target_table regclass, 106 | sequence regclass DEFAULT NULL) 107 | RETURNS text 108 | AS $create_insert_proxy_for_table$ 109 | DECLARE 110 | temp_table_name text; 111 | attr_names text[]; 112 | attr_list text; 113 | param_list text; 114 | using_list text; 115 | insert_command text; 116 | -- templates to create dynamic functions, tables, and triggers 117 | func_tmpl CONSTANT text := $$CREATE FUNCTION pg_temp.copy_to_insert() 118 | RETURNS trigger 119 | AS $copy_to_insert$ 120 | BEGIN 121 | EXECUTE %L USING %s; 122 | PERFORM nextval(%L); 123 | RETURN NULL; 124 | END; 125 | $copy_to_insert$ LANGUAGE plpgsql;$$; 126 | table_tmpl CONSTANT text := $$CREATE TEMPORARY TABLE %I 127 | (LIKE %s INCLUDING DEFAULTS)$$; 128 | trigger_tmpl CONSTANT text := $$CREATE TRIGGER copy_to_insert 129 | BEFORE INSERT ON %s FOR EACH ROW 130 | EXECUTE PROCEDURE pg_temp.copy_to_insert()$$; 131 | BEGIN 132 | -- create name of temporary table using unqualified input table name 133 | SELECT format('%s_insert_proxy', relname) 134 | INTO STRICT temp_table_name 135 | FROM pg_class 136 | WHERE oid = target_table; 137 | 138 | -- get list of all attributes in table, we'll need shortly 139 | SELECT array_agg(attname) 140 | INTO STRICT attr_names 141 | FROM pg_attribute 142 | WHERE attrelid = target_table AND 143 | attnum > 0 AND 144 | NOT attisdropped; 145 | 146 | -- build fully specified column list and USING clause from attr. names 147 | SELECT string_agg(quote_ident(attr_name), ','), 148 | string_agg(format('NEW.%I', attr_name), ',') 149 | INTO STRICT attr_list, 150 | using_list 151 | FROM unnest(attr_names) AS attr_name; 152 | 153 | -- build ($1, $2, $3)-style VALUE list to bind parameters 154 | SELECT string_agg('$' || param_num, ',') 155 | INTO STRICT param_list 156 | FROM generate_series(1, array_length(attr_names, 1)) AS param_num; 157 | 158 | -- use the above lists to generate appropriate INSERT command 159 | insert_command = format('INSERT INTO %s (%s) VALUES (%s)', target_table, 160 | attr_list, param_list); 161 | 162 | -- use the command to make one-off trigger targeting specified table 163 | EXECUTE format(func_tmpl, insert_command, using_list, sequence); 164 | 165 | -- create a temporary table exactly like the target table... 166 | EXECUTE format(table_tmpl, temp_table_name, target_table); 167 | 168 | -- ... and install the trigger on that temporary table 169 | EXECUTE format(trigger_tmpl, quote_ident(temp_table_name)::regclass); 170 | 171 | RETURN temp_table_name; 172 | END; 173 | $create_insert_proxy_for_table$ LANGUAGE plpgsql SET search_path = 'pg_catalog'; 174 | 175 | COMMENT ON FUNCTION create_insert_proxy_for_table(regclass, regclass) 176 | IS 'create a proxy table that redirects INSERTed rows to a target table'; 177 | -------------------------------------------------------------------------------- /test/sql/08-modifications.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test end-to-end modification functionality 3 | -- =================================================================== 4 | 5 | CREATE TYPE order_side AS ENUM ('buy', 'sell'); 6 | 7 | CREATE TABLE limit_orders ( 8 | id bigint PRIMARY KEY, 9 | symbol text NOT NULL, 10 | bidder_id bigint NOT NULL, 11 | placed_at timestamp NOT NULL, 12 | kind order_side NOT NULL, 13 | limit_price decimal NOT NULL DEFAULT 0.00 CHECK (limit_price >= 0.00) 14 | ); 15 | 16 | CREATE TABLE insufficient_shards ( LIKE limit_orders ); 17 | 18 | SELECT master_create_distributed_table('limit_orders', 'id'); 19 | SELECT master_create_distributed_table('insufficient_shards', 'id'); 20 | 21 | \set VERBOSITY terse 22 | SELECT master_create_worker_shards('limit_orders', 2, 1); 23 | 24 | -- make a single shard that covers no partition values 25 | SELECT master_create_worker_shards('insufficient_shards', 1, 1); 26 | UPDATE pgs_distribution_metadata.shard SET min_value = 0, max_value = 0 27 | WHERE relation_id = 'insufficient_shards'::regclass; 28 | \set VERBOSITY default 29 | 30 | -- basic single-row INSERT 31 | INSERT INTO limit_orders VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 32 | 20.69); 33 | SELECT COUNT(*) FROM limit_orders WHERE id = 32743; 34 | 35 | -- try a single-row INSERT with no shard to receive it 36 | INSERT INTO insufficient_shards VALUES (32743, 'AAPL', 9580, '2004-10-19 10:23:54', 'buy', 37 | 20.69); 38 | 39 | -- INSERT with DEFAULT in the target list 40 | INSERT INTO limit_orders VALUES (12756, 'MSFT', 10959, '2013-05-08 07:29:23', 'sell', 41 | DEFAULT); 42 | SELECT COUNT(*) FROM limit_orders WHERE id = 12756; 43 | 44 | -- INSERT with expressions in target list 45 | INSERT INTO limit_orders VALUES (430, upper('ibm'), 214, timestamp '2003-01-28 10:31:17' + 46 | interval '5 hours', 'buy', sqrt(2)); 47 | SELECT COUNT(*) FROM limit_orders WHERE id = 430; 48 | 49 | -- INSERT without partition key 50 | INSERT INTO limit_orders DEFAULT VALUES; 51 | 52 | -- squelch WARNINGs that contain worker_port 53 | SET client_min_messages TO ERROR; 54 | 55 | -- INSERT violating NOT NULL constraint 56 | INSERT INTO limit_orders VALUES (NULL, 'T', 975234, DEFAULT); 57 | 58 | -- INSERT violating column constraint 59 | INSERT INTO limit_orders VALUES (18811, 'BUD', 14962, '2014-04-05 08:32:16', 'sell', 60 | -5.00); 61 | 62 | -- INSERT violating primary key constraint 63 | INSERT INTO limit_orders VALUES (32743, 'LUV', 5994, '2001-04-16 03:37:28', 'buy', 0.58); 64 | 65 | SET client_min_messages TO DEFAULT; 66 | 67 | -- commands with non-constant partition values are unsupported 68 | INSERT INTO limit_orders VALUES (random() * 100, 'ORCL', 152, '2011-08-25 11:50:45', 69 | 'sell', 0.58); 70 | 71 | -- commands with expressions that cannot be collapsed are unsupported 72 | INSERT INTO limit_orders VALUES (2036, 'GOOG', 5634, now(), 'buy', random()); 73 | 74 | -- commands with mutable functions in their quals 75 | DELETE FROM limit_orders WHERE id = 246 AND bidder_id = (random() * 1000); 76 | 77 | -- commands with mutable but non-volatilte functions(ie: stable func.) in their quals 78 | DELETE FROM limit_orders WHERE id = 246 AND placed_at = current_timestamp; 79 | 80 | -- commands with multiple rows are unsupported 81 | INSERT INTO limit_orders VALUES (DEFAULT), (DEFAULT); 82 | 83 | -- INSERT ... SELECT ... FROM commands are unsupported 84 | INSERT INTO limit_orders SELECT * FROM limit_orders; 85 | 86 | -- commands with a RETURNING clause are unsupported 87 | INSERT INTO limit_orders VALUES (7285, 'AMZN', 3278, '2016-01-05 02:07:36', 'sell', 0.00) 88 | RETURNING *; 89 | 90 | -- commands containing a CTE are unsupported 91 | WITH deleted_orders AS (DELETE FROM limit_orders RETURNING *) 92 | INSERT INTO limit_orders DEFAULT VALUES; 93 | 94 | -- test simple DELETE 95 | INSERT INTO limit_orders VALUES (246, 'TSLA', 162, '2007-07-02 16:32:15', 'sell', 20.69); 96 | SELECT COUNT(*) FROM limit_orders WHERE id = 246; 97 | 98 | DELETE FROM limit_orders WHERE id = 246; 99 | SELECT COUNT(*) FROM limit_orders WHERE id = 246; 100 | 101 | -- DELETE with expression in WHERE clause 102 | INSERT INTO limit_orders VALUES (246, 'TSLA', 162, '2007-07-02 16:32:15', 'sell', 20.69); 103 | SELECT COUNT(*) FROM limit_orders WHERE id = 246; 104 | 105 | DELETE FROM limit_orders WHERE id = (2 * 123); 106 | SELECT COUNT(*) FROM limit_orders WHERE id = 246; 107 | 108 | -- commands with no constraints on the partition key are not supported 109 | DELETE FROM limit_orders WHERE bidder_id = 162; 110 | 111 | -- commands with a USING clause are unsupported 112 | CREATE TABLE bidders ( name text, id bigint ); 113 | DELETE FROM limit_orders USING bidders WHERE limit_orders.id = 246 AND 114 | limit_orders.bidder_id = bidders.id AND 115 | bidders.name = 'Bernie Madoff'; 116 | 117 | -- commands with a RETURNING clause are unsupported 118 | DELETE FROM limit_orders WHERE id = 246 RETURNING *; 119 | 120 | -- commands containing a CTE are unsupported 121 | WITH deleted_orders AS (INSERT INTO limit_orders DEFAULT VALUES RETURNING *) 122 | DELETE FROM limit_orders; 123 | 124 | -- cursors are not supported 125 | DELETE FROM limit_orders WHERE CURRENT OF cursor_name; 126 | 127 | INSERT INTO limit_orders VALUES (246, 'TSLA', 162, '2007-07-02 16:32:15', 'sell', 20.69); 128 | 129 | -- simple UPDATE 130 | UPDATE limit_orders SET symbol = 'GM' WHERE id = 246; 131 | SELECT symbol FROM limit_orders WHERE id = 246; 132 | 133 | -- expression UPDATE 134 | UPDATE limit_orders SET bidder_id = 6 * 3 WHERE id = 246; 135 | SELECT bidder_id FROM limit_orders WHERE id = 246; 136 | 137 | -- multi-column UPDATE 138 | UPDATE limit_orders SET (kind, limit_price) = ('buy', DEFAULT) WHERE id = 246; 139 | SELECT kind, limit_price FROM limit_orders WHERE id = 246; 140 | 141 | -- First: Duplicate placements but use a bad hostname 142 | -- Next: Issue a modification. It will hit a bad placement 143 | -- Last: Verify that the unreachable placement was marked unhealthy 144 | WITH limit_order_placements AS ( 145 | SELECT sp.* 146 | FROM pgs_distribution_metadata.shard_placement AS sp, 147 | pgs_distribution_metadata.shard AS s 148 | WHERE sp.shard_id = s.id 149 | AND s.relation_id = 'limit_orders'::regclass 150 | ) 151 | INSERT INTO pgs_distribution_metadata.shard_placement 152 | (shard_id, 153 | shard_state, 154 | node_name, 155 | node_port) 156 | SELECT shard_id, 157 | shard_state, 158 | 'badhost', 159 | 54321 160 | FROM limit_order_placements; 161 | 162 | \set VERBOSITY terse 163 | INSERT INTO limit_orders VALUES (275, 'ADR', 140, '2007-07-02 16:32:15', 'sell', 43.67); 164 | \set VERBOSITY default 165 | 166 | SELECT count(*) 167 | FROM pgs_distribution_metadata.shard_placement AS sp, 168 | pgs_distribution_metadata.shard AS s 169 | WHERE sp.shard_id = s.id 170 | AND sp.node_name = 'badhost' 171 | AND sp.shard_state = 3 172 | AND s.relation_id = 'limit_orders'::regclass; 173 | 174 | -- commands with no constraints on the partition key are not supported 175 | UPDATE limit_orders SET limit_price = 0.00; 176 | 177 | -- attempting to change the partition key is unsupported 178 | UPDATE limit_orders SET id = 0 WHERE id = 246; 179 | 180 | -- UPDATEs with a FROM clause are unsupported 181 | UPDATE limit_orders SET limit_price = 0.00 FROM bidders 182 | WHERE limit_orders.id = 246 AND 183 | limit_orders.bidder_id = bidders.id AND 184 | bidders.name = 'Bernie Madoff'; 185 | 186 | -- commands with a RETURNING clause are unsupported 187 | UPDATE limit_orders SET symbol = 'GM' WHERE id = 246 RETURNING *; 188 | 189 | -- commands containing a CTE are unsupported 190 | WITH deleted_orders AS (INSERT INTO limit_orders DEFAULT VALUES RETURNING *) 191 | UPDATE limit_orders SET symbol = 'GM'; 192 | 193 | -- cursors are not supported 194 | UPDATE limit_orders SET symbol = 'GM' WHERE CURRENT OF cursor_name; 195 | -------------------------------------------------------------------------------- /LICENSE: -------------------------------------------------------------------------------- 1 | GNU LESSER GENERAL PUBLIC LICENSE 2 | Version 3, 29 June 2007 3 | 4 | Copyright (C) 2007 Free Software Foundation, Inc. 5 | Everyone is permitted to copy and distribute verbatim copies 6 | of this license document, but changing it is not allowed. 7 | 8 | 9 | This version of the GNU Lesser General Public License incorporates 10 | the terms and conditions of version 3 of the GNU General Public 11 | License, supplemented by the additional permissions listed below. 12 | 13 | 0. Additional Definitions. 14 | 15 | As used herein, "this License" refers to version 3 of the GNU Lesser 16 | General Public License, and the "GNU GPL" refers to version 3 of the GNU 17 | General Public License. 18 | 19 | "The Library" refers to a covered work governed by this License, 20 | other than an Application or a Combined Work as defined below. 21 | 22 | An "Application" is any work that makes use of an interface provided 23 | by the Library, but which is not otherwise based on the Library. 24 | Defining a subclass of a class defined by the Library is deemed a mode 25 | of using an interface provided by the Library. 26 | 27 | A "Combined Work" is a work produced by combining or linking an 28 | Application with the Library. The particular version of the Library 29 | with which the Combined Work was made is also called the "Linked 30 | Version". 31 | 32 | The "Minimal Corresponding Source" for a Combined Work means the 33 | Corresponding Source for the Combined Work, excluding any source code 34 | for portions of the Combined Work that, considered in isolation, are 35 | based on the Application, and not on the Linked Version. 36 | 37 | The "Corresponding Application Code" for a Combined Work means the 38 | object code and/or source code for the Application, including any data 39 | and utility programs needed for reproducing the Combined Work from the 40 | Application, but excluding the System Libraries of the Combined Work. 41 | 42 | 1. Exception to Section 3 of the GNU GPL. 43 | 44 | You may convey a covered work under sections 3 and 4 of this License 45 | without being bound by section 3 of the GNU GPL. 46 | 47 | 2. Conveying Modified Versions. 48 | 49 | If you modify a copy of the Library, and, in your modifications, a 50 | facility refers to a function or data to be supplied by an Application 51 | that uses the facility (other than as an argument passed when the 52 | facility is invoked), then you may convey a copy of the modified 53 | version: 54 | 55 | a) under this License, provided that you make a good faith effort to 56 | ensure that, in the event an Application does not supply the 57 | function or data, the facility still operates, and performs 58 | whatever part of its purpose remains meaningful, or 59 | 60 | b) under the GNU GPL, with none of the additional permissions of 61 | this License applicable to that copy. 62 | 63 | 3. Object Code Incorporating Material from Library Header Files. 64 | 65 | The object code form of an Application may incorporate material from 66 | a header file that is part of the Library. You may convey such object 67 | code under terms of your choice, provided that, if the incorporated 68 | material is not limited to numerical parameters, data structure 69 | layouts and accessors, or small macros, inline functions and templates 70 | (ten or fewer lines in length), you do both of the following: 71 | 72 | a) Give prominent notice with each copy of the object code that the 73 | Library is used in it and that the Library and its use are 74 | covered by this License. 75 | 76 | b) Accompany the object code with a copy of the GNU GPL and this license 77 | document. 78 | 79 | 4. Combined Works. 80 | 81 | You may convey a Combined Work under terms of your choice that, 82 | taken together, effectively do not restrict modification of the 83 | portions of the Library contained in the Combined Work and reverse 84 | engineering for debugging such modifications, if you also do each of 85 | the following: 86 | 87 | a) Give prominent notice with each copy of the Combined Work that 88 | the Library is used in it and that the Library and its use are 89 | covered by this License. 90 | 91 | b) Accompany the Combined Work with a copy of the GNU GPL and this license 92 | document. 93 | 94 | c) For a Combined Work that displays copyright notices during 95 | execution, include the copyright notice for the Library among 96 | these notices, as well as a reference directing the user to the 97 | copies of the GNU GPL and this license document. 98 | 99 | d) Do one of the following: 100 | 101 | 0) Convey the Minimal Corresponding Source under the terms of this 102 | License, and the Corresponding Application Code in a form 103 | suitable for, and under terms that permit, the user to 104 | recombine or relink the Application with a modified version of 105 | the Linked Version to produce a modified Combined Work, in the 106 | manner specified by section 6 of the GNU GPL for conveying 107 | Corresponding Source. 108 | 109 | 1) Use a suitable shared library mechanism for linking with the 110 | Library. A suitable mechanism is one that (a) uses at run time 111 | a copy of the Library already present on the user's computer 112 | system, and (b) will operate properly with a modified version 113 | of the Library that is interface-compatible with the Linked 114 | Version. 115 | 116 | e) Provide Installation Information, but only if you would otherwise 117 | be required to provide such information under section 6 of the 118 | GNU GPL, and only to the extent that such information is 119 | necessary to install and execute a modified version of the 120 | Combined Work produced by recombining or relinking the 121 | Application with a modified version of the Linked Version. (If 122 | you use option 4d0, the Installation Information must accompany 123 | the Minimal Corresponding Source and Corresponding Application 124 | Code. If you use option 4d1, you must provide the Installation 125 | Information in the manner specified by section 6 of the GNU GPL 126 | for conveying Corresponding Source.) 127 | 128 | 5. Combined Libraries. 129 | 130 | You may place library facilities that are a work based on the 131 | Library side by side in a single library together with other library 132 | facilities that are not Applications and are not covered by this 133 | License, and convey such a combined library under terms of your 134 | choice, if you do both of the following: 135 | 136 | a) Accompany the combined library with a copy of the same work based 137 | on the Library, uncombined with any other library facilities, 138 | conveyed under the terms of this License. 139 | 140 | b) Give prominent notice with the combined library that part of it 141 | is a work based on the Library, and explaining where to find the 142 | accompanying uncombined form of the same work. 143 | 144 | 6. Revised Versions of the GNU Lesser General Public License. 145 | 146 | The Free Software Foundation may publish revised and/or new versions 147 | of the GNU Lesser General Public License from time to time. Such new 148 | versions will be similar in spirit to the present version, but may 149 | differ in detail to address new problems or concerns. 150 | 151 | Each version is given a distinguishing version number. If the 152 | Library as you received it specifies that a certain numbered version 153 | of the GNU Lesser General Public License "or any later version" 154 | applies to it, you have the option of following the terms and 155 | conditions either of that published version or of any later version 156 | published by the Free Software Foundation. If the Library as you 157 | received it does not specify a version number of the GNU Lesser 158 | General Public License, you may choose any version of the GNU Lesser 159 | General Public License ever published by the Free Software Foundation. 160 | 161 | If the Library as you received it specifies that a proxy can decide 162 | whether future versions of the GNU Lesser General Public License shall 163 | apply, that proxy's public statement of acceptance of any version is 164 | permanent authorization for you to choose that version for the 165 | Library. 166 | -------------------------------------------------------------------------------- /test/sql/02-distribution_metadata.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | 5 | CREATE FUNCTION load_shard_id_array(regclass, bool) 6 | RETURNS bigint[] 7 | AS 'pg_shard' 8 | LANGUAGE C STRICT; 9 | 10 | CREATE FUNCTION load_shard_interval_array(bigint, anyelement) 11 | RETURNS anyarray 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | 15 | CREATE FUNCTION load_shard_placement_array(bigint, bool) 16 | RETURNS text[] 17 | AS 'pg_shard' 18 | LANGUAGE C STRICT; 19 | 20 | CREATE FUNCTION partition_column_id(regclass) 21 | RETURNS smallint 22 | AS 'pg_shard' 23 | LANGUAGE C STRICT; 24 | 25 | CREATE FUNCTION partition_type(regclass) 26 | RETURNS "char" 27 | AS 'pg_shard' 28 | LANGUAGE C STRICT; 29 | 30 | CREATE FUNCTION is_distributed_table(regclass) 31 | RETURNS boolean 32 | AS 'pg_shard' 33 | LANGUAGE C STRICT; 34 | 35 | CREATE FUNCTION distributed_tables_exist() 36 | RETURNS boolean 37 | AS 'pg_shard' 38 | LANGUAGE C STRICT; 39 | 40 | CREATE FUNCTION column_name_to_column_id(regclass, cstring) 41 | RETURNS smallint 42 | AS 'pg_shard' 43 | LANGUAGE C STRICT; 44 | 45 | CREATE FUNCTION insert_hash_partition_row(regclass, text) 46 | RETURNS void 47 | AS 'pg_shard' 48 | LANGUAGE C STRICT; 49 | 50 | CREATE FUNCTION create_monolithic_shard_row(regclass) 51 | RETURNS bigint 52 | AS 'pg_shard' 53 | LANGUAGE C STRICT; 54 | 55 | CREATE FUNCTION create_healthy_local_shard_placement_row(bigint) 56 | RETURNS bigint 57 | AS 'pg_shard' 58 | LANGUAGE C STRICT; 59 | 60 | CREATE FUNCTION delete_shard_placement_row(bigint) 61 | RETURNS bool 62 | AS 'pg_shard' 63 | LANGUAGE C STRICT; 64 | 65 | CREATE FUNCTION update_shard_placement_row_state(bigint, int) 66 | RETURNS bool 67 | AS 'pg_shard' 68 | LANGUAGE C STRICT; 69 | 70 | CREATE FUNCTION acquire_shared_shard_lock(bigint) 71 | RETURNS void 72 | AS 'pg_shard' 73 | LANGUAGE C STRICT; 74 | 75 | -- =================================================================== 76 | -- test distribution metadata functionality 77 | -- =================================================================== 78 | 79 | -- create table to be distributed 80 | CREATE TABLE events ( 81 | id bigint, 82 | name text 83 | ); 84 | 85 | -- before distribution, should return, but not cache, an empty list 86 | SELECT load_shard_id_array('events', true); 87 | 88 | -- for this table we'll "distribute" manually but verify using function calls 89 | INSERT INTO pgs_distribution_metadata.shard 90 | (id, relation_id, storage, min_value, max_value) 91 | VALUES 92 | (1, 'events'::regclass, 't', '0', '10'), 93 | (2, 'events'::regclass, 't', '10', '20'), 94 | (3, 'events'::regclass, 't', '20', '30'), 95 | (4, 'events'::regclass, 't', '30', '40'); 96 | 97 | INSERT INTO pgs_distribution_metadata.shard_placement 98 | (id, node_name, node_port, shard_id, shard_state) 99 | VALUES 100 | (101, 'cluster-worker-01', 5432, 1, 0), 101 | (102, 'cluster-worker-01', 5432, 2, 0), 102 | (103, 'cluster-worker-02', 5433, 3, 0), 103 | (104, 'cluster-worker-02', 5433, 4, 0), 104 | (105, 'cluster-worker-03', 5434, 1, 1), 105 | (106, 'cluster-worker-03', 5434, 2, 1), 106 | (107, 'cluster-worker-04', 5435, 3, 1), 107 | (108, 'cluster-worker-04', 5435, 4, 1); 108 | 109 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 110 | VALUES 111 | ('events'::regclass, 'h', 'name'); 112 | 113 | -- should see above shard identifiers 114 | SELECT load_shard_id_array('events', false); 115 | 116 | -- cache them for later use 117 | SELECT load_shard_id_array('events', true); 118 | 119 | -- should see empty array (catalog is not distributed) 120 | SELECT load_shard_id_array('pg_type', false); 121 | 122 | -- should see array with first shard range 123 | SELECT load_shard_interval_array(1, 0); 124 | 125 | -- should even work for range-partitioned shards 126 | BEGIN; 127 | UPDATE pgs_distribution_metadata.shard SET 128 | min_value = 'Aardvark', 129 | max_value = 'Zebra' 130 | WHERE id = 1; 131 | 132 | UPDATE pgs_distribution_metadata.partition SET partition_method = 'r' 133 | WHERE relation_id = 'events'::regclass; 134 | 135 | SELECT load_shard_interval_array(1, ''::text); 136 | ROLLBACK; 137 | 138 | -- should see error for non-existent shard 139 | SELECT load_shard_interval_array(5, 0); 140 | 141 | -- should see two placements 142 | SELECT load_shard_placement_array(2, false); 143 | 144 | -- only one of which is finalized 145 | SELECT load_shard_placement_array(2, true); 146 | 147 | -- should see error for non-existent shard 148 | SELECT load_shard_placement_array(6, false); 149 | 150 | -- should see column id of 'name' 151 | SELECT partition_column_id('events'); 152 | 153 | -- should see hash partition type and fail for non-distributed tables 154 | SELECT partition_type('events'); 155 | SELECT partition_type('pg_type'); 156 | 157 | -- should see true for events, false for others 158 | SELECT is_distributed_table('events'); 159 | SELECT is_distributed_table('pg_type'); 160 | SELECT is_distributed_table('pgs_distribution_metadata.shard'); 161 | 162 | -- should see that we have distributed tables 163 | SELECT distributed_tables_exist(); 164 | 165 | -- or maybe that we don't 166 | BEGIN; 167 | DELETE FROM pgs_distribution_metadata.partition; 168 | SELECT distributed_tables_exist(); 169 | ROLLBACK; 170 | 171 | -- test underlying column name-id translation 172 | SELECT column_name_to_column_id('events', 'name'); 173 | SELECT column_name_to_column_id('events', 'ctid'); 174 | SELECT column_name_to_column_id('events', 'non_existent'); 175 | 176 | -- drop shard rows (must drop placements first) 177 | DELETE FROM pgs_distribution_metadata.shard_placement 178 | WHERE shard_id BETWEEN 1 AND 4; 179 | DELETE FROM pgs_distribution_metadata.shard 180 | WHERE relation_id = 'events'::regclass; 181 | 182 | -- verify that an eager load shows them missing 183 | SELECT load_shard_id_array('events', false); 184 | 185 | -- but they live on in the cache 186 | SELECT load_shard_id_array('events', true); 187 | 188 | -- create second table to distribute 189 | CREATE TABLE customers ( 190 | id bigint, 191 | name text 192 | ); 193 | 194 | -- now we'll distribute using function calls but verify metadata manually... 195 | 196 | -- partition on id and manually inspect partition row 197 | SELECT insert_hash_partition_row('customers', 'id'); 198 | SELECT partition_method, key FROM pgs_distribution_metadata.partition 199 | WHERE relation_id = 'customers'::regclass; 200 | 201 | -- make one huge shard and manually inspect shard row 202 | SELECT create_monolithic_shard_row('customers') AS new_shard_id 203 | \gset 204 | SELECT storage, min_value, max_value FROM pgs_distribution_metadata.shard 205 | WHERE id = :new_shard_id; 206 | 207 | -- add a placement and manually inspect row 208 | SELECT create_healthy_local_shard_placement_row(:new_shard_id) AS new_placement_id 209 | \gset 210 | SELECT shard_state, node_name, node_port FROM pgs_distribution_metadata.shard_placement 211 | WHERE id = :new_placement_id; 212 | 213 | -- mark it as unhealthy and inspect 214 | SELECT update_shard_placement_row_state(:new_placement_id, 3); 215 | SELECT shard_state FROM pgs_distribution_metadata.shard_placement 216 | WHERE id = :new_placement_id; 217 | 218 | -- remove it and verify it is gone 219 | SELECT delete_shard_placement_row(:new_placement_id); 220 | SELECT COUNT(*) FROM pgs_distribution_metadata.shard_placement 221 | WHERE id = :new_placement_id; 222 | 223 | -- deleting or updating a non-existent row should fail 224 | SELECT delete_shard_placement_row(:new_placement_id); 225 | SELECT update_shard_placement_row_state(:new_placement_id, 3); 226 | 227 | -- now we'll even test our lock methods... 228 | 229 | -- use transaction to bound how long we hold the lock 230 | BEGIN; 231 | 232 | -- pick up a shard lock and look for it in pg_locks 233 | SELECT acquire_shared_shard_lock(5); 234 | SELECT objid, mode FROM pg_locks WHERE locktype = 'advisory' AND objid = 5; 235 | 236 | -- commit should drop the lock 237 | COMMIT; 238 | 239 | -- lock should be gone now 240 | SELECT COUNT(*) FROM pg_locks WHERE locktype = 'advisory' AND objid = 5; 241 | 242 | -- finally, check that having distributed tables prevent dropping the extension 243 | DROP EXTENSION pg_shard; 244 | 245 | -- prevent actual drop using transaction 246 | BEGIN; 247 | -- the above should fail but we can force a drop with CASCADE 248 | DROP EXTENSION pg_shard CASCADE; 249 | ROLLBACK; 250 | -------------------------------------------------------------------------------- /test/sql/09-queries.sql: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test end-to-end query functionality 3 | -- =================================================================== 4 | 5 | CREATE TABLE articles ( 6 | id bigint NOT NULL, 7 | author_id bigint NOT NULL, 8 | title text NOT NULL, 9 | word_count integer NOT NULL CHECK (word_count > 0) 10 | ); 11 | 12 | -- this table is used in a CTE test 13 | CREATE TABLE authors ( name text, id bigint ); 14 | 15 | SELECT master_create_distributed_table('articles', 'author_id'); 16 | 17 | -- test when a table is distributed but no shards created yet 18 | SELECT count(*) from articles; 19 | 20 | -- squelch noisy warnings when creating shards 21 | \set VERBOSITY terse 22 | SELECT master_create_worker_shards('articles', 2, 1); 23 | \set VERBOSITY default 24 | 25 | -- create a bunch of test data 26 | INSERT INTO articles VALUES ( 1, 1, 'arsenous', 9572); 27 | INSERT INTO articles VALUES ( 2, 2, 'abducing', 13642); 28 | INSERT INTO articles VALUES ( 3, 3, 'asternal', 10480); 29 | INSERT INTO articles VALUES ( 4, 4, 'altdorfer', 14551); 30 | INSERT INTO articles VALUES ( 5, 5, 'aruru', 11389); 31 | INSERT INTO articles VALUES ( 6, 6, 'atlases', 15459); 32 | INSERT INTO articles VALUES ( 7, 7, 'aseptic', 12298); 33 | INSERT INTO articles VALUES ( 8, 8, 'agatized', 16368); 34 | INSERT INTO articles VALUES ( 9, 9, 'alligate', 438); 35 | INSERT INTO articles VALUES (10, 10, 'aggrandize', 17277); 36 | INSERT INTO articles VALUES (11, 1, 'alamo', 1347); 37 | INSERT INTO articles VALUES (12, 2, 'archiblast', 18185); 38 | INSERT INTO articles VALUES (13, 3, 'aseyev', 2255); 39 | INSERT INTO articles VALUES (14, 4, 'andesite', 19094); 40 | INSERT INTO articles VALUES (15, 5, 'adversa', 3164); 41 | INSERT INTO articles VALUES (16, 6, 'allonym', 2); 42 | INSERT INTO articles VALUES (17, 7, 'auriga', 4073); 43 | INSERT INTO articles VALUES (18, 8, 'assembly', 911); 44 | INSERT INTO articles VALUES (19, 9, 'aubergiste', 4981); 45 | INSERT INTO articles VALUES (20, 10, 'absentness', 1820); 46 | INSERT INTO articles VALUES (21, 1, 'arcading', 5890); 47 | INSERT INTO articles VALUES (22, 2, 'antipope', 2728); 48 | INSERT INTO articles VALUES (23, 3, 'abhorring', 6799); 49 | INSERT INTO articles VALUES (24, 4, 'audacious', 3637); 50 | INSERT INTO articles VALUES (25, 5, 'antehall', 7707); 51 | INSERT INTO articles VALUES (26, 6, 'abington', 4545); 52 | INSERT INTO articles VALUES (27, 7, 'arsenous', 8616); 53 | INSERT INTO articles VALUES (28, 8, 'aerophyte', 5454); 54 | INSERT INTO articles VALUES (29, 9, 'amateur', 9524); 55 | INSERT INTO articles VALUES (30, 10, 'andelee', 6363); 56 | INSERT INTO articles VALUES (31, 1, 'athwartships', 7271); 57 | INSERT INTO articles VALUES (32, 2, 'amazon', 11342); 58 | INSERT INTO articles VALUES (33, 3, 'autochrome', 8180); 59 | INSERT INTO articles VALUES (34, 4, 'amnestied', 12250); 60 | INSERT INTO articles VALUES (35, 5, 'aminate', 9089); 61 | INSERT INTO articles VALUES (36, 6, 'ablation', 13159); 62 | INSERT INTO articles VALUES (37, 7, 'archduchies', 9997); 63 | INSERT INTO articles VALUES (38, 8, 'anatine', 14067); 64 | INSERT INTO articles VALUES (39, 9, 'anchises', 10906); 65 | INSERT INTO articles VALUES (40, 10, 'attemper', 14976); 66 | INSERT INTO articles VALUES (41, 1, 'aznavour', 11814); 67 | INSERT INTO articles VALUES (42, 2, 'ausable', 15885); 68 | INSERT INTO articles VALUES (43, 3, 'affixal', 12723); 69 | INSERT INTO articles VALUES (44, 4, 'anteport', 16793); 70 | INSERT INTO articles VALUES (45, 5, 'afrasia', 864); 71 | INSERT INTO articles VALUES (46, 6, 'atlanta', 17702); 72 | INSERT INTO articles VALUES (47, 7, 'abeyance', 1772); 73 | INSERT INTO articles VALUES (48, 8, 'alkylic', 18610); 74 | INSERT INTO articles VALUES (49, 9, 'anyone', 2681); 75 | INSERT INTO articles VALUES (50, 10, 'anjanette', 19519); 76 | 77 | -- first, test zero-shard SELECT, which should return zero rows 78 | SELECT COUNT(*) FROM articles WHERE author_id = 1 AND author_id = 2; 79 | 80 | -- zero-shard modifications should be no-ops in pg_shard, fail in CitusDB 81 | UPDATE articles SET title = '' WHERE author_id = 1 AND author_id = 2; 82 | DELETE FROM articles WHERE author_id = 1 AND author_id = 2; 83 | 84 | -- single-shard tests 85 | 86 | -- test simple select for a single row 87 | SELECT * FROM articles WHERE author_id = 10 AND id = 50; 88 | 89 | -- get all titles by a single author 90 | SELECT title FROM articles WHERE author_id = 10; 91 | 92 | -- try ordering them by word count 93 | SELECT title, word_count FROM articles 94 | WHERE author_id = 10 95 | ORDER BY word_count DESC NULLS LAST; 96 | 97 | -- look at last two articles by an author 98 | SELECT title, id FROM articles 99 | WHERE author_id = 5 100 | ORDER BY id 101 | LIMIT 2; 102 | 103 | -- find all articles by two authors in same shard 104 | SELECT title, author_id FROM articles 105 | WHERE author_id = 7 OR author_id = 8 106 | ORDER BY author_id ASC, id; 107 | 108 | -- add in some grouping expressions, still on same shard 109 | SELECT author_id, sum(word_count) AS corpus_size FROM articles 110 | WHERE author_id = 1 OR author_id = 7 OR author_id = 8 OR author_id = 10 111 | GROUP BY author_id 112 | HAVING sum(word_count) > 40000 113 | ORDER BY sum(word_count) DESC; 114 | 115 | -- UNION/INTERSECT queries are unsupported 116 | SELECT * FROM articles WHERE author_id = 10 UNION 117 | SELECT * FROM articles WHERE author_id = 1; 118 | 119 | -- queries using CTEs are unsupported 120 | WITH long_names AS ( SELECT id FROM authors WHERE char_length(name) > 15 ) 121 | SELECT title FROM articles; 122 | 123 | -- queries which involve functions in FROM clause are unsupported. 124 | SELECT * FROM articles, position('om' in 'Thomas'); 125 | 126 | -- subqueries are not supported in WHERE clause 127 | SELECT * FROM articles WHERE author_id IN (SELECT id FROM authors WHERE name LIKE '%a'); 128 | 129 | -- subqueries are not supported in FROM clause 130 | SELECT articles.id,test.word_count 131 | FROM articles, (SELECT id, word_count FROM articles) AS test WHERE test.id = articles.id; 132 | 133 | -- subqueries are not supported in SELECT clause 134 | SELECT a.title AS name, (SELECT a2.id FROM authors a2 WHERE a.id = a2.id LIMIT 1) 135 | AS special_price FROM articles a; 136 | 137 | -- joins are not supported in WHERE clause 138 | SELECT title, authors.name FROM authors, articles WHERE authors.id = articles.author_id; 139 | 140 | -- joins are not supported in FROM clause 141 | SELECT * FROM (articles INNER JOIN authors ON articles.id = authors.id); 142 | 143 | -- with normal PostgreSQL, expect error about CitusDB being missing 144 | -- with CitusDB, expect an error about JOINing local table with distributed 145 | SET pg_shard.use_citusdb_select_logic TO true; 146 | SELECT title, authors.name FROM authors, articles WHERE authors.id = articles.author_id; 147 | SET pg_shard.use_citusdb_select_logic TO false; 148 | 149 | -- test use of EXECUTE statements within plpgsql 150 | DO $sharded_execute$ 151 | BEGIN 152 | EXECUTE 'SELECT COUNT(*) FROM articles ' || 153 | 'WHERE author_id = $1 AND author_id = $2' USING 1, 2; 154 | END 155 | $sharded_execute$; 156 | 157 | -- test use of bare SQL within plpgsql 158 | DO $sharded_sql$ 159 | BEGIN 160 | SELECT COUNT(*) FROM articles WHERE author_id = 1 AND author_id = 2; 161 | END 162 | $sharded_sql$; 163 | 164 | -- test cross-shard queries 165 | SELECT COUNT(*) FROM articles; 166 | 167 | -- try query with more SQL features 168 | SELECT author_id, sum(word_count) AS corpus_size FROM articles 169 | GROUP BY author_id 170 | HAVING sum(word_count) > 25000 171 | ORDER BY sum(word_count) DESC 172 | LIMIT 5; 173 | 174 | -- cross-shard queries on a foreign table should fail 175 | -- we'll just point the article shards to a foreign table 176 | BEGIN; 177 | CREATE FOREIGN TABLE foreign_articles (id bigint, author_id bigint) 178 | SERVER fake_fdw_server; 179 | 180 | UPDATE pgs_distribution_metadata.partition 181 | SET relation_id='foreign_articles'::regclass 182 | WHERE relation_id='articles'::regclass; 183 | 184 | UPDATE pgs_distribution_metadata.shard 185 | SET relation_id='foreign_articles'::regclass 186 | WHERE relation_id='articles'::regclass; 187 | 188 | SET pg_shard.log_distributed_statements = on; 189 | 190 | SELECT COUNT(*) FROM foreign_articles; 191 | ROLLBACK; 192 | 193 | -- verify pg_shard produces correct remote SQL using logging flag 194 | SET pg_shard.log_distributed_statements = on; 195 | SET client_min_messages = log; 196 | 197 | SELECT count(*) FROM articles WHERE word_count > 10000; 198 | 199 | SET client_min_messages = DEFAULT; 200 | SET pg_shard.log_distributed_statements = DEFAULT; 201 | 202 | -- use HAVING without its variable in target list 203 | SELECT author_id FROM articles 204 | GROUP BY author_id 205 | HAVING sum(word_count) > 50000 206 | ORDER BY author_id; 207 | 208 | -- verify temp tables used by cross-shard queries do not persist 209 | SELECT COUNT(*) FROM pg_class WHERE relname LIKE 'pg_shard_temp_table%' AND 210 | relkind = 'r'; 211 | -------------------------------------------------------------------------------- /test/expected/11-citus_metadata_sync.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- test metadata sync functionality 3 | -- =================================================================== 4 | -- declare some variables for clarity 5 | \set finalized 1 6 | \set inactive 3 7 | -- set up a table and "distribute" it manually 8 | CREATE TABLE set_of_ids ( id bigint ); 9 | INSERT INTO pgs_distribution_metadata.shard 10 | (id, relation_id, storage, min_value, max_value) 11 | VALUES 12 | (1, 'set_of_ids'::regclass, 't', '0', '10'), 13 | (2, 'set_of_ids'::regclass, 't', '10', '20'); 14 | -- two shards, replication factor two 15 | INSERT INTO pgs_distribution_metadata.shard_placement 16 | (id, node_name, node_port, shard_id, shard_state) 17 | VALUES 18 | (101, 'cluster-worker-01', 5432, 1, :finalized), 19 | (102, 'cluster-worker-02', 5433, 2, :finalized), 20 | (103, 'cluster-worker-03', 5434, 1, :finalized), 21 | (104, 'cluster-worker-04', 5435, 2, :finalized); 22 | INSERT INTO pgs_distribution_metadata.partition (relation_id, partition_method, key) 23 | VALUES 24 | ('set_of_ids'::regclass, 'h', 'id'); 25 | -- should get ERROR for NULL, non-existent, or non-distributed table 26 | SELECT partition_column_to_node_string(NULL); 27 | ERROR: table_oid must not be null 28 | SELECT partition_column_to_node_string(0); 29 | ERROR: no partition column is defined for relation "(null)" 30 | SELECT partition_column_to_node_string('pg_class'::regclass); 31 | ERROR: no partition column is defined for relation "pg_class" 32 | -- should get node representation for distributed table 33 | SELECT partition_column_to_node_string('set_of_ids'::regclass); 34 | partition_column_to_node_string 35 | ------------------------------------------------------------------------------------------------------------------------ 36 | {VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 1 :location -1} 37 | (1 row) 38 | 39 | -- should get error for column names that are too long 40 | SELECT column_name_to_column('set_of_ids'::regclass, repeat('a', 1024)); 41 | ERROR: column name too long 42 | DETAIL: Column name must be less than 64 characters. 43 | -- should get error for system or non-existent column 44 | SELECT column_name_to_column('set_of_ids'::regclass, 'ctid'); 45 | ERROR: column "ctid" of relation "set_of_ids" is a system column 46 | SELECT column_name_to_column('set_of_ids'::regclass, 'non_existent'); 47 | ERROR: column "non_existent" of relation "set_of_ids" does not exist 48 | -- should get node representation for valid column 49 | SELECT column_name_to_column('set_of_ids'::regclass, 'id') AS column_var 50 | \gset 51 | SELECT replace(:'column_var', ':varattno 1', ':varattno -1') AS ctid_var, 52 | replace(:'column_var', ':varattno 1', ':varattno 2') AS non_ext_var 53 | \gset 54 | -- should get error for system or non-existent column 55 | SELECT column_to_column_name('set_of_ids'::regclass, :'ctid_var'); 56 | ERROR: attribute -1 of relation "set_of_ids" is a system column 57 | SELECT column_to_column_name('set_of_ids'::regclass, :'non_ext_var'); 58 | ERROR: attribute 2 of relation "set_of_ids" does not exist 59 | -- should get node representation for valid column 60 | SELECT column_to_column_name('set_of_ids'::regclass, :'column_var'); 61 | column_to_column_name 62 | ----------------------- 63 | id 64 | (1 row) 65 | 66 | -- create subset of CitusDB metadata schema 67 | CREATE TABLE pg_dist_partition ( 68 | logicalrelid oid NOT NULL, 69 | partmethod "char" NOT NULL, 70 | partkey text 71 | ); 72 | CREATE TABLE pg_dist_shard ( 73 | logicalrelid oid NOT NULL, 74 | shardid bigint NOT NULL, 75 | shardstorage "char" NOT NULL, 76 | shardalias text, 77 | shardminvalue text, 78 | shardmaxvalue text 79 | ); 80 | CREATE TABLE pg_dist_shard_placement ( 81 | shardid bigint NOT NULL, 82 | shardstate integer NOT NULL, 83 | shardlength bigint NOT NULL, 84 | nodename text, 85 | nodeport integer 86 | ) WITH OIDS; 87 | -- sync metadata and verify it has transferred 88 | SELECT sync_table_metadata_to_citus('set_of_ids'); 89 | WARNING: sync_table_metadata_to_citus is deprecated and will be removed in a future version 90 | sync_table_metadata_to_citus 91 | ------------------------------ 92 | 93 | (1 row) 94 | 95 | SELECT partmethod, partkey 96 | FROM pg_dist_partition 97 | WHERE logicalrelid = 'set_of_ids'::regclass; 98 | partmethod | partkey 99 | ------------+------------------------------------------------------------------------------------------------------------------------ 100 | h | {VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 1 :location -1} 101 | (1 row) 102 | 103 | SELECT shardid, shardstorage, shardalias, shardminvalue, shardmaxvalue 104 | FROM pg_dist_shard 105 | WHERE logicalrelid = 'set_of_ids'::regclass 106 | ORDER BY shardid; 107 | shardid | shardstorage | shardalias | shardminvalue | shardmaxvalue 108 | ---------+--------------+------------+---------------+--------------- 109 | 1 | t | | 0 | 10 110 | 2 | t | | 10 | 20 111 | (2 rows) 112 | 113 | SELECT * FROM pg_dist_shard_placement 114 | WHERE shardid IN (SELECT shardid 115 | FROM pg_dist_shard 116 | WHERE logicalrelid = 'set_of_ids'::regclass) 117 | ORDER BY nodename; 118 | shardid | shardstate | shardlength | nodename | nodeport 119 | ---------+------------+-------------+-------------------+---------- 120 | 1 | 1 | 0 | cluster-worker-01 | 5432 121 | 2 | 1 | 0 | cluster-worker-02 | 5433 122 | 1 | 1 | 0 | cluster-worker-03 | 5434 123 | 2 | 1 | 0 | cluster-worker-04 | 5435 124 | (4 rows) 125 | 126 | -- subsequent sync should have no effect 127 | SELECT sync_table_metadata_to_citus('set_of_ids'); 128 | WARNING: sync_table_metadata_to_citus is deprecated and will be removed in a future version 129 | sync_table_metadata_to_citus 130 | ------------------------------ 131 | 132 | (1 row) 133 | 134 | SELECT partmethod, partkey 135 | FROM pg_dist_partition 136 | WHERE logicalrelid = 'set_of_ids'::regclass; 137 | partmethod | partkey 138 | ------------+------------------------------------------------------------------------------------------------------------------------ 139 | h | {VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varlevelsup 0 :varnoold 1 :varoattno 1 :location -1} 140 | (1 row) 141 | 142 | SELECT shardid, shardstorage, shardalias, shardminvalue, shardmaxvalue 143 | FROM pg_dist_shard 144 | WHERE logicalrelid = 'set_of_ids'::regclass 145 | ORDER BY shardid; 146 | shardid | shardstorage | shardalias | shardminvalue | shardmaxvalue 147 | ---------+--------------+------------+---------------+--------------- 148 | 1 | t | | 0 | 10 149 | 2 | t | | 10 | 20 150 | (2 rows) 151 | 152 | SELECT * FROM pg_dist_shard_placement 153 | WHERE shardid IN (SELECT shardid 154 | FROM pg_dist_shard 155 | WHERE logicalrelid = 'set_of_ids'::regclass) 156 | ORDER BY nodename; 157 | shardid | shardstate | shardlength | nodename | nodeport 158 | ---------+------------+-------------+-------------------+---------- 159 | 1 | 1 | 0 | cluster-worker-01 | 5432 160 | 2 | 1 | 0 | cluster-worker-02 | 5433 161 | 1 | 1 | 0 | cluster-worker-03 | 5434 162 | 2 | 1 | 0 | cluster-worker-04 | 5435 163 | (4 rows) 164 | 165 | -- mark a placement as unhealthy and add a new one 166 | UPDATE pgs_distribution_metadata.shard_placement 167 | SET shard_state = :inactive 168 | WHERE node_name = 'cluster-worker-02'; 169 | INSERT INTO pgs_distribution_metadata.shard_placement 170 | (id, node_name, node_port, shard_id, shard_state) 171 | VALUES 172 | (105, 'cluster-worker-05', 5436, 1, :finalized); 173 | -- write latest changes to CitusDB tables 174 | SELECT sync_table_metadata_to_citus('set_of_ids'); 175 | WARNING: sync_table_metadata_to_citus is deprecated and will be removed in a future version 176 | sync_table_metadata_to_citus 177 | ------------------------------ 178 | 179 | (1 row) 180 | 181 | -- should see updated state and new placement 182 | SELECT * FROM pg_dist_shard_placement 183 | WHERE shardid IN (SELECT shardid 184 | FROM pg_dist_shard 185 | WHERE logicalrelid = 'set_of_ids'::regclass) 186 | ORDER BY nodename; 187 | shardid | shardstate | shardlength | nodename | nodeport 188 | ---------+------------+-------------+-------------------+---------- 189 | 1 | 1 | 0 | cluster-worker-01 | 5432 190 | 2 | 3 | 0 | cluster-worker-02 | 5433 191 | 1 | 1 | 0 | cluster-worker-03 | 5434 192 | 2 | 1 | 0 | cluster-worker-04 | 5435 193 | 1 | 1 | 0 | cluster-worker-05 | 5436 194 | (5 rows) 195 | 196 | -------------------------------------------------------------------------------- /test/expected/04-generate_ddl_commands.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | CREATE FUNCTION table_ddl_command_array(regclass) 5 | RETURNS text[] 6 | AS 'pg_shard' 7 | LANGUAGE C STRICT; 8 | CREATE FUNCTION alter_server_host_and_port_command(server_name cstring, 9 | host cstring, 10 | port cstring) 11 | RETURNS text 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | -- =================================================================== 15 | -- test ddl command generation functionality 16 | -- =================================================================== 17 | -- first make sure a simple table works 18 | CREATE TABLE simple_table ( 19 | first_name text, 20 | last_name text, 21 | id bigint 22 | ); 23 | SELECT table_ddl_command_array('simple_table'); 24 | table_ddl_command_array 25 | ----------------------------------------------------------------------------------- 26 | {"CREATE TABLE public.simple_table (first_name text, last_name text, id bigint)"} 27 | (1 row) 28 | 29 | -- ensure not-null constraints are propagated 30 | CREATE TABLE not_null_table ( 31 | city text, 32 | id bigint not null 33 | ); 34 | SELECT table_ddl_command_array('not_null_table'); 35 | table_ddl_command_array 36 | ------------------------------------------------------------------------ 37 | {"CREATE TABLE public.not_null_table (city text, id bigint NOT NULL)"} 38 | (1 row) 39 | 40 | -- even more complex constraints should be preserved... 41 | CREATE TABLE column_constraint_table ( 42 | first_name text, 43 | last_name text, 44 | age int CONSTRAINT non_negative_age CHECK (age >= 0) 45 | ); 46 | SELECT table_ddl_command_array('column_constraint_table'); 47 | table_ddl_command_array 48 | ---------------------------------------------------------------------------------------------------------------------------------------------- 49 | {"CREATE TABLE public.column_constraint_table (first_name text, last_name text, age integer, CONSTRAINT non_negative_age CHECK (age >= 0))"} 50 | (1 row) 51 | 52 | -- including table constraints 53 | CREATE TABLE table_constraint_table ( 54 | bid_item_id bigint, 55 | min_bid decimal not null, 56 | max_bid decimal not null, 57 | CONSTRAINT bids_ordered CHECK (min_bid > max_bid) 58 | ); 59 | SELECT table_ddl_command_array('table_constraint_table'); 60 | table_ddl_command_array 61 | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 62 | {"CREATE TABLE public.table_constraint_table (bid_item_id bigint, min_bid numeric NOT NULL, max_bid numeric NOT NULL, CONSTRAINT bids_ordered CHECK (min_bid > max_bid))"} 63 | (1 row) 64 | 65 | -- default values are supported 66 | CREATE TABLE default_value_table ( 67 | name text, 68 | price decimal default 0.00 69 | ); 70 | SELECT table_ddl_command_array('default_value_table'); 71 | table_ddl_command_array 72 | ------------------------------------------------------------------------------------- 73 | {"CREATE TABLE public.default_value_table (name text, price numeric DEFAULT 0.00)"} 74 | (1 row) 75 | 76 | -- of course primary keys work... 77 | CREATE TABLE pkey_table ( 78 | first_name text, 79 | last_name text, 80 | id bigint PRIMARY KEY 81 | ); 82 | SELECT table_ddl_command_array('pkey_table'); 83 | table_ddl_command_array 84 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 85 | {"CREATE TABLE public.pkey_table (first_name text, last_name text, id bigint NOT NULL)","ALTER TABLE ONLY pkey_table ADD CONSTRAINT pkey_table_pkey PRIMARY KEY (id)"} 86 | (1 row) 87 | 88 | -- as do unique indexes... 89 | CREATE TABLE unique_table ( 90 | user_id bigint not null, 91 | username text UNIQUE not null 92 | ); 93 | SELECT table_ddl_command_array('unique_table'); 94 | table_ddl_command_array 95 | ----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 96 | {"CREATE TABLE public.unique_table (user_id bigint NOT NULL, username text NOT NULL)","ALTER TABLE ONLY unique_table ADD CONSTRAINT unique_table_username_key UNIQUE (username)"} 97 | (1 row) 98 | 99 | -- and indexes used for clustering 100 | CREATE TABLE clustered_table ( 101 | data json not null, 102 | received_at timestamp not null 103 | ); 104 | CREATE INDEX clustered_time_idx ON clustered_table (received_at); 105 | CLUSTER clustered_table USING clustered_time_idx; 106 | SELECT table_ddl_command_array('clustered_table'); 107 | table_ddl_command_array 108 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 109 | {"CREATE TABLE public.clustered_table (data json NOT NULL, received_at timestamp without time zone NOT NULL)","CREATE INDEX clustered_time_idx ON clustered_table USING btree (received_at)","ALTER TABLE public.clustered_table CLUSTER ON clustered_time_idx"} 110 | (1 row) 111 | 112 | -- fiddly things like storage type and statistics also work 113 | CREATE TABLE fiddly_table ( 114 | hostname char(255) not null, 115 | os char(255) not null, 116 | ip_addr inet not null, 117 | traceroute text not null 118 | ); 119 | ALTER TABLE fiddly_table 120 | ALTER hostname SET STORAGE PLAIN, 121 | ALTER os SET STORAGE MAIN, 122 | ALTER ip_addr SET STORAGE EXTENDED, 123 | ALTER traceroute SET STORAGE EXTERNAL, 124 | ALTER ip_addr SET STATISTICS 500; 125 | SELECT table_ddl_command_array('fiddly_table'); 126 | table_ddl_command_array 127 | --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 128 | {"CREATE TABLE public.fiddly_table (hostname character(255) NOT NULL, os character(255) NOT NULL, ip_addr inet NOT NULL, traceroute text NOT NULL)","ALTER TABLE ONLY public.fiddly_table ALTER COLUMN hostname SET STORAGE PLAIN, ALTER COLUMN os SET STORAGE MAIN, ALTER COLUMN ip_addr SET STORAGE EXTENDED, ALTER COLUMN ip_addr SET STATISTICS 500, ALTER COLUMN traceroute SET STORAGE EXTERNAL"} 129 | (1 row) 130 | 131 | -- test foreign tables using fake FDW 132 | CREATE FOREIGN TABLE foreign_table ( 133 | id bigint not null, 134 | full_name text not null default '' 135 | ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); 136 | SELECT table_ddl_command_array('foreign_table'); 137 | table_ddl_command_array 138 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 139 | {"CREATE FOREIGN TABLE public.foreign_table (id bigint NOT NULL, full_name text DEFAULT ''::text NOT NULL) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true')"} 140 | (1 row) 141 | 142 | -- propagating views is not supported 143 | CREATE VIEW local_view AS SELECT * FROM simple_table; 144 | SELECT table_ddl_command_array('local_view'); 145 | ERROR: public.local_view is not a regular or foreign table 146 | -- independently test option-generation code 147 | SELECT alter_server_host_and_port_command('fake_fdw_server', 'localhost', '5432'); 148 | alter_server_host_and_port_command 149 | ---------------------------------------------------------------------- 150 | ALTER SERVER fake_fdw_server OPTIONS (host 'localhost', port '5432') 151 | (1 row) 152 | 153 | -- clean up 154 | DROP VIEW IF EXISTS local_view; 155 | DROP FOREIGN TABLE IF EXISTS foreign_table; 156 | DROP TABLE IF EXISTS simple_table, not_null_table, column_constraint_table, 157 | table_constraint_table, default_value_table, pkey_table, 158 | unique_table, clustered_table, fiddly_table; 159 | -------------------------------------------------------------------------------- /test/expected/04-generate_ddl_commands_1.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | CREATE FUNCTION table_ddl_command_array(regclass) 5 | RETURNS text[] 6 | AS 'pg_shard' 7 | LANGUAGE C STRICT; 8 | CREATE FUNCTION alter_server_host_and_port_command(server_name cstring, 9 | host cstring, 10 | port cstring) 11 | RETURNS text 12 | AS 'pg_shard' 13 | LANGUAGE C STRICT; 14 | -- =================================================================== 15 | -- test ddl command generation functionality 16 | -- =================================================================== 17 | -- first make sure a simple table works 18 | CREATE TABLE simple_table ( 19 | first_name text, 20 | last_name text, 21 | id bigint 22 | ); 23 | SELECT table_ddl_command_array('simple_table'); 24 | table_ddl_command_array 25 | ----------------------------------------------------------------------------------- 26 | {"CREATE TABLE public.simple_table (first_name text, last_name text, id bigint)"} 27 | (1 row) 28 | 29 | -- ensure not-null constraints are propagated 30 | CREATE TABLE not_null_table ( 31 | city text, 32 | id bigint not null 33 | ); 34 | SELECT table_ddl_command_array('not_null_table'); 35 | table_ddl_command_array 36 | ------------------------------------------------------------------------ 37 | {"CREATE TABLE public.not_null_table (city text, id bigint NOT NULL)"} 38 | (1 row) 39 | 40 | -- even more complex constraints should be preserved... 41 | CREATE TABLE column_constraint_table ( 42 | first_name text, 43 | last_name text, 44 | age int CONSTRAINT non_negative_age CHECK (age >= 0) 45 | ); 46 | SELECT table_ddl_command_array('column_constraint_table'); 47 | table_ddl_command_array 48 | ---------------------------------------------------------------------------------------------------------------------------------------------- 49 | {"CREATE TABLE public.column_constraint_table (first_name text, last_name text, age integer, CONSTRAINT non_negative_age CHECK (age >= 0))"} 50 | (1 row) 51 | 52 | -- including table constraints 53 | CREATE TABLE table_constraint_table ( 54 | bid_item_id bigint, 55 | min_bid decimal not null, 56 | max_bid decimal not null, 57 | CONSTRAINT bids_ordered CHECK (min_bid > max_bid) 58 | ); 59 | SELECT table_ddl_command_array('table_constraint_table'); 60 | table_ddl_command_array 61 | ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 62 | {"CREATE TABLE public.table_constraint_table (bid_item_id bigint, min_bid numeric NOT NULL, max_bid numeric NOT NULL, CONSTRAINT bids_ordered CHECK (min_bid > max_bid))"} 63 | (1 row) 64 | 65 | -- default values are supported 66 | CREATE TABLE default_value_table ( 67 | name text, 68 | price decimal default 0.00 69 | ); 70 | SELECT table_ddl_command_array('default_value_table'); 71 | table_ddl_command_array 72 | ------------------------------------------------------------------------------------- 73 | {"CREATE TABLE public.default_value_table (name text, price numeric DEFAULT 0.00)"} 74 | (1 row) 75 | 76 | -- of course primary keys work... 77 | CREATE TABLE pkey_table ( 78 | first_name text, 79 | last_name text, 80 | id bigint PRIMARY KEY 81 | ); 82 | SELECT table_ddl_command_array('pkey_table'); 83 | table_ddl_command_array 84 | -------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 85 | {"CREATE TABLE public.pkey_table (first_name text, last_name text, id bigint NOT NULL)","ALTER TABLE public.pkey_table ADD CONSTRAINT pkey_table_pkey PRIMARY KEY (id)"} 86 | (1 row) 87 | 88 | -- as do unique indexes... 89 | CREATE TABLE unique_table ( 90 | user_id bigint not null, 91 | username text UNIQUE not null 92 | ); 93 | SELECT table_ddl_command_array('unique_table'); 94 | table_ddl_command_array 95 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 96 | {"CREATE TABLE public.unique_table (user_id bigint NOT NULL, username text NOT NULL)","ALTER TABLE public.unique_table ADD CONSTRAINT unique_table_username_key UNIQUE (username)"} 97 | (1 row) 98 | 99 | -- and indexes used for clustering 100 | CREATE TABLE clustered_table ( 101 | data json not null, 102 | received_at timestamp not null 103 | ); 104 | CREATE INDEX clustered_time_idx ON clustered_table (received_at); 105 | CLUSTER clustered_table USING clustered_time_idx; 106 | SELECT table_ddl_command_array('clustered_table'); 107 | table_ddl_command_array 108 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 109 | {"CREATE TABLE public.clustered_table (data json NOT NULL, received_at timestamp without time zone NOT NULL)","CREATE INDEX clustered_time_idx ON clustered_table USING btree (received_at)","ALTER TABLE public.clustered_table CLUSTER ON clustered_time_idx"} 110 | (1 row) 111 | 112 | -- fiddly things like storage type and statistics also work 113 | CREATE TABLE fiddly_table ( 114 | hostname char(255) not null, 115 | os char(255) not null, 116 | ip_addr inet not null, 117 | traceroute text not null 118 | ); 119 | ALTER TABLE fiddly_table 120 | ALTER hostname SET STORAGE PLAIN, 121 | ALTER os SET STORAGE MAIN, 122 | ALTER ip_addr SET STORAGE EXTENDED, 123 | ALTER traceroute SET STORAGE EXTERNAL, 124 | ALTER ip_addr SET STATISTICS 500; 125 | SELECT table_ddl_command_array('fiddly_table'); 126 | table_ddl_command_array 127 | --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 128 | {"CREATE TABLE public.fiddly_table (hostname character(255) NOT NULL, os character(255) NOT NULL, ip_addr inet NOT NULL, traceroute text NOT NULL)","ALTER TABLE ONLY public.fiddly_table ALTER COLUMN hostname SET STORAGE PLAIN, ALTER COLUMN os SET STORAGE MAIN, ALTER COLUMN ip_addr SET STORAGE EXTENDED, ALTER COLUMN ip_addr SET STATISTICS 500, ALTER COLUMN traceroute SET STORAGE EXTERNAL"} 129 | (1 row) 130 | 131 | -- test foreign tables using fake FDW 132 | CREATE FOREIGN TABLE foreign_table ( 133 | id bigint not null, 134 | full_name text not null default '' 135 | ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); 136 | SELECT table_ddl_command_array('foreign_table'); 137 | table_ddl_command_array 138 | ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ 139 | {"CREATE FOREIGN TABLE public.foreign_table (id bigint NOT NULL, full_name text DEFAULT ''::text NOT NULL) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true')"} 140 | (1 row) 141 | 142 | -- propagating views is not supported 143 | CREATE VIEW local_view AS SELECT * FROM simple_table; 144 | SELECT table_ddl_command_array('local_view'); 145 | ERROR: public.local_view is not a regular or foreign table 146 | -- independently test option-generation code 147 | SELECT alter_server_host_and_port_command('fake_fdw_server', 'localhost', '5432'); 148 | alter_server_host_and_port_command 149 | ---------------------------------------------------------------------- 150 | ALTER SERVER fake_fdw_server OPTIONS (host 'localhost', port '5432') 151 | (1 row) 152 | 153 | -- clean up 154 | DROP VIEW IF EXISTS local_view; 155 | DROP FOREIGN TABLE IF EXISTS foreign_table; 156 | DROP TABLE IF EXISTS simple_table, not_null_table, column_constraint_table, 157 | table_constraint_table, default_value_table, pkey_table, 158 | unique_table, clustered_table, fiddly_table; 159 | -------------------------------------------------------------------------------- /updates/pg_shard--1.1--1.2.sql: -------------------------------------------------------------------------------- 1 | -- needed in our views 2 | CREATE FUNCTION column_to_column_name(table_oid oid, column_var text) 3 | RETURNS text 4 | AS 'MODULE_PATHNAME' 5 | LANGUAGE C STABLE STRICT; 6 | 7 | CREATE FUNCTION column_name_to_column(table_oid oid, column_name text) 8 | RETURNS text 9 | AS 'MODULE_PATHNAME' 10 | LANGUAGE C STABLE STRICT; 11 | 12 | DO $$ 13 | DECLARE 14 | use_citus_metadata boolean := false; 15 | relation_name text; 16 | BEGIN 17 | BEGIN 18 | PERFORM 'pg_catalog.pg_dist_partition'::regclass; 19 | use_citus_metadata = true; 20 | EXCEPTION 21 | WHEN undefined_table THEN 22 | use_citus_metadata = false; 23 | END; 24 | 25 | IF use_citus_metadata THEN 26 | -- just in case, lock everyone out of pg_shard partitions 27 | LOCK TABLE pgs_distribution_metadata.partition IN EXCLUSIVE MODE; 28 | FOR relation_name IN SELECT relation_id::regclass::text 29 | FROM pgs_distribution_metadata.partition LOOP 30 | PERFORM sync_table_metadata_to_citus(relation_name); 31 | END LOOP; 32 | 33 | -- clean up dependencies on configuration objects 34 | ALTER EXTENSION pg_shard DROP SEQUENCE pgs_distribution_metadata.shard_placement_id_sequence; 35 | ALTER EXTENSION pg_shard DROP SEQUENCE pgs_distribution_metadata.shard_id_sequence; 36 | ALTER EXTENSION pg_shard DROP TABLE pgs_distribution_metadata.partition; 37 | ALTER EXTENSION pg_shard DROP TABLE pgs_distribution_metadata.shard_placement; 38 | ALTER EXTENSION pg_shard DROP TABLE pgs_distribution_metadata.shard; 39 | ALTER EXTENSION pg_shard DROP SCHEMA pgs_distribution_metadata; 40 | 41 | DROP SCHEMA pgs_distribution_metadata CASCADE; 42 | 43 | CREATE FUNCTION adapt_and_insert_shard() RETURNS TRIGGER AS $aais$ 44 | BEGIN 45 | IF NEW.id IS NULL THEN 46 | NEW.id = nextval('pg_dist_shardid_seq'); 47 | END IF; 48 | 49 | INSERT INTO pg_dist_shard 50 | (logicalrelid, 51 | shardid, 52 | shardstorage, 53 | shardalias, 54 | shardminvalue, 55 | shardmaxvalue) 56 | VALUES (NEW.relation_id, 57 | NEW.id, 58 | NEW.storage, 59 | NULL, 60 | NEW.min_value, 61 | NEW.max_value); 62 | 63 | RETURN NEW; 64 | END 65 | $aais$ LANGUAGE plpgsql; 66 | 67 | CREATE FUNCTION adapt_and_insert_shard_placement() RETURNS trigger AS $aaisp$ 68 | BEGIN 69 | INSERT INTO pg_dist_shard_placement 70 | (shardid, 71 | shardstate, 72 | shardlength, 73 | nodename, 74 | nodeport) 75 | VALUES (NEW.shard_id, 76 | NEW.shard_state, 77 | 0, 78 | NEW.node_name, 79 | NEW.node_port) 80 | RETURNING oid INTO STRICT NEW.id; 81 | 82 | RETURN NEW; 83 | END 84 | $aaisp$ LANGUAGE plpgsql; 85 | 86 | CREATE FUNCTION adapt_and_insert_partition() RETURNS trigger AS $aaip$ 87 | BEGIN 88 | INSERT INTO pg_dist_partition 89 | (logicalrelid, 90 | partmethod, 91 | partkey) 92 | VALUES (NEW.relation_id, 93 | NEW.partition_method, 94 | column_name_to_column(NEW.relation_id, NEW.key)); 95 | 96 | RETURN NEW; 97 | END 98 | $aaip$ LANGUAGE plpgsql; 99 | 100 | CREATE FUNCTION adapt_and_update_partition() RETURNS trigger AS $aaup$ 101 | BEGIN 102 | UPDATE pg_dist_partition 103 | SET logicalrelid = NEW.relation_id, 104 | partmethod = NEW.partition_method, 105 | partkey = column_name_to_column(NEW.relation_id, NEW.key) 106 | WHERE logicalrelid = OLD.relation_id; 107 | 108 | RETURN NEW; 109 | END 110 | $aaup$ LANGUAGE plpgsql; 111 | 112 | -- metadata relations are views under CitusDB 113 | CREATE SCHEMA pgs_distribution_metadata 114 | CREATE VIEW shard AS 115 | SELECT shardid AS id, 116 | logicalrelid AS relation_id, 117 | shardstorage AS storage, 118 | shardminvalue AS min_value, 119 | shardmaxvalue AS max_value 120 | FROM pg_dist_shard 121 | 122 | CREATE TRIGGER shard_insert INSTEAD OF INSERT ON shard 123 | FOR EACH ROW 124 | EXECUTE PROCEDURE adapt_and_insert_shard() 125 | 126 | CREATE VIEW shard_placement AS 127 | SELECT oid::bigint AS id, 128 | shardid AS shard_id, 129 | shardstate AS shard_state, 130 | nodename AS node_name, 131 | nodeport AS node_port 132 | FROM pg_dist_shard_placement 133 | 134 | CREATE TRIGGER shard_placement_insert INSTEAD OF INSERT ON shard_placement 135 | FOR EACH ROW 136 | EXECUTE PROCEDURE adapt_and_insert_shard_placement() 137 | 138 | CREATE VIEW partition AS 139 | SELECT logicalrelid AS relation_id, 140 | partmethod AS partition_method, 141 | column_to_column_name(logicalrelid, partkey) AS key 142 | FROM pg_dist_partition 143 | 144 | CREATE TRIGGER partition_insert INSTEAD OF INSERT ON partition 145 | FOR EACH ROW 146 | EXECUTE PROCEDURE adapt_and_insert_partition() 147 | 148 | CREATE TRIGGER partition_update INSTEAD OF UPDATE ON partition 149 | FOR EACH ROW 150 | EXECUTE PROCEDURE adapt_and_update_partition(); 151 | 152 | ELSE 153 | -- add default values to id columns 154 | ALTER TABLE pgs_distribution_metadata.shard 155 | ALTER COLUMN id 156 | SET DEFAULT nextval('pgs_distribution_metadata.shard_id_sequence'); 157 | ALTER TABLE pgs_distribution_metadata.shard_placement 158 | ALTER COLUMN id 159 | SET DEFAULT nextval('pgs_distribution_metadata.shard_placement_id_sequence'); 160 | 161 | -- associate sequences with their columns 162 | ALTER SEQUENCE pgs_distribution_metadata.shard_id_sequence 163 | OWNED BY pgs_distribution_metadata.shard.id; 164 | ALTER SEQUENCE pgs_distribution_metadata.shard_placement_id_sequence 165 | OWNED BY pgs_distribution_metadata.shard_placement.id; 166 | END IF; 167 | END; 168 | $$; 169 | 170 | -- Syncs rows from the pg_shard distribution metadata related to the specified 171 | -- table name into the metadata tables used by CitusDB. After a call to this 172 | -- function for a particular pg_shard table, that table will become usable for 173 | -- queries within CitusDB. If placement health has changed for given pg_shard 174 | -- table, calling this function an additional time will propagate those health 175 | -- changes to the CitusDB metadata tables. 176 | CREATE OR REPLACE FUNCTION sync_table_metadata_to_citus(table_name text) 177 | RETURNS void 178 | AS $sync_table_metadata_to_citus$ 179 | DECLARE 180 | table_relation_id CONSTANT oid NOT NULL := table_name::regclass::oid; 181 | dummy_shard_length CONSTANT bigint := 0; 182 | warning_msg CONSTANT text := 'sync_table_metadata_to_citus is deprecated and ' || 183 | 'will be removed in a future version'; 184 | BEGIN 185 | RAISE WARNING '%', warning_msg; 186 | 187 | -- grab lock to ensure single writer for upsert 188 | LOCK TABLE pg_dist_shard_placement IN EXCLUSIVE MODE; 189 | 190 | -- First, update the health of shard placement rows already copied 191 | -- from pg_shard to CitusDB. Health is the only mutable attribute, 192 | -- so it is presently the only one needing the UPDATE treatment. 193 | UPDATE pg_dist_shard_placement 194 | SET shardstate = shard_placement.shard_state 195 | FROM pgs_distribution_metadata.shard_placement 196 | WHERE shardid = shard_placement.shard_id AND 197 | nodename = shard_placement.node_name AND 198 | nodeport = shard_placement.node_port AND 199 | shardid IN (SELECT shardid 200 | FROM pg_dist_shard 201 | WHERE logicalrelid = table_relation_id); 202 | 203 | -- copy pg_shard placement rows not yet in CitusDB's metadata tables 204 | INSERT INTO pg_dist_shard_placement 205 | (shardid, 206 | shardstate, 207 | shardlength, 208 | nodename, 209 | nodeport) 210 | SELECT shard_id, 211 | shard_state, 212 | dummy_shard_length, 213 | node_name, 214 | node_port 215 | FROM pgs_distribution_metadata.shard_placement 216 | LEFT OUTER JOIN pg_dist_shard_placement 217 | ON ( shardid = shard_placement.shard_id AND 218 | nodename = shard_placement.node_name AND 219 | nodeport = shard_placement.node_port ) 220 | WHERE shardid IS NULL AND 221 | shard_id IN (SELECT id 222 | FROM pgs_distribution_metadata.shard 223 | WHERE relation_id = table_relation_id); 224 | 225 | -- copy pg_shard shard rows not yet in CitusDB's metadata tables 226 | INSERT INTO pg_dist_shard 227 | (shardid, 228 | logicalrelid, 229 | shardstorage, 230 | shardminvalue, 231 | shardmaxvalue) 232 | SELECT id, 233 | relation_id, 234 | storage, 235 | min_value, 236 | max_value 237 | FROM pgs_distribution_metadata.shard 238 | LEFT OUTER JOIN pg_dist_shard 239 | ON ( shardid = shard.id ) 240 | WHERE shardid IS NULL AND 241 | relation_id = table_relation_id; 242 | 243 | -- Finally, copy pg_shard partition rows not yet in CitusDB's metadata 244 | -- tables. CitusDB uses a textual form of a Var node representing the 245 | -- partition column, so we must use a special function to transform the 246 | -- representation used by pg_shard (which is just the column name). 247 | INSERT INTO pg_dist_partition 248 | (logicalrelid, 249 | partmethod, 250 | partkey) 251 | SELECT relation_id, 252 | partition_method, 253 | partition_column_to_node_string(table_relation_id) 254 | FROM pgs_distribution_metadata.partition 255 | LEFT OUTER JOIN pg_dist_partition 256 | ON ( logicalrelid = partition.relation_id ) 257 | WHERE logicalrelid IS NULL AND 258 | relation_id = table_relation_id; 259 | END; 260 | $sync_table_metadata_to_citus$ LANGUAGE 'plpgsql'; 261 | 262 | COMMENT ON FUNCTION sync_table_metadata_to_citus(text) 263 | IS 'synchronize a distributed table''s pg_shard metadata to CitusDB'; 264 | -------------------------------------------------------------------------------- /test/expected/03-extend_ddl_commands.out: -------------------------------------------------------------------------------- 1 | -- =================================================================== 2 | -- create test functions 3 | -- =================================================================== 4 | CREATE FUNCTION extend_ddl_command(regclass, shard_id bigint, command text) 5 | RETURNS cstring 6 | AS 'pg_shard' 7 | LANGUAGE C STRICT; 8 | CREATE FUNCTION extend_name(name cstring, shard_id bigint) 9 | RETURNS cstring 10 | AS 'pg_shard' 11 | LANGUAGE C STRICT; 12 | -- =================================================================== 13 | -- test ddl command extension functionality 14 | -- =================================================================== 15 | -- command extension requires a valid table 16 | CREATE TABLE employees ( 17 | first_name text not null, 18 | last_name text not null, 19 | id bigint PRIMARY KEY, 20 | salary decimal default 0.00 CHECK (salary >= 0.00), 21 | start_date timestamp, 22 | resume text, 23 | mentor_id bigint UNIQUE 24 | ); 25 | -- generate a command to create a regular table on a shard 26 | SELECT extend_ddl_command('employees', 12345, 'CREATE TABLE employees (first_name ' || 27 | 'text NOT NULL, last_name text NOT NULL, id bigint NOT ' || 28 | 'NULL, salary numeric DEFAULT 0.00, start_date timestamp ' || 29 | 'without time zone, resume text, CONSTRAINT sal_check ' || 30 | 'CHECK (salary >= 0.00))'); 31 | extend_ddl_command 32 | -------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- 33 | CREATE TABLE employees_12345 (first_name text NOT NULL, last_name text NOT NULL, id bigint NOT NULL, salary numeric DEFAULT 0.00, start_date timestamp without time zone, resume text, CONSTRAINT sal_check CHECK (salary >= 0.00)) 34 | (1 row) 35 | 36 | -- generate a command to alter a column storage on a shard 37 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ALTER ' || 38 | 'COLUMN resume SET STORAGE EXTERNAL, ALTER COLUMN last_name ' || 39 | 'SET STORAGE EXTERNAL'); 40 | extend_ddl_command 41 | ------------------------------------------------------------------------------------------------------------------------ 42 | ALTER TABLE ONLY employees_12345 ALTER COLUMN resume SET STORAGE external, ALTER COLUMN last_name SET STORAGE external 43 | (1 row) 44 | 45 | -- generate a command to alter a column's statistics target on a shard 46 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ALTER ' || 47 | 'COLUMN resume SET STATISTICS 500'); 48 | extend_ddl_command 49 | ------------------------------------------------------------------------- 50 | ALTER TABLE ONLY employees_12345 ALTER COLUMN resume SET STATISTICS 500 51 | (1 row) 52 | 53 | -- generate a command to create a simple index on a shard 54 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 55 | '(first_name)'); 56 | extend_ddl_command 57 | ------------------------------------------------------------------------- 58 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree (first_name) 59 | (1 row) 60 | 61 | 62 | -- generate a command to create an index using a function call on a shard 63 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 64 | '(lower(first_name))'); 65 | extend_ddl_command 66 | -------------------------------------------------------------------------------- 67 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree (lower(first_name)) 68 | (1 row) 69 | 70 | -- generate a command to create an index using an expression on a shard 71 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 72 | '((first_name || '' '' || last_name))'); 73 | extend_ddl_command 74 | --------------------------------------------------------------------------------------------------------- 75 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree ((((first_name || ' '::text) || last_name))) 76 | (1 row) 77 | 78 | -- generate a command to create an compound index with special ordering on a shard 79 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 80 | '(first_name DESC NULLS FIRST, last_name ASC NULLS LAST)'); 81 | extend_ddl_command 82 | -------------------------------------------------------------------------------------------------------------------- 83 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree (first_name DESC NULLS FIRST, last_name ASC NULLS LAST) 84 | (1 row) 85 | 86 | 87 | -- generate a command to create an index with specific collation on a shard 88 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 89 | '(first_name COLLATE "C")'); 90 | extend_ddl_command 91 | ------------------------------------------------------------------------------------- 92 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree (first_name COLLATE "C") 93 | (1 row) 94 | 95 | -- generate a command to create an index with specific options on a shard 96 | SELECT extend_ddl_command('employees', 12345, 'CREATE INDEX name_idx ON employees ' || 97 | '(first_name) WITH (fillfactor = 70, fastupdate = off)'); 98 | extend_ddl_command 99 | ------------------------------------------------------------------------------------------------------------- 100 | CREATE INDEX name_idx_12345 ON employees_12345 USING btree (first_name) WITH(fillfactor=70, fastupdate=off) 101 | (1 row) 102 | 103 | -- generate a command to cluster a shard's table on a named index 104 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE employees CLUSTER ' || 105 | 'ON start_idx'); 106 | extend_ddl_command 107 | ------------------------------------------------------------- 108 | ALTER TABLE ONLY employees_12345 CLUSTER ON start_idx_12345 109 | (1 row) 110 | 111 | -- generate a command to add a unique constraint on a shard 112 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ADD ' || 113 | 'CONSTRAINT employees_mentor_id_key UNIQUE (mentor_id)'); 114 | extend_ddl_command 115 | -------------------------------------------------------------------------------------------------- 116 | ALTER TABLE ONLY employees_12345 ADD CONSTRAINT employees_mentor_id_key_12345 UNIQUE (mentor_id) 117 | (1 row) 118 | 119 | -- generate a command to add a primary key on a shard 120 | SELECT extend_ddl_command('employees', 12345, 'ALTER TABLE ONLY employees ADD ' || 121 | 'CONSTRAINT employees_pkey PRIMARY KEY (id)'); 122 | extend_ddl_command 123 | --------------------------------------------------------------------------------------- 124 | ALTER TABLE ONLY employees_12345 ADD CONSTRAINT employees_pkey_12345 PRIMARY KEY (id) 125 | (1 row) 126 | 127 | -- generate a command to re-cluster a shard's table on a specific index 128 | SELECT extend_ddl_command('employees', 12345, 'CLUSTER employees USING start_time_idx'); 129 | ERROR: unsupported node type: 714 130 | -- command extension also works with foreign table creation 131 | CREATE FOREIGN TABLE telecommuters ( 132 | id bigint not null, 133 | full_name text not null default '' 134 | ) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true'); 135 | -- generate a command to create a foreign table on a shard 136 | SELECT extend_ddl_command('telecommuters', 54321, 'CREATE FOREIGN TABLE telecommuters ' || 137 | '(id bigint, full_name text) SERVER fake_fdw_server OPTIONS ' || 138 | '(encoding ''utf-8'', compression ''true'')'); 139 | extend_ddl_command 140 | -------------------------------------------------------------------------------------------------------------------------------------------- 141 | CREATE FOREIGN TABLE telecommuters_54321 (id bigint, full_name text) SERVER fake_fdw_server OPTIONS (encoding 'utf-8', compression 'true') 142 | (1 row) 143 | 144 | -- independently test code to append shard identifiers 145 | SELECT extend_name('base_name', 12345678); 146 | extend_name 147 | -------------------- 148 | base_name_12345678 149 | (1 row) 150 | 151 | SELECT extend_name('long_long_long_relation_name_that_could_have_problems_extending', 1); 152 | ERROR: shard name too long to extend: "long_long_long_relation_name_that_could_have_problems_extending" 153 | SELECT extend_name('medium_relation_name_that_only_has_problems_with_large_ids', 1); 154 | extend_name 155 | -------------------------------------------------------------- 156 | medium_relation_name_that_only_has_problems_with_large_ids_1 157 | (1 row) 158 | 159 | SELECT extend_name('medium_relation_name_that_onlyhas_problems_with_large_ids', 12345678); 160 | ERROR: shard name too long to extend: "medium_relation_name_that_onlyhas_problems_with_large_ids" 161 | -- clean up 162 | DROP FOREIGN TABLE IF EXISTS telecommuters; 163 | DROP TABLE IF EXISTS employees; 164 | --------------------------------------------------------------------------------