diff --git a/.github/workflows/build_and_test.yml b/.github/workflows/build_and_test.yml index 2d06e262b..5a99abef1 100644 --- a/.github/workflows/build_and_test.yml +++ b/.github/workflows/build_and_test.yml @@ -32,7 +32,7 @@ jobs: style_checker_image_name: "ghcr.io/citusdata/stylechecker" style_checker_tools_version: "0.8.18" sql_snapshot_pg_version: "17.6" - image_suffix: "-v4df94a0" + image_suffix: "-va20872f" pg15_version: '{ "major": "15", "full": "15.14" }' pg16_version: '{ "major": "16", "full": "16.10" }' pg17_version: '{ "major": "17", "full": "17.6" }' @@ -358,14 +358,20 @@ jobs: flags: ${{ env.old_pg_major }}_${{ env.new_pg_major }}_upgrade codecov_token: ${{ secrets.CODECOV_TOKEN }} test-citus-upgrade: - name: PG${{ fromJson(needs.params.outputs.pg15_version).major }} - check-citus-upgrade + name: PG${{ fromJson(matrix.pg_version).major }} - check-citus-upgrade runs-on: ubuntu-latest container: - image: "${{ needs.params.outputs.citusupgrade_image_name }}:${{ fromJson(needs.params.outputs.pg15_version).full }}${{ needs.params.outputs.image_suffix }}" + image: "${{ needs.params.outputs.citusupgrade_image_name }}:${{ fromJson(matrix.pg_version).full }}${{ needs.params.outputs.image_suffix }}" options: --user root needs: - params - build + strategy: + fail-fast: false + matrix: + pg_version: + - ${{ needs.params.outputs.pg15_version }} + - ${{ needs.params.outputs.pg16_version }} steps: - uses: actions/checkout@v4 - uses: "./.github/actions/setup_extension" @@ -374,7 +380,7 @@ jobs: - name: Install and test citus upgrade run: |- # run make check-citus-upgrade for all citus versions - # the image has ${CITUS_VERSIONS} set with all verions it contains the binaries of + # the image has ${CITUS_VERSIONS} set with all versions it contains the binaries of for citus_version in ${CITUS_VERSIONS}; do \ gosu circleci \ make -C src/test/regress \ @@ -385,7 +391,7 @@ jobs: citus-post-tar=${GITHUB_WORKSPACE}/install-$PG_MAJOR.tar; \ done; # run make check-citus-upgrade-mixed for all citus versions - # the image has ${CITUS_VERSIONS} set with all verions it contains the binaries of + # the image has ${CITUS_VERSIONS} set with all versions it contains the binaries of for citus_version in ${CITUS_VERSIONS}; do \ gosu circleci \ make -C src/test/regress \ diff --git a/.github/workflows/codeql.yml b/.github/workflows/codeql.yml index 51799deab..16d821ffa 100644 --- a/.github/workflows/codeql.yml +++ b/.github/workflows/codeql.yml @@ -60,8 +60,7 @@ jobs: libzstd-dev \ libzstd1 \ lintian \ - postgresql-server-dev-15 \ - postgresql-server-dev-all \ + postgresql-server-dev-17 \ python3-pip \ python3-setuptools \ wget \ diff --git a/CHANGELOG.md b/CHANGELOG.md index a63d6542e..4e2e62d0b 100644 --- a/CHANGELOG.md +++ b/CHANGELOG.md @@ -1,3 +1,48 @@ +### citus v13.1.1 (Oct 1st, 2025) ### + +* Adds support for latest PG minors: 14.19, 15.14, 16.10 (#8142) + +* Fixes an assertion failure when an expression in the query references + a CTE (#8106) + +* Fixes a bug that causes an unexpected error when executing + repartitioned MERGE (#8201) + +* Fixes a bug that causes allowing UPDATE / MERGE queries that may + change the distribution column value (#8214) + +* Updates dynamic_library_path automatically when CDC is enabled (#8025) + +### citus v13.0.5 (Oct 1st, 2025) ### + +* Adds support for latest PG minors: 14.19, 15.14, 16.10 (#7986, #8142) + +* Fixes a bug that causes an unexpected error when executing + repartitioned MERGE (#8201) + +* Fixes a bug that causes allowing UPDATE / MERGE queries that may + change the distribution column value (#8214) + +* Fixes a bug in redundant WHERE clause detection (#8162) + +* Updates dynamic_library_path automatically when CDC is enabled (#8025) + +### citus v12.1.10 (Oct 1, 2025) ### + +* Adds support for latest PG minors: 14.19, 15.14, 16.10 (#7986, #8142) + +* Fixes a bug that causes allowing UPDATE / MERGE queries that may + change the distribution column value (#8214) + +* Fixes an assertion failure that happens when querying a view that is + defined on distributed tables (#8136) + +### citus v12.1.9 (Sep 3, 2025) ### + +* Adds a GUC for queries with outer joins and pseudoconstant quals (#8163) + +* Updates dynamic_library_path automatically when CDC is enabled (#7715) + ### citus v13.2.0 (August 18, 2025) ### * Adds `citus_add_clone_node()`, `citus_add_clone_node_with_nodeid()`, diff --git a/src/backend/columnar/columnar_metadata.c b/src/backend/columnar/columnar_metadata.c index f699553b6..0b4f2400c 100644 --- a/src/backend/columnar/columnar_metadata.c +++ b/src/backend/columnar/columnar_metadata.c @@ -1394,9 +1394,6 @@ static StripeMetadata * UpdateStripeMetadataRow(uint64 storageId, uint64 stripeId, uint64 fileOffset, uint64 dataLength, uint64 rowCount, uint64 chunkCount) { - SnapshotData dirtySnapshot; - InitDirtySnapshot(dirtySnapshot); - ScanKeyData scanKey[2]; ScanKeyInit(&scanKey[0], Anum_columnar_stripe_storageid, BTEqualStrategyNumber, F_INT8EQ, Int64GetDatum(storageId)); @@ -1405,23 +1402,16 @@ UpdateStripeMetadataRow(uint64 storageId, uint64 stripeId, uint64 fileOffset, Oid columnarStripesOid = ColumnarStripeRelationId(); -#if PG_VERSION_NUM >= 180000 - - /* CatalogTupleUpdate performs a normal heap UPDATE → RowExclusiveLock */ - const LOCKMODE openLockMode = RowExclusiveLock; -#else - - /* In‑place update never changed tuple length → AccessShareLock was enough */ - const LOCKMODE openLockMode = AccessShareLock; -#endif - - Relation columnarStripes = table_open(columnarStripesOid, openLockMode); + Relation columnarStripes = table_open(columnarStripesOid, AccessShareLock); TupleDesc tupleDescriptor = RelationGetDescr(columnarStripes); Oid indexId = ColumnarStripePKeyIndexRelationId(); bool indexOk = OidIsValid(indexId); - SysScanDesc scanDescriptor = systable_beginscan(columnarStripes, indexId, indexOk, - &dirtySnapshot, 2, scanKey); + + void *state; + HeapTuple tuple; + systable_inplace_update_begin(columnarStripes, indexId, indexOk, NULL, + 2, scanKey, &tuple, &state); static bool loggedSlowMetadataAccessWarning = false; if (!indexOk && !loggedSlowMetadataAccessWarning) @@ -1430,8 +1420,7 @@ UpdateStripeMetadataRow(uint64 storageId, uint64 stripeId, uint64 fileOffset, loggedSlowMetadataAccessWarning = true; } - HeapTuple oldTuple = systable_getnext(scanDescriptor); - if (!HeapTupleIsValid(oldTuple)) + if (!HeapTupleIsValid(tuple)) { ereport(ERROR, (errmsg("attempted to modify an unexpected stripe, " "columnar storage with id=" UINT64_FORMAT @@ -1439,6 +1428,11 @@ UpdateStripeMetadataRow(uint64 storageId, uint64 stripeId, uint64 fileOffset, storageId, stripeId))); } + /* + * systable_inplace_update_finish already doesn't allow changing size of the original + * tuple, so we don't allow setting any Datum's to NULL values. + */ + Datum *newValues = (Datum *) palloc(tupleDescriptor->natts * sizeof(Datum)); bool *newNulls = (bool *) palloc0(tupleDescriptor->natts * sizeof(bool)); bool *update = (bool *) palloc0(tupleDescriptor->natts * sizeof(bool)); @@ -1453,43 +1447,21 @@ UpdateStripeMetadataRow(uint64 storageId, uint64 stripeId, uint64 fileOffset, newValues[Anum_columnar_stripe_row_count - 1] = UInt64GetDatum(rowCount); newValues[Anum_columnar_stripe_chunk_count - 1] = Int32GetDatum(chunkCount); - HeapTuple modifiedTuple = heap_modify_tuple(oldTuple, - tupleDescriptor, - newValues, - newNulls, - update); + tuple = heap_modify_tuple(tuple, + tupleDescriptor, + newValues, + newNulls, + update); -#if PG_VERSION_NUM < PG_VERSION_18 + systable_inplace_update_finish(state, tuple); - /* - * heap_inplace_update already doesn't allow changing size of the original - * tuple, so we don't allow setting any Datum's to NULL values. - */ - heap_inplace_update(columnarStripes, modifiedTuple); - - /* - * Existing tuple now contains modifications, because we used - * heap_inplace_update(). - */ - HeapTuple newTuple = oldTuple; -#else - - /* Regular catalog UPDATE keeps indexes in sync */ - CatalogTupleUpdate(columnarStripes, &oldTuple->t_self, modifiedTuple); - HeapTuple newTuple = modifiedTuple; -#endif + StripeMetadata *modifiedStripeMetadata = BuildStripeMetadata(columnarStripes, + tuple); CommandCounterIncrement(); - /* - * Must not pass modifiedTuple, because BuildStripeMetadata expects a real - * heap tuple with MVCC fields. - */ - StripeMetadata *modifiedStripeMetadata = - BuildStripeMetadata(columnarStripes, newTuple); - - systable_endscan(scanDescriptor); - table_close(columnarStripes, openLockMode); + heap_freetuple(tuple); + table_close(columnarStripes, AccessShareLock); pfree(newValues); pfree(newNulls); diff --git a/src/backend/columnar/columnar_tableam.c b/src/backend/columnar/columnar_tableam.c index 2b11dd27a..1158005c8 100644 --- a/src/backend/columnar/columnar_tableam.c +++ b/src/backend/columnar/columnar_tableam.c @@ -1245,10 +1245,14 @@ LogRelationStats(Relation rel, int elevel) foreach(stripeMetadataCell, stripeList) { StripeMetadata *stripe = lfirst(stripeMetadataCell); + + Snapshot snapshot = RegisterSnapshot(GetTransactionSnapshot()); StripeSkipList *skiplist = ReadStripeSkipList(relfilelocator, stripe->id, RelationGetDescr(rel), stripe->chunkCount, - GetTransactionSnapshot()); + snapshot); + UnregisterSnapshot(snapshot); + for (uint32 column = 0; column < skiplist->columnCount; column++) { bool attrDropped = Attr(tupdesc, column)->attisdropped; diff --git a/src/backend/distributed/commands/common.c b/src/backend/distributed/commands/common.c index de05efe45..10cef8308 100644 --- a/src/backend/distributed/commands/common.c +++ b/src/backend/distributed/commands/common.c @@ -19,6 +19,7 @@ #include "nodes/parsenodes.h" #include "tcop/utility.h" +#include "distributed/citus_depended_object.h" #include "distributed/commands.h" #include "distributed/commands/utility_hook.h" #include "distributed/deparser.h" @@ -63,6 +64,13 @@ PostprocessCreateDistributedObjectFromCatalogStmt(Node *stmt, const char *queryS return NIL; } + if (ops->qualify && DistOpsValidityState(stmt, ops) == + ShouldQualifyAfterLocalCreation) + { + /* qualify the statement after local creation */ + ops->qualify(stmt); + } + List *addresses = GetObjectAddressListFromParseTree(stmt, false, true); /* the code-path only supports a single object */ diff --git a/src/backend/distributed/deparser/qualify_statistics_stmt.c b/src/backend/distributed/deparser/qualify_statistics_stmt.c index 7a99e6dfa..7243762dc 100644 --- a/src/backend/distributed/deparser/qualify_statistics_stmt.c +++ b/src/backend/distributed/deparser/qualify_statistics_stmt.c @@ -34,7 +34,14 @@ QualifyCreateStatisticsStmt(Node *node) { CreateStatsStmt *stmt = castNode(CreateStatsStmt, node); - RangeVar *relation = (RangeVar *) linitial(stmt->relations); + Node *relationNode = (Node *) linitial(stmt->relations); + + if (!IsA(relationNode, RangeVar)) + { + return; + } + + RangeVar *relation = (RangeVar *) relationNode; if (relation->schemaname == NULL) { diff --git a/src/backend/distributed/planner/distributed_planner.c b/src/backend/distributed/planner/distributed_planner.c index a15c3eede..be046bf9b 100644 --- a/src/backend/distributed/planner/distributed_planner.c +++ b/src/backend/distributed/planner/distributed_planner.c @@ -13,6 +13,7 @@ #include "postgres.h" #include "funcapi.h" +#include "miscadmin.h" #include "access/htup_details.h" #include "access/xact.h" @@ -144,6 +145,9 @@ static void ConcatenateRTablesAndPerminfos(PlannedStmt *mainPlan, static bool CheckPostPlanDistribution(DistributedPlanningContext *planContext, bool isDistributedQuery, List *rangeTableList); +#if PG_VERSION_NUM >= PG_VERSION_18 +static int DisableSelfJoinElimination(void); +#endif /* Distributed planner hook */ PlannedStmt * @@ -155,6 +159,9 @@ distributed_planner(Query *parse, bool needsDistributedPlanning = false; bool fastPathRouterQuery = false; FastPathRestrictionContext fastPathContext = { 0 }; +#if PG_VERSION_NUM >= PG_VERSION_18 + int saveNestLevel = -1; +#endif List *rangeTableList = ExtractRangeTableEntryList(parse); @@ -218,6 +225,10 @@ distributed_planner(Query *parse, bool setPartitionedTablesInherited = false; AdjustPartitioningForDistributedPlanning(rangeTableList, setPartitionedTablesInherited); + +#if PG_VERSION_NUM >= PG_VERSION_18 + saveNestLevel = DisableSelfJoinElimination(); +#endif } } @@ -264,6 +275,13 @@ distributed_planner(Query *parse, planContext.plan = standard_planner(planContext.query, NULL, planContext.cursorOptions, planContext.boundParams); +#if PG_VERSION_NUM >= PG_VERSION_18 + if (needsDistributedPlanning) + { + Assert(saveNestLevel > 0); + AtEOXact_GUC(true, saveNestLevel); + } +#endif needsDistributedPlanning = CheckPostPlanDistribution(&planContext, needsDistributedPlanning, rangeTableList); @@ -2791,3 +2809,27 @@ CheckPostPlanDistribution(DistributedPlanningContext *planContext, bool return isDistributedQuery; } + + +#if PG_VERSION_NUM >= PG_VERSION_18 + +/* + * DisableSelfJoinElimination is used to prevent self join elimination + * during distributed query planning to ensure shard queries are correctly + * generated. PG18's self join elimination (fc069a3a6) changes the Query + * in a way that can cause problems for queries with a mix of Citus and + * Postgres tables. Self join elimination is allowed on Postgres tables + * only so queries involving shards get the benefit of it. + */ +static int +DisableSelfJoinElimination(void) +{ + int NestLevel = NewGUCNestLevel(); + set_config_option("enable_self_join_elimination", "off", + (superuser() ? PGC_SUSET : PGC_USERSET), PGC_S_SESSION, + GUC_ACTION_LOCAL, true, 0, false); + return NestLevel; +} + + +#endif diff --git a/src/backend/distributed/planner/insert_select_planner.c b/src/backend/distributed/planner/insert_select_planner.c index 1cf996b77..1cd4161b6 100644 --- a/src/backend/distributed/planner/insert_select_planner.c +++ b/src/backend/distributed/planner/insert_select_planner.c @@ -428,11 +428,10 @@ CreateInsertSelectIntoLocalTablePlan(uint64 planId, Query *insertSelectQuery, ParamListInfo boundParams, bool hasUnresolvedParams, PlannerRestrictionContext *plannerRestrictionContext) { - RangeTblEntry *selectRte = ExtractSelectRangeTableEntry(insertSelectQuery); - PrepareInsertSelectForCitusPlanner(insertSelectQuery); /* get the SELECT query (may have changed after PrepareInsertSelectForCitusPlanner) */ + RangeTblEntry *selectRte = ExtractSelectRangeTableEntry(insertSelectQuery); Query *selectQuery = selectRte->subquery; bool allowRecursivePlanning = true; @@ -513,6 +512,24 @@ PrepareInsertSelectForCitusPlanner(Query *insertSelectQuery) bool isWrapped = false; +#if PG_VERSION_NUM >= PG_VERSION_18 + +/* + * PG18 is stricter about GroupRTE/GroupVar. For INSERT … SELECT with a GROUP BY, + * flatten the SELECT’s targetList and havingQual so Vars point to base RTEs and + * avoid Unrecognized range table id. + */ + if (selectRte->subquery->hasGroupRTE) + { + Query *selectQuery = selectRte->subquery; + selectQuery->targetList = (List *) + flatten_group_exprs(NULL, selectQuery, + (Node *) selectQuery->targetList); + selectQuery->havingQual = + flatten_group_exprs(NULL, selectQuery, selectQuery->havingQual); + } +#endif + if (selectRte->subquery->setOperations != NULL) { /* @@ -1431,11 +1448,6 @@ static DistributedPlan * CreateNonPushableInsertSelectPlan(uint64 planId, Query *parse, ParamListInfo boundParams) { Query *insertSelectQuery = copyObject(parse); - - RangeTblEntry *selectRte = ExtractSelectRangeTableEntry(insertSelectQuery); - RangeTblEntry *insertRte = ExtractResultRelationRTEOrError(insertSelectQuery); - Oid targetRelationId = insertRte->relid; - DistributedPlan *distributedPlan = CitusMakeNode(DistributedPlan); distributedPlan->modLevel = RowModifyLevelForQuery(insertSelectQuery); @@ -1450,6 +1462,7 @@ CreateNonPushableInsertSelectPlan(uint64 planId, Query *parse, ParamListInfo bou PrepareInsertSelectForCitusPlanner(insertSelectQuery); /* get the SELECT query (may have changed after PrepareInsertSelectForCitusPlanner) */ + RangeTblEntry *selectRte = ExtractSelectRangeTableEntry(insertSelectQuery); Query *selectQuery = selectRte->subquery; /* @@ -1472,6 +1485,9 @@ CreateNonPushableInsertSelectPlan(uint64 planId, Query *parse, ParamListInfo bou PlannedStmt *selectPlan = pg_plan_query(selectQueryCopy, NULL, cursorOptions, boundParams); + /* decide whether we can repartition the results */ + RangeTblEntry *insertRte = ExtractResultRelationRTEOrError(insertSelectQuery); + Oid targetRelationId = insertRte->relid; bool repartitioned = IsRedistributablePlan(selectPlan->planTree) && IsSupportedRedistributionTarget(targetRelationId); diff --git a/src/backend/distributed/planner/multi_explain.c b/src/backend/distributed/planner/multi_explain.c index 4d27939f7..d11aae02f 100644 --- a/src/backend/distributed/planner/multi_explain.c +++ b/src/backend/distributed/planner/multi_explain.c @@ -149,13 +149,6 @@ typedef struct ExplainAnalyzeDestination #if PG_VERSION_NUM >= PG_VERSION_17 && PG_VERSION_NUM < PG_VERSION_18 -/* - * Various places within need to convert bytes to kilobytes. Round these up - * to the next whole kilobyte. - * copied from explain.c - */ -#define BYTES_TO_KILOBYTES(b) (((b) + 1023) / 1024) - /* copied from explain.c */ /* Instrumentation data for SERIALIZE option */ typedef struct SerializeMetrics @@ -166,13 +159,7 @@ typedef struct SerializeMetrics } SerializeMetrics; /* copied from explain.c */ -static bool peek_buffer_usage(ExplainState *es, const BufferUsage *usage); -static void show_buffer_usage(ExplainState *es, const BufferUsage *usage); -static void show_memory_counters(ExplainState *es, - const MemoryContextCounters *mem_counters); static void ExplainIndentText(ExplainState *es); -static void ExplainPrintSerialize(ExplainState *es, - SerializeMetrics *metrics); static SerializeMetrics GetSerializationMetrics(DestReceiver *dest); /* @@ -200,6 +187,23 @@ typedef struct SerializeDestReceiver } SerializeDestReceiver; #endif +#if PG_VERSION_NUM >= PG_VERSION_17 + +/* + * Various places within need to convert bytes to kilobytes. Round these up + * to the next whole kilobyte. + * copied from explain.c + */ +#define BYTES_TO_KILOBYTES(b) (((b) + 1023) / 1024) + +/* copied from explain.c */ +static bool peek_buffer_usage(ExplainState *es, const BufferUsage *usage); +static void show_buffer_usage(ExplainState *es, const BufferUsage *usage); +static void show_memory_counters(ExplainState *es, + const MemoryContextCounters *mem_counters); +static void ExplainPrintSerialize(ExplainState *es, + SerializeMetrics *metrics); +#endif /* Explain functions for distributed queries */ static void ExplainSubPlans(DistributedPlan *distributedPlan, ExplainState *es); @@ -2409,7 +2413,7 @@ ExplainWorkerPlan(PlannedStmt *plannedstmt, DistributedSubPlan *subPlan, DestRec /* Create textual dump of plan tree */ ExplainPrintPlan(es, queryDesc); -#if PG_VERSION_NUM >= PG_VERSION_17 && PG_VERSION_NUM < PG_VERSION_18 +#if PG_VERSION_NUM >= PG_VERSION_17 /* Show buffer and/or memory usage in planning */ if (peek_buffer_usage(es, bufusage) || mem_counters) { @@ -2455,7 +2459,7 @@ ExplainWorkerPlan(PlannedStmt *plannedstmt, DistributedSubPlan *subPlan, DestRec if (es->costs) ExplainPrintJITSummary(es, queryDesc); -#if PG_VERSION_NUM >= PG_VERSION_17 && PG_VERSION_NUM < PG_VERSION_18 +#if PG_VERSION_NUM >= PG_VERSION_17 if (es->serialize != EXPLAIN_SERIALIZE_NONE) { /* the SERIALIZE option requires its own tuple receiver */ @@ -2530,6 +2534,50 @@ elapsed_time(instr_time *starttime) #if PG_VERSION_NUM >= PG_VERSION_17 && PG_VERSION_NUM < PG_VERSION_18 +/* + * Indent a text-format line. + * + * We indent by two spaces per indentation level. However, when emitting + * data for a parallel worker there might already be data on the current line + * (cf. ExplainOpenWorker); in that case, don't indent any more. + * + * Copied from explain.c. + */ +static void +ExplainIndentText(ExplainState *es) +{ + Assert(es->format == EXPLAIN_FORMAT_TEXT); + if (es->str->len == 0 || es->str->data[es->str->len - 1] == '\n') + appendStringInfoSpaces(es->str, es->indent * 2); +} + + +/* + * GetSerializationMetrics - collect metrics + * + * We have to be careful here since the receiver could be an IntoRel + * receiver if the subject statement is CREATE TABLE AS. In that + * case, return all-zeroes stats. + * + * Copied from explain.c. + */ +static SerializeMetrics +GetSerializationMetrics(DestReceiver *dest) +{ + SerializeMetrics empty; + + if (dest->mydest == DestExplainSerialize) + return ((SerializeDestReceiver *) dest)->metrics; + + memset(&empty, 0, sizeof(SerializeMetrics)); + INSTR_TIME_SET_ZERO(empty.timeSpent); + + return empty; +} +#endif + + +#if PG_VERSION_NUM >= PG_VERSION_17 /* * Return whether show_buffer_usage would have anything to print, if given * the same 'usage' data. Note that when the format is anything other than @@ -2747,24 +2795,6 @@ show_buffer_usage(ExplainState *es, const BufferUsage *usage) } -/* - * Indent a text-format line. - * - * We indent by two spaces per indentation level. However, when emitting - * data for a parallel worker there might already be data on the current line - * (cf. ExplainOpenWorker); in that case, don't indent any more. - * - * Copied from explain.c. - */ -static void -ExplainIndentText(ExplainState *es) -{ - Assert(es->format == EXPLAIN_FORMAT_TEXT); - if (es->str->len == 0 || es->str->data[es->str->len - 1] == '\n') - appendStringInfoSpaces(es->str, es->indent * 2); -} - - /* * Show memory usage details. * @@ -2850,28 +2880,4 @@ ExplainPrintSerialize(ExplainState *es, SerializeMetrics *metrics) ExplainCloseGroup("Serialization", "Serialization", true, es); } - - -/* - * GetSerializationMetrics - collect metrics - * - * We have to be careful here since the receiver could be an IntoRel - * receiver if the subject statement is CREATE TABLE AS. In that - * case, return all-zeroes stats. - * - * Copied from explain.c. - */ -static SerializeMetrics -GetSerializationMetrics(DestReceiver *dest) -{ - SerializeMetrics empty; - - if (dest->mydest == DestExplainSerialize) - return ((SerializeDestReceiver *) dest)->metrics; - - memset(&empty, 0, sizeof(SerializeMetrics)); - INSTR_TIME_SET_ZERO(empty.timeSpent); - - return empty; -} #endif diff --git a/src/backend/distributed/sql/citus--13.2-1--14.0-1.sql b/src/backend/distributed/sql/citus--13.2-1--14.0-1.sql index ebf34b7fd..815d4e794 100644 --- a/src/backend/distributed/sql/citus--13.2-1--14.0-1.sql +++ b/src/backend/distributed/sql/citus--13.2-1--14.0-1.sql @@ -1,2 +1,5 @@ -- citus--13.2-1--14.0-1 -- bump version to 14.0-1 + +#include "udfs/citus_prepare_pg_upgrade/14.0-1.sql" +#include "udfs/citus_finish_pg_upgrade/14.0-1.sql" diff --git a/src/backend/distributed/sql/downgrades/citus--14.0-1--13.2-1.sql b/src/backend/distributed/sql/downgrades/citus--14.0-1--13.2-1.sql index 3ef630c4b..199030339 100644 --- a/src/backend/distributed/sql/downgrades/citus--14.0-1--13.2-1.sql +++ b/src/backend/distributed/sql/downgrades/citus--14.0-1--13.2-1.sql @@ -1,2 +1,5 @@ -- citus--14.0-1--13.2-1 -- downgrade version to 13.2-1 + +#include "../udfs/citus_prepare_pg_upgrade/13.0-1.sql" +#include "../udfs/citus_finish_pg_upgrade/13.2-1.sql" diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/14.0-1.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/14.0-1.sql new file mode 100644 index 000000000..4bad681eb --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/14.0-1.sql @@ -0,0 +1,268 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_finish_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +DECLARE + table_name regclass; + command text; + trigger_name text; +BEGIN + + + IF substring(current_Setting('server_version'), '\d+')::int >= 14 THEN + EXECUTE $cmd$ + -- disable propagation to prevent EnsureCoordinator errors + -- the aggregate created here does not depend on Citus extension (yet) + -- since we add the dependency with the next command + SET citus.enable_ddl_propagation TO OFF; + CREATE AGGREGATE array_cat_agg(anycompatiblearray) (SFUNC = array_cat, STYPE = anycompatiblearray); + COMMENT ON AGGREGATE array_cat_agg(anycompatiblearray) + IS 'concatenate input arrays into a single array'; + RESET citus.enable_ddl_propagation; + $cmd$; + ELSE + EXECUTE $cmd$ + SET citus.enable_ddl_propagation TO OFF; + CREATE AGGREGATE array_cat_agg(anyarray) (SFUNC = array_cat, STYPE = anyarray); + COMMENT ON AGGREGATE array_cat_agg(anyarray) + IS 'concatenate input arrays into a single array'; + RESET citus.enable_ddl_propagation; + $cmd$; + END IF; + + -- + -- Citus creates the array_cat_agg but because of a compatibility + -- issue between pg13-pg14, we drop and create it during upgrade. + -- And as Citus creates it, there needs to be a dependency to the + -- Citus extension, so we create that dependency here. + -- We are not using: + -- ALTER EXENSION citus DROP/CREATE AGGREGATE array_cat_agg + -- because we don't have an easy way to check if the aggregate + -- exists with anyarray type or anycompatiblearray type. + + INSERT INTO pg_depend + SELECT + 'pg_proc'::regclass::oid as classid, + (SELECT oid FROM pg_proc WHERE proname = 'array_cat_agg') as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'e' as deptype; + + -- PG16 has its own any_value, so only create it pre PG16. + -- We can remove this part when we drop support for PG16 + IF substring(current_Setting('server_version'), '\d+')::int < 16 THEN + EXECUTE $cmd$ + -- disable propagation to prevent EnsureCoordinator errors + -- the aggregate created here does not depend on Citus extension (yet) + -- since we add the dependency with the next command + SET citus.enable_ddl_propagation TO OFF; + CREATE OR REPLACE FUNCTION pg_catalog.any_value_agg ( anyelement, anyelement ) + RETURNS anyelement AS $$ + SELECT CASE WHEN $1 IS NULL THEN $2 ELSE $1 END; + $$ LANGUAGE SQL STABLE; + + CREATE AGGREGATE pg_catalog.any_value ( + sfunc = pg_catalog.any_value_agg, + combinefunc = pg_catalog.any_value_agg, + basetype = anyelement, + stype = anyelement + ); + COMMENT ON AGGREGATE pg_catalog.any_value(anyelement) IS + 'Returns the value of any row in the group. It is mostly useful when you know there will be only 1 element.'; + RESET citus.enable_ddl_propagation; + -- + -- Citus creates the any_value aggregate but because of a compatibility + -- issue between pg15-pg16 -- any_value is created in PG16, we drop + -- and create it during upgrade IF upgraded version is less than 16. + -- And as Citus creates it, there needs to be a dependency to the + -- Citus extension, so we create that dependency here. + + INSERT INTO pg_depend + SELECT + 'pg_proc'::regclass::oid as classid, + (SELECT oid FROM pg_proc WHERE proname = 'any_value_agg') as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'e' as deptype; + + INSERT INTO pg_depend + SELECT + 'pg_proc'::regclass::oid as classid, + (SELECT oid FROM pg_proc WHERE proname = 'any_value') as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'e' as deptype; + $cmd$; + END IF; + + -- + -- restore citus catalog tables + -- + INSERT INTO pg_catalog.pg_dist_partition SELECT * FROM public.pg_dist_partition; + + -- if we are upgrading from PG14/PG15 to PG16+, + -- we need to regenerate the partkeys because they will include varnullingrels as well. + UPDATE pg_catalog.pg_dist_partition + SET partkey = column_name_to_column(pg_dist_partkeys_pre_16_upgrade.logicalrelid, col_name) + FROM public.pg_dist_partkeys_pre_16_upgrade + WHERE pg_dist_partkeys_pre_16_upgrade.logicalrelid = pg_dist_partition.logicalrelid; + DROP TABLE public.pg_dist_partkeys_pre_16_upgrade; + + -- if we are upgrading to PG18+, + -- we need to regenerate the partkeys because they will include varreturningtype as well. + UPDATE pg_catalog.pg_dist_partition + SET partkey = column_name_to_column(pg_dist_partkeys_pre_18_upgrade.logicalrelid, col_name) + FROM public.pg_dist_partkeys_pre_18_upgrade + WHERE pg_dist_partkeys_pre_18_upgrade.logicalrelid = pg_dist_partition.logicalrelid; + DROP TABLE public.pg_dist_partkeys_pre_18_upgrade; + + INSERT INTO pg_catalog.pg_dist_shard SELECT * FROM public.pg_dist_shard; + INSERT INTO pg_catalog.pg_dist_placement SELECT * FROM public.pg_dist_placement; + INSERT INTO pg_catalog.pg_dist_node_metadata SELECT * FROM public.pg_dist_node_metadata; + INSERT INTO pg_catalog.pg_dist_node SELECT * FROM public.pg_dist_node; + INSERT INTO pg_catalog.pg_dist_local_group SELECT * FROM public.pg_dist_local_group; + INSERT INTO pg_catalog.pg_dist_transaction SELECT * FROM public.pg_dist_transaction; + INSERT INTO pg_catalog.pg_dist_colocation SELECT * FROM public.pg_dist_colocation; + INSERT INTO pg_catalog.pg_dist_cleanup SELECT * FROM public.pg_dist_cleanup; + INSERT INTO pg_catalog.pg_dist_schema SELECT schemaname::regnamespace, colocationid FROM public.pg_dist_schema; + -- enterprise catalog tables + INSERT INTO pg_catalog.pg_dist_authinfo SELECT * FROM public.pg_dist_authinfo; + INSERT INTO pg_catalog.pg_dist_poolinfo SELECT * FROM public.pg_dist_poolinfo; + + -- Temporarily disable trigger to check for validity of functions while + -- inserting. The current contents of the table might be invalid if one of + -- the functions was removed by the user without also removing the + -- rebalance strategy. Obviously that's not great, but it should be no + -- reason to fail the upgrade. + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy DISABLE TRIGGER pg_dist_rebalance_strategy_validation_trigger; + INSERT INTO pg_catalog.pg_dist_rebalance_strategy SELECT + name, + default_strategy, + shard_cost_function::regprocedure::regproc, + node_capacity_function::regprocedure::regproc, + shard_allowed_on_node_function::regprocedure::regproc, + default_threshold, + minimum_threshold, + improvement_threshold + FROM public.pg_dist_rebalance_strategy; + ALTER TABLE pg_catalog.pg_dist_rebalance_strategy ENABLE TRIGGER pg_dist_rebalance_strategy_validation_trigger; + + -- + -- drop backup tables + -- + DROP TABLE public.pg_dist_authinfo; + DROP TABLE public.pg_dist_colocation; + DROP TABLE public.pg_dist_local_group; + DROP TABLE public.pg_dist_node; + DROP TABLE public.pg_dist_node_metadata; + DROP TABLE public.pg_dist_partition; + DROP TABLE public.pg_dist_placement; + DROP TABLE public.pg_dist_poolinfo; + DROP TABLE public.pg_dist_shard; + DROP TABLE public.pg_dist_transaction; + DROP TABLE public.pg_dist_rebalance_strategy; + DROP TABLE public.pg_dist_cleanup; + DROP TABLE public.pg_dist_schema; + -- + -- reset sequences + -- + PERFORM setval('pg_catalog.pg_dist_shardid_seq', (SELECT MAX(shardid)+1 AS max_shard_id FROM pg_dist_shard), false); + PERFORM setval('pg_catalog.pg_dist_placement_placementid_seq', (SELECT MAX(placementid)+1 AS max_placement_id FROM pg_dist_placement), false); + PERFORM setval('pg_catalog.pg_dist_groupid_seq', (SELECT MAX(groupid)+1 AS max_group_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_node_nodeid_seq', (SELECT MAX(nodeid)+1 AS max_node_id FROM pg_dist_node), false); + PERFORM setval('pg_catalog.pg_dist_colocationid_seq', (SELECT MAX(colocationid)+1 AS max_colocation_id FROM pg_dist_colocation), false); + PERFORM setval('pg_catalog.pg_dist_operationid_seq', (SELECT MAX(operation_id)+1 AS max_operation_id FROM pg_dist_cleanup), false); + PERFORM setval('pg_catalog.pg_dist_cleanup_recordid_seq', (SELECT MAX(record_id)+1 AS max_record_id FROM pg_dist_cleanup), false); + PERFORM setval('pg_catalog.pg_dist_clock_logical_seq', (SELECT last_value FROM public.pg_dist_clock_logical_seq), false); + DROP TABLE public.pg_dist_clock_logical_seq; + + + + -- + -- register triggers + -- + FOR table_name IN SELECT logicalrelid FROM pg_catalog.pg_dist_partition JOIN pg_class ON (logicalrelid = oid) WHERE relkind <> 'f' + LOOP + trigger_name := 'truncate_trigger_' || table_name::oid; + command := 'create trigger ' || trigger_name || ' after truncate on ' || table_name || ' execute procedure pg_catalog.citus_truncate_trigger()'; + EXECUTE command; + command := 'update pg_trigger set tgisinternal = true where tgname = ' || quote_literal(trigger_name); + EXECUTE command; + END LOOP; + + -- + -- set dependencies + -- + INSERT INTO pg_depend + SELECT + 'pg_class'::regclass::oid as classid, + p.logicalrelid::regclass::oid as objid, + 0 as objsubid, + 'pg_extension'::regclass::oid as refclassid, + (select oid from pg_extension where extname = 'citus') as refobjid, + 0 as refobjsubid , + 'n' as deptype + FROM pg_catalog.pg_dist_partition p; + + -- If citus_columnar extension exists, then perform the post PG-upgrade work for columnar as well. + -- + -- First look if pg_catalog.columnar_finish_pg_upgrade function exists as part of the citus_columnar + -- extension. (We check whether it's part of the extension just for security reasons). If it does, then + -- call it. If not, then look for columnar_internal.columnar_ensure_am_depends_catalog function and as + -- part of the citus_columnar extension. If so, then call it. We alternatively check for the latter UDF + -- just because pg_catalog.columnar_finish_pg_upgrade function is introduced in citus_columnar 13.2-1 + -- and as of today all it does is to call columnar_internal.columnar_ensure_am_depends_catalog function. + IF EXISTS ( + SELECT 1 FROM pg_depend + JOIN pg_proc ON (pg_depend.objid = pg_proc.oid) + JOIN pg_namespace ON (pg_proc.pronamespace = pg_namespace.oid) + JOIN pg_extension ON (pg_depend.refobjid = pg_extension.oid) + WHERE + -- Looking if pg_catalog.columnar_finish_pg_upgrade function exists and + -- if there is a dependency record from it (proc class = 1255) .. + pg_depend.classid = 1255 AND pg_namespace.nspname = 'pg_catalog' AND pg_proc.proname = 'columnar_finish_pg_upgrade' AND + -- .. to citus_columnar extension (3079 = extension class), if it exists. + pg_depend.refclassid = 3079 AND pg_extension.extname = 'citus_columnar' + ) + THEN PERFORM pg_catalog.columnar_finish_pg_upgrade(); + ELSIF EXISTS ( + SELECT 1 FROM pg_depend + JOIN pg_proc ON (pg_depend.objid = pg_proc.oid) + JOIN pg_namespace ON (pg_proc.pronamespace = pg_namespace.oid) + JOIN pg_extension ON (pg_depend.refobjid = pg_extension.oid) + WHERE + -- Looking if columnar_internal.columnar_ensure_am_depends_catalog function exists and + -- if there is a dependency record from it (proc class = 1255) .. + pg_depend.classid = 1255 AND pg_namespace.nspname = 'columnar_internal' AND pg_proc.proname = 'columnar_ensure_am_depends_catalog' AND + -- .. to citus_columnar extension (3079 = extension class), if it exists. + pg_depend.refclassid = 3079 AND pg_extension.extname = 'citus_columnar' + ) + THEN PERFORM columnar_internal.columnar_ensure_am_depends_catalog(); + END IF; + + -- restore pg_dist_object from the stable identifiers + TRUNCATE pg_catalog.pg_dist_object; + INSERT INTO pg_catalog.pg_dist_object (classid, objid, objsubid, distribution_argument_index, colocationid) + SELECT + address.classid, + address.objid, + address.objsubid, + naming.distribution_argument_index, + naming.colocationid + FROM + public.pg_dist_object naming, + pg_catalog.pg_get_object_address(naming.type, naming.object_names, naming.object_args) address; + + DROP TABLE public.pg_dist_object; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_finish_pg_upgrade() + IS 'perform tasks to restore citus settings from a location that has been prepared before pg_upgrade'; diff --git a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql index 38daeb86c..4bad681eb 100644 --- a/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql +++ b/src/backend/distributed/sql/udfs/citus_finish_pg_upgrade/latest.sql @@ -115,6 +115,14 @@ BEGIN WHERE pg_dist_partkeys_pre_16_upgrade.logicalrelid = pg_dist_partition.logicalrelid; DROP TABLE public.pg_dist_partkeys_pre_16_upgrade; + -- if we are upgrading to PG18+, + -- we need to regenerate the partkeys because they will include varreturningtype as well. + UPDATE pg_catalog.pg_dist_partition + SET partkey = column_name_to_column(pg_dist_partkeys_pre_18_upgrade.logicalrelid, col_name) + FROM public.pg_dist_partkeys_pre_18_upgrade + WHERE pg_dist_partkeys_pre_18_upgrade.logicalrelid = pg_dist_partition.logicalrelid; + DROP TABLE public.pg_dist_partkeys_pre_18_upgrade; + INSERT INTO pg_catalog.pg_dist_shard SELECT * FROM public.pg_dist_shard; INSERT INTO pg_catalog.pg_dist_placement SELECT * FROM public.pg_dist_placement; INSERT INTO pg_catalog.pg_dist_node_metadata SELECT * FROM public.pg_dist_node_metadata; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/14.0-1.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/14.0-1.sql new file mode 100644 index 000000000..ee5e98e1d --- /dev/null +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/14.0-1.sql @@ -0,0 +1,111 @@ +CREATE OR REPLACE FUNCTION pg_catalog.citus_prepare_pg_upgrade() + RETURNS void + LANGUAGE plpgsql + SET search_path = pg_catalog + AS $cppu$ +BEGIN + + DELETE FROM pg_depend WHERE + objid IN (SELECT oid FROM pg_proc WHERE proname = 'array_cat_agg') AND + refobjid IN (select oid from pg_extension where extname = 'citus'); + -- + -- We are dropping the aggregates because postgres 14 changed + -- array_cat type from anyarray to anycompatiblearray. When + -- upgrading to pg14, specifically when running pg_restore on + -- array_cat_agg we would get an error. So we drop the aggregate + -- and create the right one on citus_finish_pg_upgrade. + + DROP AGGREGATE IF EXISTS array_cat_agg(anyarray); + DROP AGGREGATE IF EXISTS array_cat_agg(anycompatiblearray); + + -- We should drop any_value because PG16+ has its own any_value function + -- We can remove this part when we drop support for PG16 + IF substring(current_Setting('server_version'), '\d+')::int < 16 THEN + DELETE FROM pg_depend WHERE + objid IN (SELECT oid FROM pg_proc WHERE proname = 'any_value' OR proname = 'any_value_agg') AND + refobjid IN (select oid from pg_extension where extname = 'citus'); + DROP AGGREGATE IF EXISTS pg_catalog.any_value(anyelement); + DROP FUNCTION IF EXISTS pg_catalog.any_value_agg(anyelement, anyelement); + END IF; + + -- + -- Drop existing backup tables + -- + DROP TABLE IF EXISTS public.pg_dist_partition; + DROP TABLE IF EXISTS public.pg_dist_shard; + DROP TABLE IF EXISTS public.pg_dist_placement; + DROP TABLE IF EXISTS public.pg_dist_node_metadata; + DROP TABLE IF EXISTS public.pg_dist_node; + DROP TABLE IF EXISTS public.pg_dist_local_group; + DROP TABLE IF EXISTS public.pg_dist_transaction; + DROP TABLE IF EXISTS public.pg_dist_colocation; + DROP TABLE IF EXISTS public.pg_dist_authinfo; + DROP TABLE IF EXISTS public.pg_dist_poolinfo; + DROP TABLE IF EXISTS public.pg_dist_rebalance_strategy; + DROP TABLE IF EXISTS public.pg_dist_object; + DROP TABLE IF EXISTS public.pg_dist_cleanup; + DROP TABLE IF EXISTS public.pg_dist_schema; + DROP TABLE IF EXISTS public.pg_dist_clock_logical_seq; + + -- + -- backup citus catalog tables + -- + CREATE TABLE public.pg_dist_partition AS SELECT * FROM pg_catalog.pg_dist_partition; + CREATE TABLE public.pg_dist_shard AS SELECT * FROM pg_catalog.pg_dist_shard; + CREATE TABLE public.pg_dist_placement AS SELECT * FROM pg_catalog.pg_dist_placement; + CREATE TABLE public.pg_dist_node_metadata AS SELECT * FROM pg_catalog.pg_dist_node_metadata; + CREATE TABLE public.pg_dist_node AS SELECT * FROM pg_catalog.pg_dist_node; + CREATE TABLE public.pg_dist_local_group AS SELECT * FROM pg_catalog.pg_dist_local_group; + CREATE TABLE public.pg_dist_transaction AS SELECT * FROM pg_catalog.pg_dist_transaction; + CREATE TABLE public.pg_dist_colocation AS SELECT * FROM pg_catalog.pg_dist_colocation; + CREATE TABLE public.pg_dist_cleanup AS SELECT * FROM pg_catalog.pg_dist_cleanup; + -- save names of the tenant schemas instead of their oids because the oids might change after pg upgrade + CREATE TABLE public.pg_dist_schema AS SELECT schemaid::regnamespace::text AS schemaname, colocationid FROM pg_catalog.pg_dist_schema; + -- enterprise catalog tables + CREATE TABLE public.pg_dist_authinfo AS SELECT * FROM pg_catalog.pg_dist_authinfo; + CREATE TABLE public.pg_dist_poolinfo AS SELECT * FROM pg_catalog.pg_dist_poolinfo; + -- sequences + CREATE TABLE public.pg_dist_clock_logical_seq AS SELECT last_value FROM pg_catalog.pg_dist_clock_logical_seq; + CREATE TABLE public.pg_dist_rebalance_strategy AS SELECT + name, + default_strategy, + shard_cost_function::regprocedure::text, + node_capacity_function::regprocedure::text, + shard_allowed_on_node_function::regprocedure::text, + default_threshold, + minimum_threshold, + improvement_threshold + FROM pg_catalog.pg_dist_rebalance_strategy; + + -- store upgrade stable identifiers on pg_dist_object catalog + CREATE TABLE public.pg_dist_object AS SELECT + address.type, + address.object_names, + address.object_args, + objects.distribution_argument_index, + objects.colocationid + FROM pg_catalog.pg_dist_object objects, + pg_catalog.pg_identify_object_as_address(objects.classid, objects.objid, objects.objsubid) address; + + -- if we are upgrading from PG14/PG15 to PG16+, + -- we will need to regenerate the partkeys because they will include varnullingrels as well. + -- so we save the partkeys as column names here + CREATE TABLE IF NOT EXISTS public.pg_dist_partkeys_pre_16_upgrade AS + SELECT logicalrelid, column_to_column_name(logicalrelid, partkey) as col_name + FROM pg_catalog.pg_dist_partition WHERE partkey IS NOT NULL AND partkey NOT ILIKE '%varnullingrels%'; + + -- similarly, if we are upgrading to PG18+, + -- we will need to regenerate the partkeys because they will include varreturningtype as well. + -- so we save the partkeys as column names here + CREATE TABLE IF NOT EXISTS public.pg_dist_partkeys_pre_18_upgrade AS + SELECT logicalrelid, column_to_column_name(logicalrelid, partkey) as col_name + FROM pg_catalog.pg_dist_partition WHERE partkey IS NOT NULL AND partkey NOT ILIKE '%varreturningtype%'; + -- remove duplicates (we would only have duplicates if we are upgrading from pre-16 to PG18+) + DELETE FROM public.pg_dist_partkeys_pre_18_upgrade USING public.pg_dist_partkeys_pre_16_upgrade p16 + WHERE public.pg_dist_partkeys_pre_18_upgrade.logicalrelid = p16.logicalrelid + AND public.pg_dist_partkeys_pre_18_upgrade.col_name = p16.col_name; +END; +$cppu$; + +COMMENT ON FUNCTION pg_catalog.citus_prepare_pg_upgrade() + IS 'perform tasks to copy citus settings to a location that could later be restored after pg_upgrade is done'; diff --git a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql index 4f07ce5c4..ee5e98e1d 100644 --- a/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql +++ b/src/backend/distributed/sql/udfs/citus_prepare_pg_upgrade/latest.sql @@ -93,6 +93,17 @@ BEGIN CREATE TABLE IF NOT EXISTS public.pg_dist_partkeys_pre_16_upgrade AS SELECT logicalrelid, column_to_column_name(logicalrelid, partkey) as col_name FROM pg_catalog.pg_dist_partition WHERE partkey IS NOT NULL AND partkey NOT ILIKE '%varnullingrels%'; + + -- similarly, if we are upgrading to PG18+, + -- we will need to regenerate the partkeys because they will include varreturningtype as well. + -- so we save the partkeys as column names here + CREATE TABLE IF NOT EXISTS public.pg_dist_partkeys_pre_18_upgrade AS + SELECT logicalrelid, column_to_column_name(logicalrelid, partkey) as col_name + FROM pg_catalog.pg_dist_partition WHERE partkey IS NOT NULL AND partkey NOT ILIKE '%varreturningtype%'; + -- remove duplicates (we would only have duplicates if we are upgrading from pre-16 to PG18+) + DELETE FROM public.pg_dist_partkeys_pre_18_upgrade USING public.pg_dist_partkeys_pre_16_upgrade p16 + WHERE public.pg_dist_partkeys_pre_18_upgrade.logicalrelid = p16.logicalrelid + AND public.pg_dist_partkeys_pre_18_upgrade.col_name = p16.col_name; END; $cppu$; diff --git a/src/backend/distributed/utils/citus_depended_object.c b/src/backend/distributed/utils/citus_depended_object.c index 4492d8a07..2a35ee7b2 100644 --- a/src/backend/distributed/utils/citus_depended_object.c +++ b/src/backend/distributed/utils/citus_depended_object.c @@ -370,6 +370,20 @@ DistOpsValidityState(Node *node, const DistributeObjectOps *ops) { if (ops && ops->operationType == DIST_OPS_CREATE) { + /* + * We should beware of qualifying the CREATE statement too early. + */ + if (nodeTag(node) == T_CreateDomainStmt) + { + /* + * Create Domain statements should be qualified after local creation + * because in case of an error in creation, we don't want to print + * the error with the qualified name, as that would differ with + * vanilla Postgres error output. + */ + return ShouldQualifyAfterLocalCreation; + } + /* * We should not validate CREATE statements because no address exists * here yet. diff --git a/src/backend/distributed/utils/colocation_utils.c b/src/backend/distributed/utils/colocation_utils.c index af507d5b9..816e3ce2a 100644 --- a/src/backend/distributed/utils/colocation_utils.c +++ b/src/backend/distributed/utils/colocation_utils.c @@ -73,34 +73,8 @@ PG_FUNCTION_INFO_V1(update_distributed_table_colocation); Datum mark_tables_colocated(PG_FUNCTION_ARGS) { - CheckCitusVersion(ERROR); - EnsureCoordinator(); - - Oid sourceRelationId = PG_GETARG_OID(0); - ArrayType *relationIdArrayObject = PG_GETARG_ARRAYTYPE_P(1); - - int relationCount = ArrayObjectCount(relationIdArrayObject); - if (relationCount < 1) - { - ereport(ERROR, (errmsg("at least one target table is required for this " - "operation"))); - } - - EnsureTableOwner(sourceRelationId); - - Datum *relationIdDatumArray = DeconstructArrayObject(relationIdArrayObject); - - for (int relationIndex = 0; relationIndex < relationCount; relationIndex++) - { - Oid nextRelationOid = DatumGetObjectId(relationIdDatumArray[relationIndex]); - - /* we require that the user either owns all tables or is superuser */ - EnsureTableOwner(nextRelationOid); - - MarkTablesColocated(sourceRelationId, nextRelationOid); - } - - PG_RETURN_VOID(); + ereport(ERROR, (errcode(ERRCODE_FEATURE_NOT_SUPPORTED), + errmsg("this function is deprecated and no longer is used"))); } @@ -1306,7 +1280,7 @@ ColocatedShardIdInRelation(Oid relationId, int shardIndex) /* * DeleteColocationGroupIfNoTablesBelong function deletes given co-location group if there * is no relation in that co-location group. A co-location group may become empty after - * mark_tables_colocated or upgrade_reference_table UDF calls. In that case we need to + * update_distributed_table_colocation UDF calls. In that case we need to * remove empty co-location group to prevent orphaned co-location groups. */ void diff --git a/src/include/distributed/citus_depended_object.h b/src/include/distributed/citus_depended_object.h index 1efbe4e2a..1923ee08a 100644 --- a/src/include/distributed/citus_depended_object.h +++ b/src/include/distributed/citus_depended_object.h @@ -25,7 +25,8 @@ typedef enum DistOpsValidationState HasAtLeastOneValidObject, HasNoneValidObject, HasObjectWithInvalidOwnership, - NoAddressResolutionRequired + NoAddressResolutionRequired, + ShouldQualifyAfterLocalCreation } DistOpsValidationState; extern void SetLocalClientMinMessagesIfRunningPGTests(int diff --git a/src/test/regress/bin/normalize.sed b/src/test/regress/bin/normalize.sed index 6df3087cb..efdff159d 100644 --- a/src/test/regress/bin/normalize.sed +++ b/src/test/regress/bin/normalize.sed @@ -297,7 +297,13 @@ s/(NOTICE: issuing CREATE EXTENSION IF NOT EXISTS citus_columnar WITH SCHEMA p s/, password_required=false//g s/provide the file or change sslmode/provide the file, use the system's trusted roots with sslrootcert=system, or change sslmode/g -s/(:varcollid [0-9]+) :varlevelsup 0/\1 :varnullingrels (b) :varlevelsup 0/g + +#pg18 varreturningtype - change needed for PG16, PG17 tests +s/(:varnullingrels \(b\) :varlevelsup 0) (:varnosyn 1)/\1 :varreturningtype 0 \2/g + +#pg16 varnullingrels and pg18 varreturningtype - change needed for PG15 tests +s/(:varcollid [0-9]+) :varlevelsup 0/\1 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0/g + s/table_name_for_view\.([_a-z0-9]+)(,| |$)/\1\2/g s/permission denied to terminate process/must be a superuser to terminate superuser process/g s/permission denied to cancel query/must be a superuser to cancel superuser query/g @@ -365,3 +371,7 @@ s/^([ \t]*)List of sequences$/\1List of relations/g s/violates RESTRICT setting of foreign key constraint/violates foreign key constraint/g # DETAIL line changed "is referenced" -> old "is still referenced" s/\/is still referenced from table/g + +# pg18 extension_control_path GUC debugs +# ignore any "find_in_path:" lines in test output +/DEBUG: find_in_path: trying .*/d diff --git a/src/test/regress/citus_tests/common.py b/src/test/regress/citus_tests/common.py index 00398767e..c3ba14ac8 100644 --- a/src/test/regress/citus_tests/common.py +++ b/src/test/regress/citus_tests/common.py @@ -137,6 +137,7 @@ def initialize_db_for_cluster(pg_path, rel_data_path, settings, node_names): # --allow-group-access is used to ensure we set permissions on # private keys correctly "--allow-group-access", + "--data-checksums", "--encoding", "UTF8", "--locale", diff --git a/src/test/regress/expected/alter_role_propagation.out b/src/test/regress/expected/alter_role_propagation.out index 4beea2a51..51eb36cad 100644 --- a/src/test/regress/expected/alter_role_propagation.out +++ b/src/test/regress/expected/alter_role_propagation.out @@ -338,7 +338,9 @@ SELECT workers.result AS worker_password, pg_authid.rolpassword AS coord_passwor | (2 rows) +SET client_min_messages TO ERROR; ALTER ROLE new_role PASSWORD 'new_password'; +RESET client_min_messages; SELECT workers.result AS worker_password, pg_authid.rolpassword AS coord_password, workers.result = pg_authid.rolpassword AS password_is_same FROM run_command_on_workers($$SELECT rolpassword FROM pg_authid WHERE rolname = 'new_role'$$) workers, pg_authid WHERE pg_authid.rolname = 'new_role'; worker_password | coord_password | password_is_same --------------------------------------------------------------------- diff --git a/src/test/regress/expected/alter_table_set_access_method.out b/src/test/regress/expected/alter_table_set_access_method.out index d24a81744..fe8b8622a 100644 --- a/src/test/regress/expected/alter_table_set_access_method.out +++ b/src/test/regress/expected/alter_table_set_access_method.out @@ -379,6 +379,7 @@ ORDER BY indexname; SELECT conname FROM pg_constraint WHERE conrelid = 'heap_\''tbl'::regclass + AND contype <> 'n' ORDER BY conname; conname --------------------------------------------------------------------- @@ -416,6 +417,7 @@ ORDER BY indexname; SELECT conname FROM pg_constraint WHERE conrelid = 'heap_\''tbl'::regclass + AND contype <> 'n' ORDER BY conname; conname --------------------------------------------------------------------- diff --git a/src/test/regress/expected/arbitrary_configs_alter_table_add_constraint_without_name.out b/src/test/regress/expected/arbitrary_configs_alter_table_add_constraint_without_name.out index e97031e30..58f1bc5d2 100644 --- a/src/test/regress/expected/arbitrary_configs_alter_table_add_constraint_without_name.out +++ b/src/test/regress/expected/arbitrary_configs_alter_table_add_constraint_without_name.out @@ -10,7 +10,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'products'; + WHERE rel.relname = 'products' AND con.contype <> 'n'; conname --------------------------------------------------------------------- products_pkey @@ -27,7 +27,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'products_ref'; + WHERE rel.relname = 'products_ref' AND con.contype <> 'n'; conname --------------------------------------------------------------------- products_ref_pkey2 @@ -41,7 +41,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname LIKE 'very%'; + WHERE rel.relname LIKE 'very%' AND con.contype <> 'n'; conname --------------------------------------------------------------------- verylonglonglonglonglonglonglonglonglonglonglonglonglonglo_pkey @@ -55,7 +55,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'dist_partitioned_table'; + WHERE rel.relname = 'dist_partitioned_table' AND con.contype <> 'n'; conname --------------------------------------------------------------------- dist_partitioned_table_pkey @@ -68,7 +68,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'citus_local_table'; + WHERE rel.relname = 'citus_local_table' AND con.contype <> 'n'; conname --------------------------------------------------------------------- citus_local_table_pkey diff --git a/src/test/regress/expected/citus_local_tables.out b/src/test/regress/expected/citus_local_tables.out index 4f3053094..cdec0aafa 100644 --- a/src/test/regress/expected/citus_local_tables.out +++ b/src/test/regress/expected/citus_local_tables.out @@ -635,7 +635,7 @@ FROM pg_dist_partition WHERE logicalrelid = 'citus_local_table_4'::regclass; SELECT column_name_to_column('citus_local_table_4', 'a'); column_name_to_column --------------------------------------------------------------------- - {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} + {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} (1 row) SELECT master_update_shard_statistics(shardid) diff --git a/src/test/regress/expected/citus_local_tables_mx.out b/src/test/regress/expected/citus_local_tables_mx.out index 8b3cb953f..98c03fea3 100644 --- a/src/test/regress/expected/citus_local_tables_mx.out +++ b/src/test/regress/expected/citus_local_tables_mx.out @@ -769,8 +769,8 @@ SELECT logicalrelid, partmethod, partkey FROM pg_dist_partition ORDER BY logicalrelid; logicalrelid | partmethod | partkey --------------------------------------------------------------------- - parent_dropped_col | h | {VAR :varno 1 :varattno 1 :vartype 1082 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} - parent_dropped_col_2 | h | {VAR :varno 1 :varattno 5 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 5 :location -1} + parent_dropped_col | h | {VAR :varno 1 :varattno 1 :vartype 1082 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} + parent_dropped_col_2 | h | {VAR :varno 1 :varattno 5 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 5 :location -1} (2 rows) -- some tests for view propagation on citus local tables diff --git a/src/test/regress/expected/citus_non_blocking_split_columnar.out b/src/test/regress/expected/citus_non_blocking_split_columnar.out index 0d5c74254..7a251afed 100644 --- a/src/test/regress/expected/citus_non_blocking_split_columnar.out +++ b/src/test/regress/expected/citus_non_blocking_split_columnar.out @@ -160,32 +160,42 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8970002 | fkey_from_child_to_child_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_dist_8970002 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_parent_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_ref_8970002 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8970002 | sensors_2020_01_01_8970002_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_8970000 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8970000 | sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_news_8970003 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8970001 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_old_8970001 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_old_8970001 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_old_8970001 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8970002 | fkey_from_child_to_child_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_dist_8970002 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_parent_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_ref_8970002 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8970000 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_8970000 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_8970000 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_8970000 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8970003 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_news_8970003 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_news_8970003 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_news_8970003 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8970001 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_old_8970001 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_old_8970001 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_old_8970001 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -240,11 +250,22 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; relname | Constraint | Definition --------------------------------------------------------------------- (0 rows) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 0 +(1 row) + SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef --------------------------------------------------------------------- @@ -368,32 +389,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999004 | fkey_from_child_to_child_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_dist_8999004 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_parent_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_ref_8999004 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999004 | sensors_2020_01_01_8999004_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_8999000 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999000 | sensors_8999000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_news_8999006 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999002 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_old_8999002 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_old_8999002 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_old_8999002 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999004 | fkey_from_child_to_child_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_dist_8999004 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_parent_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_ref_8999004 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999000 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_8999000 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_8999000 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_8999000 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999006 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_news_8999006 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_news_8999006 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_news_8999006 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999002 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_old_8999002 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_old_8999002 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_old_8999002 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -448,32 +478,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | sensors_2020_01_01_8999005_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999001 | sensors_8999001_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -634,32 +673,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999104 | fkey_from_child_to_child_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_dist_8999104 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_parent_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_ref_8999104 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999104 | sensors_2020_01_01_8999104_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_8999100 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999100 | sensors_8999100_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_news_8999106 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999102 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_old_8999102 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_old_8999102 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_old_8999102 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999104 | fkey_from_child_to_child_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_dist_8999104 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_parent_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_ref_8999104 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999100 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_8999100 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_8999100 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_8999100 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999106 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_news_8999106 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_news_8999106 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_news_8999106 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999102 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_old_8999102 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_old_8999102 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_old_8999102 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -714,54 +762,61 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | sensors_2020_01_01_8999005_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_child_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_dist_8999105 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_parent_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_ref_8999105 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999105 | sensors_2020_01_01_8999105_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999001 | sensors_8999001_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_8999101 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999101 | sensors_8999101_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_news_8999107 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_news_8999107 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_news_8999107 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_news_8999107 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999103 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_old_8999103 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_old_8999103 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_old_8999103 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(44 rows) + sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_child_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_dist_8999105 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_parent_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_ref_8999105 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999101 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_8999101 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_8999101 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_8999101 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999107 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_news_8999107 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_news_8999107 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_news_8999107 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999103 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_old_8999103 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_old_8999103 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_old_8999103 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(40 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 4 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef diff --git a/src/test/regress/expected/citus_split_shard_columnar_partitioned.out b/src/test/regress/expected/citus_split_shard_columnar_partitioned.out index 5dc0c1ebc..4ee02f867 100644 --- a/src/test/regress/expected/citus_split_shard_columnar_partitioned.out +++ b/src/test/regress/expected/citus_split_shard_columnar_partitioned.out @@ -152,32 +152,42 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8970002 | fkey_from_child_to_child_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_dist_8970002 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_parent_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_child_to_ref_8970002 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_2020_01_01_8970002 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8970002 | sensors_2020_01_01_8970002_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_8970000 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_8970000 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8970000 | sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_news_8970003 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_news_8970003 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8970001 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) - sensors_old_8970001 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) - sensors_old_8970001 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) - sensors_old_8970001 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8970002 | fkey_from_child_to_child_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_dist_8970002 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_parent_8970002 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_child_to_ref_8970002 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_2020_01_01_8970002 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8970000 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_8970000 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_8970000 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_8970000 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8970003 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_news_8970003 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_news_8970003 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_news_8970003 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8970001 | fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970010(eventdatetime, measureid) + sensors_old_8970001 | fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970008(measureid) + sensors_old_8970001 | fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970009(eventdatetime, measureid) + sensors_old_8970001 | fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -232,11 +242,22 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; relname | Constraint | Definition --------------------------------------------------------------------- (0 rows) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 0 +(1 row) + SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef --------------------------------------------------------------------- @@ -360,32 +381,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999004 | fkey_from_child_to_child_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_dist_8999004 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_parent_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_child_to_ref_8999004 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_2020_01_01_8999004 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999004 | sensors_2020_01_01_8999004_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_8999000 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_8999000 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999000 | sensors_8999000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_news_8999006 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_news_8999006 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999002 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) - sensors_old_8999002 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) - sensors_old_8999002 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) - sensors_old_8999002 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999004 | fkey_from_child_to_child_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_dist_8999004 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_parent_8999004 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_child_to_ref_8999004 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_2020_01_01_8999004 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999000 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_8999000 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_8999000 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_8999000 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999006 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_news_8999006 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_news_8999006 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_news_8999006 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999002 | fkey_from_parent_to_child_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999020(eventdatetime, measureid) + sensors_old_8999002 | fkey_from_parent_to_dist_8999000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999016(measureid) + sensors_old_8999002 | fkey_from_parent_to_parent_8999000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999018(eventdatetime, measureid) + sensors_old_8999002 | fkey_from_parent_to_ref_8999000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -440,32 +470,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | sensors_2020_01_01_8999005_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999001 | sensors_8999001_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -626,32 +665,41 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999104 | fkey_from_child_to_child_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_dist_8999104 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_parent_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_child_to_ref_8999104 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_2020_01_01_8999104 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999104 | sensors_2020_01_01_8999104_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_8999100 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_8999100 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999100 | sensors_8999100_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_news_8999106 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_news_8999106 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999102 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) - sensors_old_8999102 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) - sensors_old_8999102 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) - sensors_old_8999102 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(22 rows) + sensors_2020_01_01_8999104 | fkey_from_child_to_child_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_dist_8999104 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_parent_8999104 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_child_to_ref_8999104 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_2020_01_01_8999104 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999100 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_8999100 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_8999100 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_8999100 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999106 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_news_8999106 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_news_8999106 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_news_8999106 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999102 | fkey_from_parent_to_child_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999120(eventdatetime, measureid) + sensors_old_8999102 | fkey_from_parent_to_dist_8999100 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999116(measureid) + sensors_old_8999102 | fkey_from_parent_to_parent_8999100 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999118(eventdatetime, measureid) + sensors_old_8999102 | fkey_from_parent_to_ref_8999100 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(20 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 2 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef @@ -706,54 +754,61 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; - relname | Constraint | Definition + relname | Constraint | Definition --------------------------------------------------------------------- - sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999005 | sensors_2020_01_01_8999005_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_child_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_dist_8999105 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_parent_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_child_to_ref_8999105 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_2020_01_01_8999105 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_2020_01_01_8999105 | sensors_2020_01_01_8999105_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999001 | sensors_8999001_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_8999101 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_8999101 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_8999101 | sensors_8999101_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_news_8999107 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_news_8999107 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_news_8999107 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_news_8999107 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) - sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) - sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) - sensors_old_8999103 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) - sensors_old_8999103 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) - sensors_old_8999103 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) - sensors_old_8999103 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) -(44 rows) + sensors_2020_01_01_8999005 | fkey_from_child_to_child_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_dist_8999005 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_parent_8999005 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_child_to_ref_8999005 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_2020_01_01_8999005 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_child_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_dist_8999105 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_parent_8999105 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_child_to_ref_8999105 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_2020_01_01_8999105 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999001 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_8999001 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_8999001 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_8999101 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_8999101 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_8999101 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_8999101 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999007 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_news_8999007 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_news_8999007 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_news_8999107 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_news_8999107 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_news_8999107 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_news_8999107 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999003 | fkey_from_parent_to_child_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999021(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_dist_8999001 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999017(measureid) + sensors_old_8999003 | fkey_from_parent_to_parent_8999001 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999019(eventdatetime, measureid) + sensors_old_8999003 | fkey_from_parent_to_ref_8999001 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) + sensors_old_8999103 | fkey_from_parent_to_child_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8999121(eventdatetime, measureid) + sensors_old_8999103 | fkey_from_parent_to_dist_8999101 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8999117(measureid) + sensors_old_8999103 | fkey_from_parent_to_parent_8999101 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8999119(eventdatetime, measureid) + sensors_old_8999103 | fkey_from_parent_to_ref_8999101 | FOREIGN KEY (measureid) REFERENCES reference_table_8970011(measureid) +(40 rows) + + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 4 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; tablename | indexdef diff --git a/src/test/regress/expected/generated_identity.out b/src/test/regress/expected/generated_identity.out index 3155bb769..cf0d64372 100644 --- a/src/test/regress/expected/generated_identity.out +++ b/src/test/regress/expected/generated_identity.out @@ -473,25 +473,19 @@ SELECT create_distributed_table('color', 'color_id'); (1 row) INSERT INTO color(color_name) VALUES ('Blue'); -\d+ color - Table "generated_identities.color" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT pg_get_serial_sequence('color', 'color_id'); + pg_get_serial_sequence --------------------------------------------------------------------- - color_id | bigint | | not null | generated always as identity | plain | | - color_name | character varying | | not null | | extended | | -Indexes: - "color_color_id_key" UNIQUE CONSTRAINT, btree (color_id) + generated_identities.color_color_id_seq +(1 row) \c - - - :worker_1_port SET search_path TO generated_identities; -\d+ color - Table "generated_identities.color" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT pg_get_serial_sequence('color', 'color_id'); + pg_get_serial_sequence --------------------------------------------------------------------- - color_id | bigint | | not null | generated always as identity | plain | | - color_name | character varying | | not null | | extended | | -Indexes: - "color_color_id_key" UNIQUE CONSTRAINT, btree (color_id) + generated_identities.color_color_id_seq +(1 row) INSERT INTO color(color_name) VALUES ('Red'); -- alter sequence .. restart diff --git a/src/test/regress/expected/local_shard_execution.out b/src/test/regress/expected/local_shard_execution.out index 0f0c7a14e..3348db63a 100644 --- a/src/test/regress/expected/local_shard_execution.out +++ b/src/test/regress/expected/local_shard_execution.out @@ -312,8 +312,8 @@ EXPLAIN (COSTS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; Filter: (age = 20) (8 rows) -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; - QUERY PLAN +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; + QUERY PLAN --------------------------------------------------------------------- Custom Scan (Citus Adaptive) (actual rows=1 loops=1) Task Count: 1 @@ -368,8 +368,8 @@ EXPLAIN (COSTS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; Filter: (age = 20) (9 rows) -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; - QUERY PLAN +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; + QUERY PLAN --------------------------------------------------------------------- Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Task Count: 1 diff --git a/src/test/regress/expected/local_shard_execution_replicated.out b/src/test/regress/expected/local_shard_execution_replicated.out index bf49cc2ee..835df717d 100644 --- a/src/test/regress/expected/local_shard_execution_replicated.out +++ b/src/test/regress/expected/local_shard_execution_replicated.out @@ -250,8 +250,8 @@ EXPLAIN (COSTS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; Filter: (age = 20) (8 rows) -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; - QUERY PLAN +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; + QUERY PLAN --------------------------------------------------------------------- Custom Scan (Citus Adaptive) (actual rows=1 loops=1) Task Count: 1 @@ -306,8 +306,8 @@ EXPLAIN (COSTS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; Filter: (age = 20) (9 rows) -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; - QUERY PLAN +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; + QUERY PLAN --------------------------------------------------------------------- Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Task Count: 1 diff --git a/src/test/regress/expected/metadata_sync_helpers.out b/src/test/regress/expected/metadata_sync_helpers.out index 9db68eaf5..6345e15ac 100644 --- a/src/test/regress/expected/metadata_sync_helpers.out +++ b/src/test/regress/expected/metadata_sync_helpers.out @@ -1287,11 +1287,17 @@ BEGIN TRANSACTION ISOLATION LEVEL READ COMMITTED; SET application_name to 'citus_internal gpid=10000000001'; -- with an ugly trick, update the vartype of table from int to bigint -- so that making two tables colocated fails - -- include varnullingrels for PG16 + -- include varnullingrels for PG16+ SHOW server_version \gset SELECT substring(:'server_version', '\d+')::int >= 16 AS server_version_ge_16 \gset - \if :server_version_ge_16 + -- include varreturningtype for PG18+ + SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 + \gset + \if :server_version_ge_18 + UPDATE pg_dist_partition SET partkey = '{VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 1 :varreturningtype 0 :varnoold 1 :varoattno 1 :location -1}' + WHERE logicalrelid = 'test_2'::regclass; + \elif :server_version_ge_16 UPDATE pg_dist_partition SET partkey = '{VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 1 :varnoold 1 :varoattno 1 :location -1}' WHERE logicalrelid = 'test_2'::regclass; \else diff --git a/src/test/regress/expected/multi_array_agg.out b/src/test/regress/expected/multi_array_agg.out index 35a445bd9..b1db3f19c 100644 --- a/src/test/regress/expected/multi_array_agg.out +++ b/src/test/regress/expected/multi_array_agg.out @@ -4,7 +4,7 @@ SET citus.next_shard_id TO 520000; SET citus.coordinator_aggregation_strategy TO 'disabled'; SELECT run_command_on_master_and_workers($r$ -CREATE OR REPLACE FUNCTION array_sort (ANYARRAY) +CREATE OR REPLACE FUNCTION array_sort_citus (ANYARRAY) RETURNS ANYARRAY LANGUAGE SQL AS $$ SELECT ARRAY(SELECT unnest($1) ORDER BY 1) @@ -30,9 +30,9 @@ ERROR: array_agg with order by is unsupported SELECT array_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem; ERROR: array_agg with order by is unsupported -- Check array_agg() for different data types and LIMIT clauses -SELECT array_sort(array_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; - array_sort + array_sort_citus --------------------------------------------------------------------- {2132,15635,24027,63700,67310,155190} {106170} @@ -46,9 +46,9 @@ SELECT array_sort(array_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey {88362,89414,169544} (10 rows) -SELECT array_sort(array_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; - array_sort + array_sort_citus --------------------------------------------------------------------- {13309.60,21168.23,22824.48,28955.64,45983.16,49620.16} {44694.46} @@ -62,9 +62,9 @@ SELECT array_sort(array_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey {9681.24,17554.68,30875.02} (10 rows) -SELECT array_sort(array_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; - array_sort + array_sort_citus --------------------------------------------------------------------- {01-29-1996,01-30-1996,03-13-1996,03-30-1996,04-12-1996,04-21-1996} {01-28-1997} @@ -78,9 +78,9 @@ SELECT array_sort(array_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey {10-09-1998,10-23-1998,10-30-1998} (10 rows) -SELECT array_sort(array_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; - array_sort + array_sort_citus --------------------------------------------------------------------- {"AIR ","FOB ","MAIL ","MAIL ","REG AIR ","TRUCK "} {"RAIL "} @@ -105,10 +105,10 @@ SELECT array_length(array_agg(l_orderkey), 1) FROM lineitem; -- shards and contain different aggregates, filter clauses and other complex -- expressions. Note that the l_orderkey ranges are such that the matching rows -- lie in different shards. -SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(array_agg(l_orderkey)) FROM lineitem +SELECT l_quantity, count(*), avg(l_extendedprice), array_sort_citus(array_agg(l_orderkey)) FROM lineitem WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; - l_quantity | count | avg | array_sort + l_quantity | count | avg | array_sort_citus --------------------------------------------------------------------- 1.00 | 17 | 1477.1258823529411765 | {5543,5633,5634,5698,5766,5856,5857,5986,8997,9026,9158,9184,9220,9222,9348,9383,9476} 2.00 | 19 | 3078.4242105263157895 | {5506,5540,5573,5669,5703,5730,5798,5831,5893,5920,5923,9030,9058,9123,9124,9188,9344,9441,9476} @@ -116,7 +116,7 @@ SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(array_agg(l_orderk 4.00 | 19 | 5929.7136842105263158 | {5504,5507,5508,5511,5538,5764,5766,5826,5829,5862,5959,5985,9091,9120,9281,9347,9382,9440,9473} (4 rows) -SELECT l_quantity, array_sort(array_agg(extract (month FROM o_orderdate))) AS my_month +SELECT l_quantity, array_sort_citus(array_agg(extract (month FROM o_orderdate))) AS my_month FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; l_quantity | my_month @@ -127,10 +127,10 @@ SELECT l_quantity, array_sort(array_agg(extract (month FROM o_orderdate))) AS my 4.00 | {1,1,1,2,2,2,5,5,6,6,6,6,8,9,10,10,11,11,12} (4 rows) -SELECT l_quantity, array_sort(array_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5 +SELECT l_quantity, array_sort_citus(array_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5 AND octet_length(l_comment) + octet_length('randomtext'::text) > 40 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; - l_quantity | array_sort + l_quantity | array_sort_citus --------------------------------------------------------------------- 1.00 | {11269,11397,11713,11715,11973,18317,18445} 2.00 | {11847,18061,18247,18953} @@ -139,17 +139,17 @@ SELECT l_quantity, array_sort(array_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE (4 rows) -- Check that we can execute array_agg() with an expression containing NULL values -SELECT array_sort(array_agg(case when l_quantity > 20 then l_quantity else NULL end)) +SELECT array_sort_citus(array_agg(case when l_quantity > 20 then l_quantity else NULL end)) FROM lineitem WHERE l_orderkey < 10; - array_sort + array_sort_citus --------------------------------------------------------------------- {24.00,26.00,26.00,27.00,28.00,28.00,28.00,30.00,32.00,35.00,36.00,37.00,38.00,38.00,45.00,46.00,49.00,50.00,NULL,NULL,NULL,NULL,NULL,NULL,NULL} (1 row) -- Check that we return NULL in case there are no input rows to array_agg() -SELECT array_sort(array_agg(l_orderkey)) +SELECT array_sort_citus(array_agg(l_orderkey)) FROM lineitem WHERE l_orderkey < 0; - array_sort + array_sort_citus --------------------------------------------------------------------- {} (1 row) diff --git a/src/test/regress/expected/multi_explain.out b/src/test/regress/expected/multi_explain.out index e67b2d6c6..6fc2e36a3 100644 --- a/src/test/regress/expected/multi_explain.out +++ b/src/test/regress/expected/multi_explain.out @@ -3053,7 +3053,7 @@ Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Conflicting Tuples: 0 -> Seq Scan on users_table_2_570028 users_table_2 (actual rows=0 loops=1) -- simple test to confirm we can fetch long (>4KB) plans -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; +EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF, BUFFERS OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Task Count: 1 Tuple data received from nodes: 0 bytes diff --git a/src/test/regress/expected/multi_explain_0.out b/src/test/regress/expected/multi_explain_0.out index 8f2b412eb..5589f3d69 100644 --- a/src/test/regress/expected/multi_explain_0.out +++ b/src/test/regress/expected/multi_explain_0.out @@ -3042,7 +3042,7 @@ Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Conflicting Tuples: 0 -> Seq Scan on users_table_2_570028 users_table_2 (actual rows=0 loops=1) -- simple test to confirm we can fetch long (>4KB) plans -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; +EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF, BUFFERS OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; Custom Scan (Citus Adaptive) (actual rows=0 loops=1) Task Count: 1 Tuple data received from nodes: 0 bytes diff --git a/src/test/regress/expected/multi_extension.out b/src/test/regress/expected/multi_extension.out index d3ed19f21..99774d9ef 100644 --- a/src/test/regress/expected/multi_extension.out +++ b/src/test/regress/expected/multi_extension.out @@ -1120,16 +1120,17 @@ DROP TABLE columnar_schema_members, columnar_schema_members_pg_depend; -- Use a synthetic pg_dist_shard record to show that upgrade fails -- when there are cstore_fdw tables INSERT INTO pg_dist_shard (logicalrelid, shardid, shardstorage) VALUES ('pg_dist_shard', 1, 'c'); +-- reduce verbosity since there is more context in PG18 (774171c4f) +\set VERBOSITY terse ALTER EXTENSION citus UPDATE TO '11.0-1'; ERROR: cstore_fdw tables are deprecated as of Citus 11.0 -HINT: Install Citus 10.2 and convert your cstore_fdw tables to the columnar access method before upgrading further -CONTEXT: PL/pgSQL function inline_code_block line XX at RAISE +\set VERBOSITY default DELETE FROM pg_dist_shard WHERE shardid = 1; -- partitioned table count is tracked on Citus 11 upgrade CREATE TABLE e_transactions(order_id varchar(255) NULL, transaction_id int) PARTITION BY LIST(transaction_id); CREATE TABLE orders_2020_07_01 PARTITION OF e_transactions FOR VALUES IN (1,2,3); -INSERT INTO pg_dist_partition VALUES ('e_transactions'::regclass,'h', '{VAR :varno 1 :varattno 1 :vartype 1043 :vartypmod 259 :varcollid 100 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1}', 7, 's'); +INSERT INTO pg_dist_partition VALUES ('e_transactions'::regclass,'h', '{VAR :varno 1 :varattno 1 :vartype 1043 :vartypmod 259 :varcollid 100 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1}', 7, 's'); SELECT (metadata->>'partitioned_citus_table_exists_pre_11')::boolean as partitioned_citus_table_exists_pre_11, (metadata->>'partitioned_citus_table_exists_pre_11') IS NULL as is_null @@ -1510,11 +1511,11 @@ SELECT create_distributed_table('null_shard_key', null); -- Show that we cannot downgrade to 11.3-2 becuase the cluster has a -- distributed table with single-shard. +-- reduce verbosity since there is more context in PG18 (774171c4f) +\set VERBOSITY terse ALTER EXTENSION citus UPDATE TO '11.3-2'; ERROR: cannot downgrade Citus because there are distributed tables without a shard key. -DETAIL: To downgrade Citus to an older version, you should first convert those tables to Postgres tables by executing SELECT undistribute_table("%s"). -HINT: You can find the distributed tables without a shard key in the cluster by using the following query: "SELECT * FROM citus_tables WHERE distribution_column = '' AND colocation_id > 0". -CONTEXT: PL/pgSQL function inline_code_block line XX at RAISE +\set VERBOSITY default DROP TABLE null_shard_key; ALTER EXTENSION citus UPDATE TO '11.3-2'; -- Should be empty result since upgrade+downgrade should be a no-op diff --git a/src/test/regress/expected/multi_metadata_sync.out b/src/test/regress/expected/multi_metadata_sync.out index 4ab7a3026..e9b5b587e 100644 --- a/src/test/regress/expected/multi_metadata_sync.out +++ b/src/test/regress/expected/multi_metadata_sync.out @@ -55,7 +55,9 @@ SELECT pg_sleep(0.1); (1 row) +SET client_min_messages TO ERROR; ALTER ROLE CURRENT_USER WITH PASSWORD 'dummypassword'; +RESET client_min_messages; -- Show that, with no MX tables, activate node snapshot contains only the delete commands, -- pg_dist_node entries, pg_dist_object entries and roles. SELECT unnest(activate_node_snapshot()) order by 1; @@ -523,7 +525,7 @@ SELECT * FROM pg_dist_node ORDER BY nodeid; SELECT * FROM pg_dist_partition WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY logicalrelid::text; logicalrelid | partmethod | partkey | colocationid | repmodel | autoconverted --------------------------------------------------------------------- - mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f + mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f (1 row) SELECT * FROM pg_dist_shard WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY shardid; @@ -662,7 +664,7 @@ SELECT * FROM pg_dist_node ORDER BY nodeid; SELECT * FROM pg_dist_partition WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY logicalrelid::text; logicalrelid | partmethod | partkey | colocationid | repmodel | autoconverted --------------------------------------------------------------------- - mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f + mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f (1 row) SELECT * FROM pg_dist_shard WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY shardid; diff --git a/src/test/regress/expected/multi_metadata_sync_0.out b/src/test/regress/expected/multi_metadata_sync_0.out index bc1775ada..5ff926ff6 100644 --- a/src/test/regress/expected/multi_metadata_sync_0.out +++ b/src/test/regress/expected/multi_metadata_sync_0.out @@ -65,7 +65,9 @@ SELECT pg_sleep(0.1); (1 row) +SET client_min_messages TO ERROR; ALTER ROLE CURRENT_USER WITH PASSWORD 'dummypassword'; +RESET client_min_messages; -- Show that, with no MX tables, activate node snapshot contains only the delete commands, -- pg_dist_node entries, pg_dist_object entries and roles. SELECT unnest(activate_node_snapshot()) order by 1; @@ -533,7 +535,7 @@ SELECT * FROM pg_dist_node ORDER BY nodeid; SELECT * FROM pg_dist_partition WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY logicalrelid::text; logicalrelid | partmethod | partkey | colocationid | repmodel | autoconverted --------------------------------------------------------------------- - mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f + mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f (1 row) SELECT * FROM pg_dist_shard WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY shardid; @@ -672,7 +674,7 @@ SELECT * FROM pg_dist_node ORDER BY nodeid; SELECT * FROM pg_dist_partition WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY logicalrelid::text; logicalrelid | partmethod | partkey | colocationid | repmodel | autoconverted --------------------------------------------------------------------- - mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f + mx_testing_schema.mx_test_table | h | {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 2 | s | f (1 row) SELECT * FROM pg_dist_shard WHERE logicalrelid::text LIKE 'mx_testing_schema%' ORDER BY shardid; diff --git a/src/test/regress/expected/multi_mx_hide_shard_names.out b/src/test/regress/expected/multi_mx_hide_shard_names.out index 1f6e06ab1..bcc77db8f 100644 --- a/src/test/regress/expected/multi_mx_hide_shard_names.out +++ b/src/test/regress/expected/multi_mx_hide_shard_names.out @@ -476,11 +476,18 @@ SELECT relname FROM pg_catalog.pg_class WHERE relnamespace = 'mx_hide_shard_name -- Relevant PG16 commit: -- https://github.com/postgres/postgres/commit/0c679464a837079acc75ff1d45eaa83f79e05690 -- Relevant Pg17 commit: --- https://github.com/postgres/postgres/commit/067701f57758f9baed5bd9d868539738d77bfa92#diff-afc0ebd67534b71b5b94b29a1387aa6eedffe342a5539f52d686428be323e802 +-- https://github.com/postgres/postgres/commit/067701f57758f9baed5bd9d868539738d77bfa92 +-- Relevant PG18 commit: +-- https://github.com/postgres/postgres/commit/18d67a8d7d30884655d65910b82781d9360819a6 SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 \gset SELECT substring(:'server_version', '\d+')::int >= 17 AS server_version_ge_17 \gset SELECT substring(:'server_version', '\d+')::int >= 16 AS server_version_ge_16 \gset -\if :server_version_ge_17 +\if :server_version_ge_18 + SELECT 1 AS client_backend \gset + SELECT 5 AS bgworker \gset + SELECT 6 AS walsender \gset +\elif :server_version_ge_17 SELECT 1 AS client_backend \gset SELECT 4 AS bgworker \gset SELECT 5 AS walsender \gset diff --git a/src/test/regress/expected/multi_partitioning_utils.out b/src/test/regress/expected/multi_partitioning_utils.out index 9cd17d56a..21e80f994 100644 --- a/src/test/regress/expected/multi_partitioning_utils.out +++ b/src/test/regress/expected/multi_partitioning_utils.out @@ -118,15 +118,17 @@ SELECT generate_alter_table_attach_partition_command('date_partition_2007'); (1 row) -- detach and attach the partition by the command generated by us -\d+ date_partitioned_table - Partitioned table "public.date_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | | | plain | | - time | date | | | | plain | | -Partition key: RANGE ("time") -Partitions: date_partition_2006 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'), - date_partition_2007 FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') + date_partition_2006 | FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + date_partition_2007 | FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') +(2 rows) SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_table'); detach_and_attach_partition @@ -135,15 +137,17 @@ SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_tabl (1 row) -- check that both partitions are visiable -\d+ date_partitioned_table - Partitioned table "public.date_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | | | plain | | - time | date | | | | plain | | -Partition key: RANGE ("time") -Partitions: date_partition_2006 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007'), - date_partition_2007 FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') + date_partition_2006 | FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + date_partition_2007 | FOR VALUES FROM ('01-01-2007') TO ('01-01-2008') +(2 rows) -- make sure that inter shard commands work as expected -- assume that the shardId is 100 @@ -159,14 +163,16 @@ SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_ (1 row) -- the hierarcy is successfully created -\d+ date_partitioned_table_100 - Partitioned table "public.date_partitioned_table_100" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table_100'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | | | plain | | - time | date | | | | plain | | -Partition key: RANGE ("time") -Partitions: date_partition_2007_100 FOR VALUES FROM ('01-01-2007') TO ('01-02-2008') + date_partition_2007_100 | FOR VALUES FROM ('01-01-2007') TO ('01-02-2008') +(1 row) -- Citus can also get the DDL events for the partitions as regular tables SELECT master_get_table_ddl_events('date_partition_2007_100'); @@ -186,14 +192,15 @@ SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_ (1 row) -- the hierarcy is successfully broken -\d+ date_partitioned_table_100 - Partitioned table "public.date_partitioned_table_100" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table_100'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | | | plain | | - time | date | | | | plain | | -Partition key: RANGE ("time") -Number of partitions: 0 +(0 rows) -- now lets have some more complex partitioning hierarcies with -- tables on different schemas and constraints on the tables @@ -242,15 +249,17 @@ SELECT public.generate_alter_table_attach_partition_command('child_2'); SET search_path = 'partition_parent_schema'; -- detach and attach the partition by the command generated by us -\d+ parent_table - Partitioned table "partition_parent_schema.parent_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'parent_table'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | not null | | plain | | - time | date | | | now() | plain | | -Partition key: RANGE ("time") -Partitions: partition_child_1_schema.child_1 FOR VALUES FROM ('01-01-2009') TO ('01-02-2010'), - partition_child_2_schema.child_2 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + child_1 | FOR VALUES FROM ('01-01-2009') TO ('01-02-2010') + child_2 | FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') +(2 rows) SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'parent_table'); detach_and_attach_partition @@ -259,15 +268,17 @@ SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'p (1 row) -- check that both partitions are visiable -\d+ parent_table - Partitioned table "partition_parent_schema.parent_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'parent_table'; + partition_name | partition_bound --------------------------------------------------------------------- - id | integer | | not null | | plain | | - time | date | | | now() | plain | | -Partition key: RANGE ("time") -Partitions: partition_child_1_schema.child_1 FOR VALUES FROM ('01-01-2009') TO ('01-02-2010'), - partition_child_2_schema.child_2 FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + child_2 | FOR VALUES FROM ('01-01-2006') TO ('01-01-2007') + child_1 | FOR VALUES FROM ('01-01-2009') TO ('01-02-2010') +(2 rows) -- some very simple checks that should error out SELECT public.generate_alter_table_attach_partition_command('parent_table'); diff --git a/src/test/regress/expected/multi_prune_shard_list.out b/src/test/regress/expected/multi_prune_shard_list.out index 3762bd05d..88c385a46 100644 --- a/src/test/regress/expected/multi_prune_shard_list.out +++ b/src/test/regress/expected/multi_prune_shard_list.out @@ -86,7 +86,7 @@ SELECT prune_using_both_values('pruning', 'tomato', 'rose'); SELECT debug_equality_expression('pruning'); debug_equality_expression --------------------------------------------------------------------- - {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 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} {CONST :consttype 25 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull true :location -1 :constvalue <>}) :location -1} + {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 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} {CONST :consttype 25 :consttypmod -1 :constcollid 100 :constlen -1 :constbyval false :constisnull true :location -1 :constvalue <>}) :location -1} (1 row) -- print the initial ordering of shard intervals diff --git a/src/test/regress/expected/multi_reference_table.out b/src/test/regress/expected/multi_reference_table.out index 68835be40..b86606f7c 100644 --- a/src/test/regress/expected/multi_reference_table.out +++ b/src/test/regress/expected/multi_reference_table.out @@ -1200,7 +1200,7 @@ DEBUG: cannot perform distributed INSERT INTO ... SELECT because the partition DETAIL: The target table's partition column should correspond to a partition column in the subquery. DEBUG: performing repartitioned INSERT ... SELECT RESET client_min_messages; --- some tests for mark_tables_colocated +-- some tests for update_distributed_table_colocation -- should error out SELECT update_distributed_table_colocation('colocated_table_test_2', colocate_with => 'reference_table_test'); ERROR: relation reference_table_test should be a hash or single shard distributed table diff --git a/src/test/regress/expected/partitioning_issue_3970.out b/src/test/regress/expected/partitioning_issue_3970.out index 1131bfc68..7ef91bf65 100644 --- a/src/test/regress/expected/partitioning_issue_3970.out +++ b/src/test/regress/expected/partitioning_issue_3970.out @@ -41,6 +41,7 @@ CREATE TABLE part_table_p202009 PARTITION OF part_table FOR VALUES FROM ('2020-0 SELECT relname, conname, pg_catalog.pg_get_constraintdef(con.oid, true) FROM pg_constraint con JOIN pg_class rel ON (rel.oid=con.conrelid) WHERE relname LIKE 'part_table%' + AND contype <> 'n' ORDER BY 1,2,3; relname | conname | pg_get_constraintdef --------------------------------------------------------------------- @@ -70,6 +71,7 @@ ORDER BY 1,2,3; SELECT relname, conname, pg_catalog.pg_get_constraintdef(con.oid, true) FROM pg_constraint con JOIN pg_class rel ON (rel.oid=con.conrelid) WHERE relname SIMILAR TO 'part_table%\_\d%' + AND contype <> 'n' ORDER BY 1,2,3; relname | conname | pg_get_constraintdef --------------------------------------------------------------------- diff --git a/src/test/regress/expected/pg17.out b/src/test/regress/expected/pg17.out index 4b28413b4..2b3042ca1 100644 --- a/src/test/regress/expected/pg17.out +++ b/src/test/regress/expected/pg17.out @@ -743,15 +743,17 @@ SELECT create_distributed_table('partitioned_table', 'a'); CREATE TABLE pt_2 PARTITION OF partitioned_table FOR VALUES FROM (50) TO (1000); -- (1) The partitioned table has pt_1 and pt_2 as its partitions -\d+ partitioned_table; - Partitioned table "pg17.partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: pt_1 FOR VALUES FROM (1) TO (50), - pt_2 FOR VALUES FROM (50) TO (1000) + pt_1 | FOR VALUES FROM (1) TO (50) + pt_2 | FOR VALUES FROM (50) TO (1000) +(2 rows) -- (2) The partitions have the same identity column as the parent table; -- This is PG17 behavior for support for identity in partitioned tables. @@ -774,16 +776,18 @@ Partition of: partitioned_table FOR VALUES FROM (50) TO (1000) -- Attaching a partition inherits the identity column from the parent table CREATE TABLE pt_3 (a bigint not null, c int); ALTER TABLE partitioned_table ATTACH PARTITION pt_3 FOR VALUES FROM (1000) TO (2000); -\d+ partitioned_table; - Partitioned table "pg17.partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: pt_1 FOR VALUES FROM (1) TO (50), - pt_2 FOR VALUES FROM (50) TO (1000), - pt_3 FOR VALUES FROM (1000) TO (2000) + pt_1 | FOR VALUES FROM (1) TO (50) + pt_2 | FOR VALUES FROM (50) TO (1000) + pt_3 | FOR VALUES FROM (1000) TO (2000) +(3 rows) \d pt_3; Table "pg17.pt_3" @@ -803,16 +807,18 @@ DETAIL: The new partition may not contain an identity column. SET search_path TO pg17; -- Show that DDL for partitioned_table has correctly propagated to the worker node; -- (1) The partitioned table has pt_1, pt_2 and pt_3 as its partitions -\d+ partitioned_table; - Partitioned table "pg17.partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: pt_1 FOR VALUES FROM (1) TO (50), - pt_2 FOR VALUES FROM (50) TO (1000), - pt_3 FOR VALUES FROM (1000) TO (2000) + pt_1 | FOR VALUES FROM (1) TO (50) + pt_2 | FOR VALUES FROM (50) TO (1000) + pt_3 | FOR VALUES FROM (1000) TO (2000) +(3 rows) -- (2) The partititions have the same identity column as the parent table \d pt_1; @@ -845,15 +851,17 @@ SET search_path TO pg17; ALTER TABLE partitioned_table DETACH PARTITION pt_3; -- partitioned_table has pt_1, pt_2 as its partitions -- and pt_3 does not have an identity column -\d+ partitioned_table; - Partitioned table "pg17.partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: pt_1 FOR VALUES FROM (1) TO (50), - pt_2 FOR VALUES FROM (50) TO (1000) + pt_1 | FOR VALUES FROM (1) TO (50) + pt_2 | FOR VALUES FROM (50) TO (1000) +(2 rows) \d pt_3; Table "pg17.pt_3" @@ -865,15 +873,17 @@ Partitions: pt_1 FOR VALUES FROM (1) TO (50), -- Verify that the detach has propagated to the worker node \c - - - :worker_1_port SET search_path TO pg17; -\d+ partitioned_table; - Partitioned table "pg17.partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: pt_1 FOR VALUES FROM (1) TO (50), - pt_2 FOR VALUES FROM (50) TO (1000) + pt_1 | FOR VALUES FROM (1) TO (50) + pt_2 | FOR VALUES FROM (50) TO (1000) +(2 rows) \d pt_3; Table "pg17.pt_3" @@ -903,16 +913,17 @@ ALTER TABLE alt_test ALTER COLUMN a SET GENERATED BY DEFAULT SET INCREMENT BY 2 ERROR: alter table command is currently unsupported DETAIL: Only ADD|DROP COLUMN, SET|DROP NOT NULL, SET|DROP DEFAULT, ADD|DROP|VALIDATE CONSTRAINT, SET (), RESET (), ENABLE|DISABLE|NO FORCE|FORCE ROW LEVEL SECURITY, ATTACH|DETACH PARTITION and TYPE subcommands are supported. -- Verify that the identity column was not added, on coordinator and worker nodes -\d+ alt_test; - Partitioned table "pg17.alt_test" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; + partition_name | partition_bound --------------------------------------------------------------------- - a | integer | | | | plain | | - b | date | | | | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: alt_test_pt_1 FOR VALUES FROM (1) TO (50), - alt_test_pt_2 FOR VALUES FROM (50) TO (100) + alt_test_pt_1 | FOR VALUES FROM (1) TO (50) + alt_test_pt_2 | FOR VALUES FROM (50) TO (100) +(2 rows) \d alt_test_pt_1; Table "pg17.alt_test_pt_1" @@ -934,16 +945,17 @@ Partition of: alt_test FOR VALUES FROM (50) TO (100) \c - - - :worker_1_port SET search_path TO pg17; -\d+ alt_test; - Partitioned table "pg17.alt_test" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; + partition_name | partition_bound --------------------------------------------------------------------- - a | integer | | | | plain | | - b | date | | | | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: alt_test_pt_1 FOR VALUES FROM (1) TO (50), - alt_test_pt_2 FOR VALUES FROM (50) TO (100) + alt_test_pt_1 | FOR VALUES FROM (1) TO (50) + alt_test_pt_2 | FOR VALUES FROM (50) TO (100) +(2 rows) \d alt_test_pt_1; Table "pg17.alt_test_pt_1" @@ -984,16 +996,17 @@ ALTER TABLE alt_test ALTER COLUMN a DROP IDENTITY; ERROR: alter table command is currently unsupported DETAIL: Only ADD|DROP COLUMN, SET|DROP NOT NULL, SET|DROP DEFAULT, ADD|DROP|VALIDATE CONSTRAINT, SET (), RESET (), ENABLE|DISABLE|NO FORCE|FORCE ROW LEVEL SECURITY, ATTACH|DETACH PARTITION and TYPE subcommands are supported. -- Verify that alt_test still has identity on column a -\d+ alt_test; - Partitioned table "pg17.alt_test" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - b | integer | | | | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: alt_test_pt_1 FOR VALUES FROM (1) TO (50), - alt_test_pt_2 FOR VALUES FROM (50) TO (100) + alt_test_pt_1 | FOR VALUES FROM (1) TO (50) + alt_test_pt_2 | FOR VALUES FROM (50) TO (100) +(2 rows) \d alt_test_pt_1; Table "pg17.alt_test_pt_1" @@ -1015,16 +1028,17 @@ Partition of: alt_test FOR VALUES FROM (50) TO (100) \c - - - :worker_1_port SET search_path TO pg17; -\d+ alt_test; - Partitioned table "pg17.alt_test" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - b | integer | | | | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: alt_test_pt_1 FOR VALUES FROM (1) TO (50), - alt_test_pt_2 FOR VALUES FROM (50) TO (100) + alt_test_pt_1 | FOR VALUES FROM (1) TO (50) + alt_test_pt_2 | FOR VALUES FROM (50) TO (100) +(2 rows) \d alt_test_pt_1; Table "pg17.alt_test_pt_1" @@ -1064,16 +1078,18 @@ CREATE TABLE lpt_2 PARTITION OF local_partitioned_table FOR VALUES FROM (50) TO CREATE TABLE lpt_3 (a bigint not null, c int); ALTER TABLE local_partitioned_table ATTACH PARTITION lpt_3 FOR VALUES FROM (1000) TO (2000); -- The partitions have the same identity column as the parent table, on coordinator and worker nodes -\d+ local_partitioned_table; - Partitioned table "pg17.local_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: lpt_1 FOR VALUES FROM (1) TO (50), - lpt_2 FOR VALUES FROM (50) TO (1000), - lpt_3 FOR VALUES FROM (1000) TO (2000) + lpt_1 | FOR VALUES FROM (1) TO (50) + lpt_2 | FOR VALUES FROM (50) TO (1000) + lpt_3 | FOR VALUES FROM (1000) TO (2000) +(3 rows) \d lpt_1; Table "pg17.lpt_1" @@ -1101,16 +1117,18 @@ Partition of: local_partitioned_table FOR VALUES FROM (1000) TO (2000) \c - - - :worker_1_port SET search_path TO pg17; -\d+ local_partitioned_table; - Partitioned table "pg17.local_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: lpt_1 FOR VALUES FROM (1) TO (50), - lpt_2 FOR VALUES FROM (50) TO (1000), - lpt_3 FOR VALUES FROM (1000) TO (2000) + lpt_1 | FOR VALUES FROM (1) TO (50) + lpt_2 | FOR VALUES FROM (50) TO (1000) + lpt_3 | FOR VALUES FROM (1000) TO (2000) +(3 rows) \d lpt_1; Table "pg17.lpt_1" @@ -1140,15 +1158,17 @@ Partition of: local_partitioned_table FOR VALUES FROM (1000) TO (2000) SET search_path TO pg17; -- Test detaching a partition with an identity column from a citus local table ALTER TABLE local_partitioned_table DETACH PARTITION lpt_3; -\d+ local_partitioned_table; - Partitioned table "pg17.local_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: lpt_1 FOR VALUES FROM (1) TO (50), - lpt_2 FOR VALUES FROM (50) TO (1000) + lpt_1 | FOR VALUES FROM (1) TO (50) + lpt_2 | FOR VALUES FROM (50) TO (1000) +(2 rows) \d lpt_3; Table "pg17.lpt_3" @@ -1159,15 +1179,17 @@ Partitions: lpt_1 FOR VALUES FROM (1) TO (50), \c - - - :worker_1_port SET search_path TO pg17; -\d+ local_partitioned_table; - Partitioned table "pg17.local_partitioned_table" - Column | Type | Collation | Nullable | Default | Storage | Stats target | Description +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; + partition_name | partition_bound --------------------------------------------------------------------- - a | bigint | | not null | generated by default as identity | plain | | - c | integer | | | | plain | | -Partition key: RANGE (c) -Partitions: lpt_1 FOR VALUES FROM (1) TO (50), - lpt_2 FOR VALUES FROM (50) TO (1000) + lpt_1 | FOR VALUES FROM (1) TO (50) + lpt_2 | FOR VALUES FROM (50) TO (1000) +(2 rows) \d lpt_3; Table "pg17.lpt_3" @@ -2061,7 +2083,7 @@ CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXEC Memory: used=NkB allocated=NkB (9 rows) -select public.explain_filter('explain (memory, analyze) select * from int8_tbl i8'); +select public.explain_filter('explain (memory, analyze, buffers false) select * from int8_tbl i8'); NOTICE: issuing SELECT * FROM worker_save_query_explain_analyze('SELECT q1, q2 FROM pg17.int8_tbl_12242024 i8 WHERE true', '{"verbose": false, "costs": true, "buffers": false, "wal": false, "memory": true, "serialize": "none", "timing": true, "summary": true, "format": "TEXT"}') AS (field_0 bigint, field_1 bigint) DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXECUTE statement @@ -2127,7 +2149,7 @@ CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXEC Planning Time: N.N (1 row) -select public.explain_filter('explain (memory, analyze, format json) select * from int8_tbl i8'); +select public.explain_filter('explain (memory, analyze, buffers false, format json) select * from int8_tbl i8'); NOTICE: issuing SELECT * FROM worker_save_query_explain_analyze('SELECT q1, q2 FROM pg17.int8_tbl_12242024 i8 WHERE true', '{"verbose": false, "costs": true, "buffers": false, "wal": false, "memory": true, "serialize": "none", "timing": true, "summary": true, "format": "JSON"}') AS (field_0 bigint, field_1 bigint) DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXECUTE statement @@ -2344,7 +2366,7 @@ CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXEC Execution Time: N.N (1 row) -select public.explain_filter('explain (analyze,serialize) select * from int8_tbl i8'); +select public.explain_filter('explain (analyze, buffers false, serialize) select * from int8_tbl i8'); NOTICE: issuing SELECT * FROM worker_save_query_explain_analyze('SELECT q1, q2 FROM pg17.int8_tbl_12242024 i8 WHERE true', '{"verbose": false, "costs": true, "buffers": false, "wal": false, "memory": false, "serialize": "text", "timing": true, "summary": true, "format": "TEXT"}') AS (field_0 bigint, field_1 bigint) DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXECUTE statement @@ -2411,7 +2433,7 @@ CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXEC (14 rows) -- this tests an edge case where we have no data to return -select public.explain_filter('explain (analyze,serialize) create temp table explain_temp as select * from int8_tbl i8'); +select public.explain_filter('explain (analyze, buffers false, serialize) create temp table explain_temp as select * from int8_tbl i8'); NOTICE: issuing SELECT * FROM worker_save_query_explain_analyze('SELECT q1, q2 FROM pg17.int8_tbl_12242024 i8 WHERE true', '{"verbose": false, "costs": true, "buffers": false, "wal": false, "memory": false, "serialize": "text", "timing": true, "summary": true, "format": "TEXT"}') AS (field_0 bigint, field_1 bigint) DETAIL: on server postgres@localhost:xxxxx connectionId: xxxxxxx CONTEXT: PL/pgSQL function public.explain_filter(text) line XX at FOR over EXECUTE statement diff --git a/src/test/regress/expected/pg18.out b/src/test/regress/expected/pg18.out index fd42f4070..64b0ba101 100644 --- a/src/test/regress/expected/pg18.out +++ b/src/test/regress/expected/pg18.out @@ -6,10 +6,15 @@ SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 \gset -- test invalid statistics -- behavior is same among PG versions, error message differs --- relevant PG18 commit: 3eea4dc2c7 +-- relevant PG18 commit: 3eea4dc2c7, 38883916e CREATE STATISTICS tst ON a FROM (VALUES (x)) AS foo; -ERROR: cannot create statistics on the specified relation -DETAIL: CREATE STATISTICS only supports tables, foreign tables and materialized views. +ERROR: CREATE STATISTICS only supports relation names in the FROM clause +CREATE FUNCTION tftest(int) returns table(a int, b int) as $$ +SELECT $1, $1+i FROM generate_series(1,5) g(i); +$$ LANGUAGE sql IMMUTABLE STRICT; +CREATE STATISTICS alt_stat2 ON a FROM tftest(1); +ERROR: CREATE STATISTICS only supports relation names in the FROM clause +DROP FUNCTION tftest; \if :server_version_ge_18 \else \q @@ -160,10 +165,290 @@ ORDER BY contype; dist_n_after_drop | n | 1 (2 rows) --- cleanup -RESET client_min_messages; +-- Purpose: test self join elimination for distributed, citus local and local tables. +-- +CREATE TABLE sje_d1 (id bigserial PRIMARY KEY, name text, created_at timestamptz DEFAULT now()); +CREATE TABLE sje_d2 (id bigserial PRIMARY KEY, name text, created_at timestamptz DEFAULT now()); +CREATE TABLE sje_local (id bigserial PRIMARY KEY, title text); +SET citus.next_shard_id TO 4754000; +SELECT create_distributed_table('sje_d1', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +SELECT create_distributed_table('sje_d2', 'id'); + create_distributed_table +--------------------------------------------------------------------- + +(1 row) + +INSERT INTO sje_d1 SELECT i, i::text, now() FROM generate_series(0,100)i; +INSERT INTO sje_d2 SELECT i, i::text, now() FROM generate_series(0,100)i; +INSERT INTO sje_local SELECT i, i::text FROM generate_series(0,100)i; +-- Self-join elimination is applied when distributed tables are involved +-- The query plan has only one join +EXPLAIN (costs off) +select count(1) from sje_d1 INNER +JOIN sje_d2 u1 USING (id) INNER +JOIN sje_d2 u2 USING (id) INNER +JOIN sje_d2 u3 USING (id) INNER +JOIN sje_d2 u4 USING (id) INNER +JOIN sje_d2 u5 USING (id) INNER +JOIN sje_d2 u6 USING (id); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (sje_d1.id = u6.id) + -> Seq Scan on sje_d1_4754000 sje_d1 + -> Hash + -> Seq Scan on sje_d2_4754004 u6 +(12 rows) + +select count(1) from sje_d1 INNER +JOIN sje_d2 u1 USING (id) INNER +JOIN sje_d2 u2 USING (id) INNER +JOIN sje_d2 u3 USING (id) INNER +JOIN sje_d2 u4 USING (id) INNER +JOIN sje_d2 u5 USING (id) INNER +JOIN sje_d2 u6 USING (id); + count +--------------------------------------------------------------------- + 101 +(1 row) + +-- Self-join elimination applied to from list join +EXPLAIN (costs off) +SELECT count(1) from sje_d1 d1, sje_d2 u1, sje_d2 u2, sje_d2 u3 +WHERE d1.id = u1.id and u1.id = u2.id and u3.id = d1.id; + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (d1.id = u3.id) + -> Seq Scan on sje_d1_4754000 d1 + -> Hash + -> Seq Scan on sje_d2_4754004 u3 +(12 rows) + +SELECT count(1) from sje_d1 d1, sje_d2 u1, sje_d2 u2, sje_d2 u3 +WHERE d1.id = u1.id and u1.id = u2.id and u3.id = d1.id; + count +--------------------------------------------------------------------- + 101 +(1 row) + +-- Self-join elimination is not applied when a local table is involved +-- This is a limitation that will be resolved in citus 14 +EXPLAIN (costs off) +select count(1) from sje_d1 INNER +JOIN sje_local u1 USING (id) INNER +JOIN sje_local u2 USING (id) INNER +JOIN sje_local u3 USING (id) INNER +JOIN sje_local u4 USING (id) INNER +JOIN sje_local u5 USING (id) INNER +JOIN sje_local u6 USING (id); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + -> Distributed Subplan XXX_1 + -> Seq Scan on sje_local u1 + -> Distributed Subplan XXX_2 + -> Seq Scan on sje_local u2 + -> Distributed Subplan XXX_3 + -> Seq Scan on sje_local u3 + -> Distributed Subplan XXX_4 + -> Seq Scan on sje_local u4 + -> Distributed Subplan XXX_5 + -> Seq Scan on sje_local u5 + -> Distributed Subplan XXX_6 + -> Seq Scan on sje_local u6 + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (intermediate_result_5.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result_5 + -> Hash + -> Hash Join + Hash Cond: (intermediate_result_4.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result_4 + -> Hash + -> Hash Join + Hash Cond: (intermediate_result_3.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result_3 + -> Hash + -> Hash Join + Hash Cond: (intermediate_result_2.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result_2 + -> Hash + -> Hash Join + Hash Cond: (intermediate_result_1.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result_1 + -> Hash + -> Hash Join + Hash Cond: (intermediate_result.id = sje_d1.id) + -> Function Scan on read_intermediate_result intermediate_result + -> Hash + -> Seq Scan on sje_d1_4754000 sje_d1 +(44 rows) + +select count(1) from sje_d1 INNER +JOIN sje_local u1 USING (id) INNER +JOIN sje_local u2 USING (id) INNER +JOIN sje_local u3 USING (id) INNER +JOIN sje_local u4 USING (id) INNER +JOIN sje_local u5 USING (id) INNER +JOIN sje_local u6 USING (id); + count +--------------------------------------------------------------------- + 101 +(1 row) + +-- to test USING vs ON equivalence +EXPLAIN (costs off) +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 ON (d.id = u1.id) +JOIN sje_d2 u2 ON (u1.id = u2.id); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (d.id = u2.id) + -> Seq Scan on sje_d1_4754000 d + -> Hash + -> Seq Scan on sje_d2_4754004 u2 +(12 rows) + +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 ON (d.id = u1.id) +JOIN sje_d2 u2 ON (u1.id = u2.id); + count +--------------------------------------------------------------------- + 101 +(1 row) + +-- Null-introducing join can have SJE +EXPLAIN (costs off) +SELECT count(*) +FROM sje_d1 d +LEFT JOIN sje_d2 u1 USING (id) +LEFT JOIN sje_d2 u2 USING (id); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Seq Scan on sje_d1_4754000 d +(8 rows) + +SELECT count(*) +FROM sje_d1 d +LEFT JOIN sje_d2 u1 USING (id) +LEFT JOIN sje_d2 u2 USING (id); + count +--------------------------------------------------------------------- + 101 +(1 row) + +-- prepared statement +PREPARE sje_p(int,int) AS +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 USING (id) +JOIN sje_d2 u2 USING (id) +WHERE d.id BETWEEN $1 AND $2; +EXPLAIN (costs off) +EXECUTE sje_p(10,20); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (u2.id = d.id) + -> Seq Scan on sje_d2_4754004 u2 + -> Hash + -> Bitmap Heap Scan on sje_d1_4754000 d + Recheck Cond: ((id >= 10) AND (id <= 20)) + -> Bitmap Index Scan on sje_d1_pkey_4754000 + Index Cond: ((id >= 10) AND (id <= 20)) +(15 rows) + +EXECUTE sje_p(10,20); + count +--------------------------------------------------------------------- + 11 +(1 row) + +-- cte +EXPLAIN (costs off) +WITH z AS (SELECT id FROM sje_d2 WHERE id % 2 = 0) +SELECT count(1) +FROM sje_d1 d +JOIN z USING (id) +JOIN sje_d2 u2 USING (id); + QUERY PLAN +--------------------------------------------------------------------- + Aggregate + -> Custom Scan (Citus Adaptive) + Task Count: 4 + Tasks Shown: One of 4 + -> Task + Node: host=localhost port=xxxxx dbname=regression + -> Aggregate + -> Hash Join + Hash Cond: (d.id = u2.id) + -> Seq Scan on sje_d1_4754000 d + -> Hash + -> Seq Scan on sje_d2_4754004 u2 + Filter: ((id % '2'::bigint) = 0) +(13 rows) + +WITH z AS (SELECT id FROM sje_d2 WHERE id % 2 = 0) +SELECT count(1) +FROM sje_d1 d +JOIN z USING (id) +JOIN sje_d2 u2 USING (id); + count +--------------------------------------------------------------------- + 51 +(1 row) + +-- cleanup with minimum verbosity +SET client_min_messages TO ERROR; RESET search_path; DROP SCHEMA pg18_nn CASCADE; -NOTICE: drop cascades to 2 other objects -DETAIL: drop cascades to table pg18_nn.nn_local -drop cascades to table pg18_nn.nn_dist +RESET client_min_messages; diff --git a/src/test/regress/expected/pg18_0.out b/src/test/regress/expected/pg18_0.out index 8d8c55727..27d3c8d74 100644 --- a/src/test/regress/expected/pg18_0.out +++ b/src/test/regress/expected/pg18_0.out @@ -6,9 +6,15 @@ SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 \gset -- test invalid statistics -- behavior is same among PG versions, error message differs --- relevant PG18 commit: 3eea4dc2c7 +-- relevant PG18 commit: 3eea4dc2c7, 38883916e CREATE STATISTICS tst ON a FROM (VALUES (x)) AS foo; ERROR: only a single relation is allowed in CREATE STATISTICS +CREATE FUNCTION tftest(int) returns table(a int, b int) as $$ +SELECT $1, $1+i FROM generate_series(1,5) g(i); +$$ LANGUAGE sql IMMUTABLE STRICT; +CREATE STATISTICS alt_stat2 ON a FROM tftest(1); +ERROR: only a single relation is allowed in CREATE STATISTICS +DROP FUNCTION tftest; \if :server_version_ge_18 \else \q diff --git a/src/test/regress/expected/shard_move_constraints.out b/src/test/regress/expected/shard_move_constraints.out index 72b49f262..d5b2aa74d 100644 --- a/src/test/regress/expected/shard_move_constraints.out +++ b/src/test/regress/expected/shard_move_constraints.out @@ -136,26 +136,43 @@ INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i; \c - postgres - :worker_1_port SET search_path TO "shard Move Fkeys Indexes", public, pg_catalog; -- show the current state of the constraints -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; + Constraint | Definition --------------------------------------------------------------------- - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(4 rows) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) +(3 rows) -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; - Constraint | Definition +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints --------------------------------------------------------------------- - fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(7 rows) + 1 +(1 row) + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; + Constraint | Definition +--------------------------------------------------------------------- + fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) +(6 rows) + +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 1 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; tablename | indexdef @@ -231,26 +248,42 @@ SELECT public.wait_for_resource_cleanup(); \c - postgres - :worker_2_port SET search_path TO "shard Move Fkeys Indexes", public, pg_catalog; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; + Constraint | Definition --------------------------------------------------------------------- - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(4 rows) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) +(3 rows) -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints --------------------------------------------------------------------- - fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(7 rows) + 1 +(1 row) + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; + Constraint | Definition +--------------------------------------------------------------------- + fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) +(6 rows) + +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 1 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; tablename | indexdef diff --git a/src/test/regress/expected/shard_move_constraints_blocking.out b/src/test/regress/expected/shard_move_constraints_blocking.out index 5f1b91cb6..66dec069e 100644 --- a/src/test/regress/expected/shard_move_constraints_blocking.out +++ b/src/test/regress/expected/shard_move_constraints_blocking.out @@ -132,29 +132,46 @@ INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i; \c - postgres - :worker_1_port SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog; -- show the current state of the constraints -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; + Constraint | Definition --------------------------------------------------------------------- - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(5 rows) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) +(4 rows) -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; - Constraint | Definition +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints --------------------------------------------------------------------- - fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(9 rows) + 1 +(1 row) + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; + Constraint | Definition +--------------------------------------------------------------------- + fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) +(8 rows) + +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 1 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; tablename | indexdef @@ -230,29 +247,45 @@ SELECT public.wait_for_resource_cleanup(); \c - postgres - :worker_2_port SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; + Constraint | Definition --------------------------------------------------------------------- - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - sensors_8970000_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(5 rows) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) +(4 rows) -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; - Constraint | Definition +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints --------------------------------------------------------------------- - fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) - fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) - fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) - fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) - sensors_2020_01_01_8970008_measureid_eventdatetime_fkey | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) -(9 rows) + 1 +(1 row) + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; + Constraint | Definition +--------------------------------------------------------------------- + fkey_from_child_to_child_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_child_to_dist_8970008 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_child_to_parent_8970008 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_child_to_ref_8970008 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) + fkey_from_parent_to_child_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_2020_01_01_8970024(eventdatetime, measureid) + fkey_from_parent_to_dist_8970000 | FOREIGN KEY (measureid) REFERENCES colocated_dist_table_8970016(measureid) + fkey_from_parent_to_parent_8970000 | FOREIGN KEY (eventdatetime, measureid) REFERENCES colocated_partitioned_table_8970020(eventdatetime, measureid) + fkey_from_parent_to_ref_8970000 | FOREIGN KEY (measureid) REFERENCES reference_table_8970028(measureid) +(8 rows) + +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + generated_child_fk_constraints +--------------------------------------------------------------------- + 1 +(1 row) SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; tablename | indexdef diff --git a/src/test/regress/expected/single_shard_table_udfs.out b/src/test/regress/expected/single_shard_table_udfs.out index 26b3f82cc..4bcd1185c 100644 --- a/src/test/regress/expected/single_shard_table_udfs.out +++ b/src/test/regress/expected/single_shard_table_udfs.out @@ -121,7 +121,7 @@ FROM pg_dist_partition WHERE logicalrelid = 'null_dist_key_table'::regclass; SELECT column_name_to_column('null_dist_key_table', 'a'); column_name_to_column --------------------------------------------------------------------- - {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} + {VAR :varno 1 :varattno 1 :vartype 23 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} (1 row) SELECT master_update_shard_statistics(shardid) diff --git a/src/test/regress/expected/sql_procedure.out b/src/test/regress/expected/sql_procedure.out index 63802b354..ac4e45b06 100644 --- a/src/test/regress/expected/sql_procedure.out +++ b/src/test/regress/expected/sql_procedure.out @@ -29,6 +29,7 @@ SELECT * FROM test_table ORDER BY 1, 2; -- commit/rollback is not allowed in procedures in SQL -- following calls should fail +\set VERBOSITY terse CREATE PROCEDURE test_procedure_commit(tt_id int, tt_org_id int) LANGUAGE SQL AS $$ DELETE FROM test_table; COMMIT; @@ -38,7 +39,6 @@ CREATE PROCEDURE test_procedure_commit(tt_id int, tt_org_id int) LANGUAGE SQL AS $$; CALL test_procedure_commit(2,5); ERROR: COMMIT is not allowed in an SQL function -CONTEXT: SQL function "test_procedure_commit" during startup SELECT * FROM test_table ORDER BY 1, 2; id | org_id --------------------------------------------------------------------- @@ -53,7 +53,6 @@ CREATE PROCEDURE test_procedure_rollback(tt_id int, tt_org_id int) LANGUAGE SQL $$; CALL test_procedure_rollback(2,15); ERROR: ROLLBACK is not allowed in an SQL function -CONTEXT: SQL function "test_procedure_rollback" during startup SELECT * FROM test_table ORDER BY 1, 2; id | org_id --------------------------------------------------------------------- @@ -63,6 +62,7 @@ SELECT * FROM test_table ORDER BY 1, 2; DROP PROCEDURE test_procedure_delete_insert(int, int); DROP PROCEDURE test_procedure_commit(int, int); DROP PROCEDURE test_procedure_rollback(int, int); +\set VERBOSITY default -- same tests with plpgsql -- test CREATE PROCEDURE CREATE PROCEDURE test_procedure_delete_insert(id int, org_id int) LANGUAGE PLPGSQL AS $$ diff --git a/src/test/regress/expected/start_stop_metadata_sync.out b/src/test/regress/expected/start_stop_metadata_sync.out index ec9b0a034..c031700b3 100644 --- a/src/test/regress/expected/start_stop_metadata_sync.out +++ b/src/test/regress/expected/start_stop_metadata_sync.out @@ -158,12 +158,12 @@ SELECT * FROM test_matview; SELECT * FROM pg_dist_partition WHERE logicalrelid::text LIKE 'events%' ORDER BY logicalrelid::text; logicalrelid | partmethod | partkey | colocationid | repmodel | autoconverted --------------------------------------------------------------------- - events | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f - events_2021_feb | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f - events_2021_jan | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f - events_replicated | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f - events_replicated_2021_feb | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f - events_replicated_2021_jan | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f + events | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f + events_2021_feb | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f + events_2021_jan | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980000 | s | f + events_replicated | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f + events_replicated_2021_feb | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f + events_replicated_2021_jan | h | {VAR :varno 1 :varattno 1 :vartype 1184 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1} | 980001 | c | f (6 rows) SELECT count(*) > 0 FROM pg_dist_node; diff --git a/src/test/regress/expected/subquery_in_where.out b/src/test/regress/expected/subquery_in_where.out index 361415800..e614d8cba 100644 --- a/src/test/regress/expected/subquery_in_where.out +++ b/src/test/regress/expected/subquery_in_where.out @@ -42,10 +42,11 @@ SELECT * FROM (SELECT 1 AS id, 2 AS value_1, 3 AS value_3 UNION ALL SELECT 2 as id, 3 as value_1, 4 as value_3) AS tt1 WHERE id IN (SELECT user_id - FROM events_table); + FROM events_table) +ORDER BY 1; DEBUG: generating subplan XXX_1 for subquery SELECT 1 AS id, 2 AS value_1, 3 AS value_3 UNION ALL SELECT 2 AS id, 3 AS value_1, 4 AS value_3 DEBUG: generating subplan XXX_2 for subquery SELECT user_id FROM public.events_table -DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT id, value_1, value_3 FROM (SELECT intermediate_result.id, intermediate_result.value_1, intermediate_result.value_3 FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id integer, value_1 integer, value_3 integer)) tt1 WHERE (id OPERATOR(pg_catalog.=) ANY (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer))) +DEBUG: Plan XXX query after replacing subqueries and CTEs: SELECT id, value_1, value_3 FROM (SELECT intermediate_result.id, intermediate_result.value_1, intermediate_result.value_3 FROM read_intermediate_result('XXX_1'::text, 'binary'::citus_copy_format) intermediate_result(id integer, value_1 integer, value_3 integer)) tt1 WHERE (id OPERATOR(pg_catalog.=) ANY (SELECT intermediate_result.user_id FROM read_intermediate_result('XXX_2'::text, 'binary'::citus_copy_format) intermediate_result(user_id integer))) ORDER BY id id | value_1 | value_3 --------------------------------------------------------------------- 1 | 2 | 3 diff --git a/src/test/regress/expected/upgrade_basic_after.out b/src/test/regress/expected/upgrade_basic_after.out index 7c0ebfb29..2ce25bc54 100644 --- a/src/test/regress/expected/upgrade_basic_after.out +++ b/src/test/regress/expected/upgrade_basic_after.out @@ -307,6 +307,7 @@ SELECT * FROM t_range ORDER BY id; ROLLBACK; -- There is a difference in partkey Var representation between PG16 and older versions +-- There is also a difference between PG18 and older versions -- Sanity check here that we can properly do column_to_column_name SELECT column_to_column_name(logicalrelid, partkey) FROM pg_dist_partition WHERE partkey IS NOT NULL ORDER BY 1 LIMIT 1; diff --git a/src/test/regress/expected/upgrade_basic_before.out b/src/test/regress/expected/upgrade_basic_before.out index 9abb6c806..99c523bb0 100644 --- a/src/test/regress/expected/upgrade_basic_before.out +++ b/src/test/regress/expected/upgrade_basic_before.out @@ -66,6 +66,7 @@ UPDATE pg_dist_shard SET shardminvalue = '5', shardmaxvalue = '7' WHERE shardid \copy t_range FROM STDIN with (DELIMITER ',') \copy t_range FROM STDIN with (DELIMITER ',') -- There is a difference in partkey Var representation between PG16 and older versions +-- There is also a difference between PG18 and older versions -- Sanity check here that we can properly do column_to_column_name SELECT column_to_column_name(logicalrelid, partkey) FROM pg_dist_partition WHERE partkey IS NOT NULL ORDER BY 1 LIMIT 1; diff --git a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade.out b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade.out index e3ca353c2..af1236748 100644 --- a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade.out +++ b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade.out @@ -1,31 +1,18 @@ -- Citus upgrades are finished by calling a procedure --- Note that pg_catalog.citus_finish_citus_upgrade() behaves differently --- when last upgrade citus version is less than 11 --- so we have two alternative outputs for this test -\set upgrade_test_old_citus_version `echo "$CITUS_OLD_VERSION"` -SELECT substring(:'upgrade_test_old_citus_version', 'v(\d+)\.\d+\.\d+')::int < 11 -AS upgrade_test_old_citus_version_lt_11_0; - upgrade_test_old_citus_version_lt_11_0 ---------------------------------------------------------------------- - t -(1 row) - -- this is a transactional procedure, so rollback should be fine BEGIN; CALL citus_finish_citus_upgrade(); -NOTICE: Preparing all the existing partitioned table indexes -NOTICE: Preparing to sync the metadata to all nodes +NOTICE: already at the latest distributed schema version (12.1-1) ROLLBACK; -- do the actual job CALL citus_finish_citus_upgrade(); -NOTICE: Preparing all the existing partitioned table indexes -NOTICE: Preparing to sync the metadata to all nodes +NOTICE: already at the latest distributed schema version (12.1-1) -- show that the upgrade is successfull SELECT metadata->>'last_upgrade_version' = extversion FROM pg_dist_node_metadata, pg_extension WHERE extname = 'citus'; ?column? --------------------------------------------------------------------- - t + f (1 row) -- idempotent, should be called multiple times diff --git a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_0.out b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_0.out index 3c8a9a25c..b9682a7e3 100644 --- a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_0.out +++ b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_0.out @@ -1,15 +1,4 @@ -- Citus upgrades are finished by calling a procedure --- Note that pg_catalog.citus_finish_citus_upgrade() behaves differently --- when last upgrade citus version is less than 11 --- so we have two alternative outputs for this test -\set upgrade_test_old_citus_version `echo "$CITUS_OLD_VERSION"` -SELECT substring(:'upgrade_test_old_citus_version', 'v(\d+)\.\d+\.\d+')::int < 11 -AS upgrade_test_old_citus_version_lt_11_0; - upgrade_test_old_citus_version_lt_11_0 ---------------------------------------------------------------------- - f -(1 row) - -- this is a transactional procedure, so rollback should be fine BEGIN; CALL citus_finish_citus_upgrade(); diff --git a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_1.out b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_1.out index 99538b839..8338ea0a5 100644 --- a/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_1.out +++ b/src/test/regress/expected/upgrade_citus_finish_citus_upgrade_1.out @@ -1,15 +1,4 @@ -- Citus upgrades are finished by calling a procedure --- Note that pg_catalog.citus_finish_citus_upgrade() behaves differently --- when last upgrade citus version is less than 11 --- so we have two alternative outputs for this test -\set upgrade_test_old_citus_version `echo "$CITUS_OLD_VERSION"` -SELECT substring(:'upgrade_test_old_citus_version', 'v(\d+)\.\d+\.\d+')::int < 11 -AS upgrade_test_old_citus_version_lt_11_0; - upgrade_test_old_citus_version_lt_11_0 ---------------------------------------------------------------------- - f -(1 row) - -- this is a transactional procedure, so rollback should be fine BEGIN; CALL citus_finish_citus_upgrade(); diff --git a/src/test/regress/sql/alter_role_propagation.sql b/src/test/regress/sql/alter_role_propagation.sql index 658b42e3d..d0fb665df 100644 --- a/src/test/regress/sql/alter_role_propagation.sql +++ b/src/test/regress/sql/alter_role_propagation.sql @@ -112,7 +112,9 @@ SELECT workers.result AS worker_password, pg_authid.rolpassword AS coord_passwor ALTER ROLE new_role PASSWORD ''; SELECT workers.result AS worker_password, pg_authid.rolpassword AS coord_password FROM run_command_on_workers($$SELECT rolpassword FROM pg_authid WHERE rolname = 'new_role'$$) workers, pg_authid WHERE pg_authid.rolname = 'new_role'; +SET client_min_messages TO ERROR; ALTER ROLE new_role PASSWORD 'new_password'; +RESET client_min_messages; SELECT workers.result AS worker_password, pg_authid.rolpassword AS coord_password, workers.result = pg_authid.rolpassword AS password_is_same FROM run_command_on_workers($$SELECT rolpassword FROM pg_authid WHERE rolname = 'new_role'$$) workers, pg_authid WHERE pg_authid.rolname = 'new_role'; ALTER ROLE new_role PASSWORD NULL; diff --git a/src/test/regress/sql/alter_table_set_access_method.sql b/src/test/regress/sql/alter_table_set_access_method.sql index d92fe2f9a..b9e214dab 100644 --- a/src/test/regress/sql/alter_table_set_access_method.sql +++ b/src/test/regress/sql/alter_table_set_access_method.sql @@ -143,6 +143,7 @@ ORDER BY indexname; SELECT conname FROM pg_constraint WHERE conrelid = 'heap_\''tbl'::regclass + AND contype <> 'n' ORDER BY conname; SELECT alter_table_set_access_method('heap_\''tbl', 'columnar'); @@ -154,6 +155,7 @@ ORDER BY indexname; SELECT conname FROM pg_constraint WHERE conrelid = 'heap_\''tbl'::regclass + AND contype <> 'n' ORDER BY conname; -- test different table types diff --git a/src/test/regress/sql/arbitrary_configs_alter_table_add_constraint_without_name.sql b/src/test/regress/sql/arbitrary_configs_alter_table_add_constraint_without_name.sql index 1032b0d04..e440498c2 100644 --- a/src/test/regress/sql/arbitrary_configs_alter_table_add_constraint_without_name.sql +++ b/src/test/regress/sql/arbitrary_configs_alter_table_add_constraint_without_name.sql @@ -11,7 +11,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'products'; + WHERE rel.relname = 'products' AND con.contype <> 'n'; ALTER TABLE products DROP CONSTRAINT products_pkey; @@ -28,7 +28,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'products_ref'; + WHERE rel.relname = 'products_ref' AND con.contype <> 'n'; ALTER TABLE products_ref DROP CONSTRAINT products_ref_pkey2; @@ -40,7 +40,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname LIKE 'very%'; + WHERE rel.relname LIKE 'very%' AND con.contype <> 'n'; ALTER TABLE verylonglonglonglonglonglonglonglonglonglonglonglonglonglonglon DROP CONSTRAINT verylonglonglonglonglonglonglonglonglonglonglonglonglonglo_pkey; @@ -52,7 +52,7 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'dist_partitioned_table'; + WHERE rel.relname = 'dist_partitioned_table' AND con.contype <> 'n'; ALTER TABLE dist_partitioned_table DROP CONSTRAINT dist_partitioned_table_pkey; @@ -63,4 +63,4 @@ SELECT con.conname FROM pg_catalog.pg_constraint con INNER JOIN pg_catalog.pg_class rel ON rel.oid = con.conrelid INNER JOIN pg_catalog.pg_namespace nsp ON nsp.oid = connamespace - WHERE rel.relname = 'citus_local_table'; + WHERE rel.relname = 'citus_local_table' AND con.contype <> 'n'; diff --git a/src/test/regress/sql/citus_non_blocking_split_columnar.sql b/src/test/regress/sql/citus_non_blocking_split_columnar.sql index 5b0665060..525e71dd3 100644 --- a/src/test/regress/sql/citus_non_blocking_split_columnar.sql +++ b/src/test/regress/sql/citus_non_blocking_split_columnar.sql @@ -138,7 +138,14 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -155,7 +162,13 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -209,7 +222,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -226,7 +245,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -280,7 +305,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -297,7 +328,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( diff --git a/src/test/regress/sql/citus_split_shard_columnar_partitioned.sql b/src/test/regress/sql/citus_split_shard_columnar_partitioned.sql index bee287293..53767208a 100644 --- a/src/test/regress/sql/citus_split_shard_columnar_partitioned.sql +++ b/src/test/regress/sql/citus_split_shard_columnar_partitioned.sql @@ -134,7 +134,14 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -151,7 +158,13 @@ SELECT pg_reload_conf(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -205,7 +218,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -222,7 +241,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -276,7 +301,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( @@ -293,7 +324,13 @@ SELECT public.wait_for_resource_cleanup(); FROM pg_catalog.pg_class tbl JOIN public.table_fkeys fk on tbl.oid = fk.relid WHERE tbl.relname like '%_89%' + AND fk."Constraint" NOT LIKE 'sensors%' AND fk."Constraint" NOT LIKE '%to\_parent%\_1' ORDER BY 1, 2; + SELECT count(*) AS generated_child_fk_constraints + FROM pg_catalog.pg_class tbl + JOIN public.table_fkeys fk on tbl.oid = fk.relid + WHERE tbl.relname like '%_89%' + AND (fk."Constraint" LIKE 'sensors%' OR fk."Constraint" LIKE '%to\_parent%\_1'); SELECT tablename, indexdef FROM pg_indexes WHERE tablename like '%_89%' ORDER BY 1,2; SELECT stxname FROM pg_statistic_ext WHERE stxnamespace IN ( diff --git a/src/test/regress/sql/generated_identity.sql b/src/test/regress/sql/generated_identity.sql index 8dcc3ed06..c8917b0fe 100644 --- a/src/test/regress/sql/generated_identity.sql +++ b/src/test/regress/sql/generated_identity.sql @@ -242,11 +242,11 @@ CREATE TABLE color ( ) USING columnar; SELECT create_distributed_table('color', 'color_id'); INSERT INTO color(color_name) VALUES ('Blue'); -\d+ color +SELECT pg_get_serial_sequence('color', 'color_id'); \c - - - :worker_1_port SET search_path TO generated_identities; -\d+ color +SELECT pg_get_serial_sequence('color', 'color_id'); INSERT INTO color(color_name) VALUES ('Red'); -- alter sequence .. restart ALTER SEQUENCE color_color_id_seq RESTART WITH 1000; diff --git a/src/test/regress/sql/local_shard_execution.sql b/src/test/regress/sql/local_shard_execution.sql index 095b9a7bf..0ba2f9e38 100644 --- a/src/test/regress/sql/local_shard_execution.sql +++ b/src/test/regress/sql/local_shard_execution.sql @@ -218,7 +218,7 @@ SET citus.enable_binary_protocol = TRUE; -- though going through distributed execution EXPLAIN (COSTS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) WITH r AS ( SELECT GREATEST(random(), 2) z,* FROM distributed_table) @@ -226,7 +226,7 @@ SELECT 1 FROM r WHERE z < 3; EXPLAIN (COSTS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; -- show that EXPLAIN ANALYZE deleted the row and cascades deletes SELECT * FROM distributed_table WHERE key = 1 AND age = 20 ORDER BY 1,2,3; SELECT * FROM second_distributed_table WHERE key = 1 ORDER BY 1,2; diff --git a/src/test/regress/sql/local_shard_execution_replicated.sql b/src/test/regress/sql/local_shard_execution_replicated.sql index 5b4343bdc..0740d58da 100644 --- a/src/test/regress/sql/local_shard_execution_replicated.sql +++ b/src/test/regress/sql/local_shard_execution_replicated.sql @@ -183,7 +183,7 @@ SET citus.enable_binary_protocol = TRUE; -- though going through distributed execution EXPLAIN (COSTS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) SELECT * FROM distributed_table WHERE key = 1 AND age = 20; EXPLAIN (ANALYZE ON, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) WITH r AS ( SELECT GREATEST(random(), 2) z,* FROM distributed_table) @@ -191,7 +191,7 @@ SELECT 1 FROM r WHERE z < 3; EXPLAIN (COSTS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; -EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; +EXPLAIN (ANALYZE, COSTS OFF, SUMMARY OFF, TIMING OFF, BUFFERS OFF) DELETE FROM distributed_table WHERE key = 1 AND age = 20; -- show that EXPLAIN ANALYZE deleted the row SELECT * FROM distributed_table WHERE key = 1 AND age = 20 ORDER BY 1,2,3; SELECT * FROM second_distributed_table WHERE key = 1 ORDER BY 1,2; diff --git a/src/test/regress/sql/metadata_sync_helpers.sql b/src/test/regress/sql/metadata_sync_helpers.sql index dae331d25..9e67fa337 100644 --- a/src/test/regress/sql/metadata_sync_helpers.sql +++ b/src/test/regress/sql/metadata_sync_helpers.sql @@ -798,11 +798,17 @@ BEGIN TRANSACTION ISOLATION LEVEL READ COMMITTED; -- with an ugly trick, update the vartype of table from int to bigint -- so that making two tables colocated fails - -- include varnullingrels for PG16 + -- include varnullingrels for PG16+ SHOW server_version \gset SELECT substring(:'server_version', '\d+')::int >= 16 AS server_version_ge_16 \gset - \if :server_version_ge_16 + -- include varreturningtype for PG18+ + SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 + \gset + \if :server_version_ge_18 + UPDATE pg_dist_partition SET partkey = '{VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 1 :varreturningtype 0 :varnoold 1 :varoattno 1 :location -1}' + WHERE logicalrelid = 'test_2'::regclass; + \elif :server_version_ge_16 UPDATE pg_dist_partition SET partkey = '{VAR :varno 1 :varattno 1 :vartype 20 :vartypmod -1 :varcollid 0 :varnullingrels (b) :varlevelsup 1 :varnoold 1 :varoattno 1 :location -1}' WHERE logicalrelid = 'test_2'::regclass; \else diff --git a/src/test/regress/sql/multi_array_agg.sql b/src/test/regress/sql/multi_array_agg.sql index 53aa4025f..ad1beff16 100644 --- a/src/test/regress/sql/multi_array_agg.sql +++ b/src/test/regress/sql/multi_array_agg.sql @@ -7,7 +7,7 @@ SET citus.next_shard_id TO 520000; SET citus.coordinator_aggregation_strategy TO 'disabled'; SELECT run_command_on_master_and_workers($r$ -CREATE OR REPLACE FUNCTION array_sort (ANYARRAY) +CREATE OR REPLACE FUNCTION array_sort_citus (ANYARRAY) RETURNS ANYARRAY LANGUAGE SQL AS $$ SELECT ARRAY(SELECT unnest($1) ORDER BY 1) @@ -28,16 +28,16 @@ SELECT array_agg(distinct l_orderkey ORDER BY l_orderkey) FROM lineitem; -- Check array_agg() for different data types and LIMIT clauses -SELECT array_sort(array_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_partkey)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; -SELECT array_sort(array_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_extendedprice)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; -SELECT array_sort(array_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_shipdate)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; -SELECT array_sort(array_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey +SELECT array_sort_citus(array_agg(l_shipmode)) FROM lineitem GROUP BY l_orderkey ORDER BY l_orderkey LIMIT 10; -- Check that we can execute array_agg() within other functions @@ -49,24 +49,24 @@ SELECT array_length(array_agg(l_orderkey), 1) FROM lineitem; -- expressions. Note that the l_orderkey ranges are such that the matching rows -- lie in different shards. -SELECT l_quantity, count(*), avg(l_extendedprice), array_sort(array_agg(l_orderkey)) FROM lineitem +SELECT l_quantity, count(*), avg(l_extendedprice), array_sort_citus(array_agg(l_orderkey)) FROM lineitem WHERE l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; -SELECT l_quantity, array_sort(array_agg(extract (month FROM o_orderdate))) AS my_month +SELECT l_quantity, array_sort_citus(array_agg(extract (month FROM o_orderdate))) AS my_month FROM lineitem, orders WHERE l_orderkey = o_orderkey AND l_quantity < 5 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; -SELECT l_quantity, array_sort(array_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5 +SELECT l_quantity, array_sort_citus(array_agg(l_orderkey * 2 + 1)) FROM lineitem WHERE l_quantity < 5 AND octet_length(l_comment) + octet_length('randomtext'::text) > 40 AND l_orderkey > 5500 AND l_orderkey < 9500 GROUP BY l_quantity ORDER BY l_quantity; -- Check that we can execute array_agg() with an expression containing NULL values -SELECT array_sort(array_agg(case when l_quantity > 20 then l_quantity else NULL end)) +SELECT array_sort_citus(array_agg(case when l_quantity > 20 then l_quantity else NULL end)) FROM lineitem WHERE l_orderkey < 10; -- Check that we return NULL in case there are no input rows to array_agg() -SELECT array_sort(array_agg(l_orderkey)) +SELECT array_sort_citus(array_agg(l_orderkey)) FROM lineitem WHERE l_orderkey < 0; diff --git a/src/test/regress/sql/multi_explain.sql b/src/test/regress/sql/multi_explain.sql index 9ebc3e4e7..365fda970 100644 --- a/src/test/regress/sql/multi_explain.sql +++ b/src/test/regress/sql/multi_explain.sql @@ -1099,7 +1099,7 @@ EXPLAIN :default_explain_flags execute p4(20,20); EXPLAIN :default_analyze_flags execute p4(20,20); -- simple test to confirm we can fetch long (>4KB) plans -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; +EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF, BUFFERS OFF) SELECT * FROM users_table_2 WHERE value_1::text = '00000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000000X'; DROP TABLE users_table_2; diff --git a/src/test/regress/sql/multi_extension.sql b/src/test/regress/sql/multi_extension.sql index 0a82075c3..90d565966 100644 --- a/src/test/regress/sql/multi_extension.sql +++ b/src/test/regress/sql/multi_extension.sql @@ -534,14 +534,17 @@ DROP TABLE columnar_schema_members, columnar_schema_members_pg_depend; -- Use a synthetic pg_dist_shard record to show that upgrade fails -- when there are cstore_fdw tables INSERT INTO pg_dist_shard (logicalrelid, shardid, shardstorage) VALUES ('pg_dist_shard', 1, 'c'); +-- reduce verbosity since there is more context in PG18 (774171c4f) +\set VERBOSITY terse ALTER EXTENSION citus UPDATE TO '11.0-1'; +\set VERBOSITY default DELETE FROM pg_dist_shard WHERE shardid = 1; -- partitioned table count is tracked on Citus 11 upgrade CREATE TABLE e_transactions(order_id varchar(255) NULL, transaction_id int) PARTITION BY LIST(transaction_id); CREATE TABLE orders_2020_07_01 PARTITION OF e_transactions FOR VALUES IN (1,2,3); -INSERT INTO pg_dist_partition VALUES ('e_transactions'::regclass,'h', '{VAR :varno 1 :varattno 1 :vartype 1043 :vartypmod 259 :varcollid 100 :varnullingrels (b) :varlevelsup 0 :varnosyn 1 :varattnosyn 1 :location -1}', 7, 's'); +INSERT INTO pg_dist_partition VALUES ('e_transactions'::regclass,'h', '{VAR :varno 1 :varattno 1 :vartype 1043 :vartypmod 259 :varcollid 100 :varnullingrels (b) :varlevelsup 0 :varreturningtype 0 :varnosyn 1 :varattnosyn 1 :location -1}', 7, 's'); SELECT (metadata->>'partitioned_citus_table_exists_pre_11')::boolean as partitioned_citus_table_exists_pre_11, @@ -699,7 +702,10 @@ SELECT create_distributed_table('null_shard_key', null); -- Show that we cannot downgrade to 11.3-2 becuase the cluster has a -- distributed table with single-shard. +-- reduce verbosity since there is more context in PG18 (774171c4f) +\set VERBOSITY terse ALTER EXTENSION citus UPDATE TO '11.3-2'; +\set VERBOSITY default DROP TABLE null_shard_key; diff --git a/src/test/regress/sql/multi_metadata_sync.sql b/src/test/regress/sql/multi_metadata_sync.sql index 9c584c1ac..d261adb5c 100644 --- a/src/test/regress/sql/multi_metadata_sync.sql +++ b/src/test/regress/sql/multi_metadata_sync.sql @@ -38,7 +38,9 @@ SELECT * FROM pg_dist_partition WHERE partmethod='h' AND repmodel='s'; ALTER SYSTEM SET password_encryption TO md5; SELECT pg_reload_conf(); SELECT pg_sleep(0.1); +SET client_min_messages TO ERROR; ALTER ROLE CURRENT_USER WITH PASSWORD 'dummypassword'; +RESET client_min_messages; -- Show that, with no MX tables, activate node snapshot contains only the delete commands, -- pg_dist_node entries, pg_dist_object entries and roles. diff --git a/src/test/regress/sql/multi_mx_hide_shard_names.sql b/src/test/regress/sql/multi_mx_hide_shard_names.sql index 70f87a875..c275f3b0b 100644 --- a/src/test/regress/sql/multi_mx_hide_shard_names.sql +++ b/src/test/regress/sql/multi_mx_hide_shard_names.sql @@ -249,11 +249,18 @@ SELECT relname FROM pg_catalog.pg_class WHERE relnamespace = 'mx_hide_shard_name -- Relevant PG16 commit: -- https://github.com/postgres/postgres/commit/0c679464a837079acc75ff1d45eaa83f79e05690 -- Relevant Pg17 commit: --- https://github.com/postgres/postgres/commit/067701f57758f9baed5bd9d868539738d77bfa92#diff-afc0ebd67534b71b5b94b29a1387aa6eedffe342a5539f52d686428be323e802 +-- https://github.com/postgres/postgres/commit/067701f57758f9baed5bd9d868539738d77bfa92 +-- Relevant PG18 commit: +-- https://github.com/postgres/postgres/commit/18d67a8d7d30884655d65910b82781d9360819a6 SHOW server_version \gset +SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 \gset SELECT substring(:'server_version', '\d+')::int >= 17 AS server_version_ge_17 \gset SELECT substring(:'server_version', '\d+')::int >= 16 AS server_version_ge_16 \gset -\if :server_version_ge_17 +\if :server_version_ge_18 + SELECT 1 AS client_backend \gset + SELECT 5 AS bgworker \gset + SELECT 6 AS walsender \gset +\elif :server_version_ge_17 SELECT 1 AS client_backend \gset SELECT 4 AS bgworker \gset SELECT 5 AS walsender \gset diff --git a/src/test/regress/sql/multi_partitioning_utils.sql b/src/test/regress/sql/multi_partitioning_utils.sql index 20a238bf1..cac98ea94 100644 --- a/src/test/regress/sql/multi_partitioning_utils.sql +++ b/src/test/regress/sql/multi_partitioning_utils.sql @@ -102,12 +102,22 @@ SELECT generate_alter_table_attach_partition_command('date_partition_2006'); SELECT generate_alter_table_attach_partition_command('date_partition_2007'); -- detach and attach the partition by the command generated by us -\d+ date_partitioned_table +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table'; SELECT detach_and_attach_partition('date_partition_2007', 'date_partitioned_table'); -- check that both partitions are visiable -\d+ date_partitioned_table +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table'; -- make sure that inter shard commands work as expected @@ -121,7 +131,12 @@ SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_ command:='ALTER TABLE date_partitioned_table ATTACH PARTITION date_partition_2007 FOR VALUES FROM (''2007-01-01'') TO (''2008-01-02'')' ); -- the hierarcy is successfully created -\d+ date_partitioned_table_100 +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table_100'; -- Citus can also get the DDL events for the partitions as regular tables SELECT master_get_table_ddl_events('date_partition_2007_100'); @@ -132,7 +147,12 @@ SELECT worker_apply_inter_shard_ddl_command(referencing_shard:=100, referencing_ command:='ALTER TABLE date_partitioned_table DETACH PARTITION date_partition_2007' ); -- the hierarcy is successfully broken -\d+ date_partitioned_table_100 +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'date_partitioned_table_100'; -- now lets have some more complex partitioning hierarcies with -- tables on different schemas and constraints on the tables @@ -171,12 +191,22 @@ SELECT public.generate_alter_table_attach_partition_command('child_2'); SET search_path = 'partition_parent_schema'; -- detach and attach the partition by the command generated by us -\d+ parent_table +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'parent_table'; SELECT public.detach_and_attach_partition('partition_child_1_schema.child_1', 'parent_table'); -- check that both partitions are visiable -\d+ parent_table +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'parent_table'; -- some very simple checks that should error out SELECT public.generate_alter_table_attach_partition_command('parent_table'); diff --git a/src/test/regress/sql/multi_reference_table.sql b/src/test/regress/sql/multi_reference_table.sql index d538effe6..924a135b0 100644 --- a/src/test/regress/sql/multi_reference_table.sql +++ b/src/test/regress/sql/multi_reference_table.sql @@ -768,7 +768,7 @@ WHERE RESET client_min_messages; --- some tests for mark_tables_colocated +-- some tests for update_distributed_table_colocation -- should error out SELECT update_distributed_table_colocation('colocated_table_test_2', colocate_with => 'reference_table_test'); diff --git a/src/test/regress/sql/partitioning_issue_3970.sql b/src/test/regress/sql/partitioning_issue_3970.sql index c60f428b7..12cc32703 100644 --- a/src/test/regress/sql/partitioning_issue_3970.sql +++ b/src/test/regress/sql/partitioning_issue_3970.sql @@ -39,6 +39,7 @@ CREATE TABLE part_table_p202009 PARTITION OF part_table FOR VALUES FROM ('2020-0 SELECT relname, conname, pg_catalog.pg_get_constraintdef(con.oid, true) FROM pg_constraint con JOIN pg_class rel ON (rel.oid=con.conrelid) WHERE relname LIKE 'part_table%' + AND contype <> 'n' ORDER BY 1,2,3; -- check the constraint names on the worker node @@ -47,6 +48,7 @@ ORDER BY 1,2,3; SELECT relname, conname, pg_catalog.pg_get_constraintdef(con.oid, true) FROM pg_constraint con JOIN pg_class rel ON (rel.oid=con.conrelid) WHERE relname SIMILAR TO 'part_table%\_\d%' + AND contype <> 'n' ORDER BY 1,2,3; \c - - - :master_port diff --git a/src/test/regress/sql/pg17.sql b/src/test/regress/sql/pg17.sql index 3bcbc07b7..b88cde1c1 100644 --- a/src/test/regress/sql/pg17.sql +++ b/src/test/regress/sql/pg17.sql @@ -449,7 +449,12 @@ SELECT create_distributed_table('partitioned_table', 'a'); CREATE TABLE pt_2 PARTITION OF partitioned_table FOR VALUES FROM (50) TO (1000); -- (1) The partitioned table has pt_1 and pt_2 as its partitions -\d+ partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; -- (2) The partitions have the same identity column as the parent table; -- This is PG17 behavior for support for identity in partitioned tables. @@ -460,7 +465,12 @@ CREATE TABLE pt_2 PARTITION OF partitioned_table FOR VALUES FROM (50) TO (1000); CREATE TABLE pt_3 (a bigint not null, c int); ALTER TABLE partitioned_table ATTACH PARTITION pt_3 FOR VALUES FROM (1000) TO (2000); -\d+ partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; \d pt_3; -- Partition pt_4 has its own identity column, which is not allowed in PG17 @@ -473,7 +483,12 @@ ALTER TABLE partitioned_table ATTACH PARTITION pt_4 FOR VALUES FROM (2000) TO (3 SET search_path TO pg17; -- Show that DDL for partitioned_table has correctly propagated to the worker node; -- (1) The partitioned table has pt_1, pt_2 and pt_3 as its partitions -\d+ partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; -- (2) The partititions have the same identity column as the parent table \d pt_1; @@ -488,14 +503,24 @@ ALTER TABLE partitioned_table DETACH PARTITION pt_3; -- partitioned_table has pt_1, pt_2 as its partitions -- and pt_3 does not have an identity column -\d+ partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; \d pt_3; -- Verify that the detach has propagated to the worker node \c - - - :worker_1_port SET search_path TO pg17; -\d+ partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'partitioned_table'; \d pt_3; \c - - - :master_port @@ -516,14 +541,24 @@ ALTER TABLE alt_test ADD COLUMN d bigint GENERATED BY DEFAULT AS IDENTITY (START ALTER TABLE alt_test ALTER COLUMN a SET GENERATED BY DEFAULT SET INCREMENT BY 2 SET START WITH 75 RESTART; -- Verify that the identity column was not added, on coordinator and worker nodes -\d+ alt_test; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; \d alt_test_pt_1; \d alt_test_pt_2; \c - - - :worker_1_port SET search_path TO pg17; -\d+ alt_test; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; \d alt_test_pt_1; \d alt_test_pt_2; @@ -545,14 +580,24 @@ CREATE TABLE alt_test_pt_2 PARTITION OF alt_test FOR VALUES FROM (50) TO (100); ALTER TABLE alt_test ALTER COLUMN a DROP IDENTITY; -- Verify that alt_test still has identity on column a -\d+ alt_test; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; \d alt_test_pt_1; \d alt_test_pt_2; \c - - - :worker_1_port SET search_path TO pg17; -\d+ alt_test; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'alt_test'; \d alt_test_pt_1; \d alt_test_pt_2 @@ -577,7 +622,12 @@ CREATE TABLE lpt_3 (a bigint not null, c int); ALTER TABLE local_partitioned_table ATTACH PARTITION lpt_3 FOR VALUES FROM (1000) TO (2000); -- The partitions have the same identity column as the parent table, on coordinator and worker nodes -\d+ local_partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; \d lpt_1; \d lpt_2; \d lpt_3; @@ -585,7 +635,12 @@ ALTER TABLE local_partitioned_table ATTACH PARTITION lpt_3 FOR VALUES FROM (1000 \c - - - :worker_1_port SET search_path TO pg17; -\d+ local_partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; \d lpt_1; \d lpt_2; \d lpt_3; @@ -596,13 +651,23 @@ SET search_path TO pg17; -- Test detaching a partition with an identity column from a citus local table ALTER TABLE local_partitioned_table DETACH PARTITION lpt_3; -\d+ local_partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; \d lpt_3; \c - - - :worker_1_port SET search_path TO pg17; -\d+ local_partitioned_table; +SELECT child.relname AS partition_name, + pg_get_expr(child.relpartbound, child.oid) AS partition_bound +FROM pg_inherits +JOIN pg_class parent ON pg_inherits.inhparent = parent.oid +JOIN pg_class child ON pg_inherits.inhrelid = child.oid +WHERE parent.relname = 'local_partitioned_table'; \d lpt_3; \c - - - :master_port @@ -1225,19 +1290,19 @@ SET citus.log_remote_commands TO true; SET citus.grep_remote_commands TO '%12242024%'; select public.explain_filter('explain (memory) select * from int8_tbl i8'); -select public.explain_filter('explain (memory, analyze) select * from int8_tbl i8'); +select public.explain_filter('explain (memory, analyze, buffers false) select * from int8_tbl i8'); select public.explain_filter('explain (memory, summary, format yaml) select * from int8_tbl i8'); -select public.explain_filter('explain (memory, analyze, format json) select * from int8_tbl i8'); +select public.explain_filter('explain (memory, analyze, buffers false, format json) select * from int8_tbl i8'); prepare int8_query as select * from int8_tbl i8; select public.explain_filter('explain (memory) execute int8_query'); -- serialize tests, same as postgres tests, we just distributed the table select public.explain_filter('explain (analyze, serialize, buffers, format yaml) select * from int8_tbl i8'); -select public.explain_filter('explain (analyze,serialize) select * from int8_tbl i8'); +select public.explain_filter('explain (analyze, buffers false, serialize) select * from int8_tbl i8'); select public.explain_filter('explain (analyze,serialize text,buffers,timing off) select * from int8_tbl i8'); select public.explain_filter('explain (analyze,serialize binary,buffers,timing) select * from int8_tbl i8'); -- this tests an edge case where we have no data to return -select public.explain_filter('explain (analyze,serialize) create temp table explain_temp as select * from int8_tbl i8'); +select public.explain_filter('explain (analyze, buffers false, serialize) create temp table explain_temp as select * from int8_tbl i8'); RESET citus.log_remote_commands; -- End of EXPLAIN MEMORY SERIALIZE tests diff --git a/src/test/regress/sql/pg18.sql b/src/test/regress/sql/pg18.sql index 94c0ad997..b7da4cfc4 100644 --- a/src/test/regress/sql/pg18.sql +++ b/src/test/regress/sql/pg18.sql @@ -7,9 +7,15 @@ SELECT substring(:'server_version', '\d+')::int >= 18 AS server_version_ge_18 -- test invalid statistics -- behavior is same among PG versions, error message differs --- relevant PG18 commit: 3eea4dc2c7 +-- relevant PG18 commit: 3eea4dc2c7, 38883916e CREATE STATISTICS tst ON a FROM (VALUES (x)) AS foo; +CREATE FUNCTION tftest(int) returns table(a int, b int) as $$ +SELECT $1, $1+i FROM generate_series(1,5) g(i); +$$ LANGUAGE sql IMMUTABLE STRICT; +CREATE STATISTICS alt_stat2 ON a FROM tftest(1); +DROP FUNCTION tftest; + \if :server_version_ge_18 \else \q @@ -128,7 +134,120 @@ WHERE conrelid = 'pg18_nn.nn_dist'::regclass GROUP BY contype ORDER BY contype; --- cleanup -RESET client_min_messages; +-- Purpose: test self join elimination for distributed, citus local and local tables. +-- +CREATE TABLE sje_d1 (id bigserial PRIMARY KEY, name text, created_at timestamptz DEFAULT now()); +CREATE TABLE sje_d2 (id bigserial PRIMARY KEY, name text, created_at timestamptz DEFAULT now()); +CREATE TABLE sje_local (id bigserial PRIMARY KEY, title text); + +SET citus.next_shard_id TO 4754000; +SELECT create_distributed_table('sje_d1', 'id'); +SELECT create_distributed_table('sje_d2', 'id'); + +INSERT INTO sje_d1 SELECT i, i::text, now() FROM generate_series(0,100)i; +INSERT INTO sje_d2 SELECT i, i::text, now() FROM generate_series(0,100)i; +INSERT INTO sje_local SELECT i, i::text FROM generate_series(0,100)i; + +-- Self-join elimination is applied when distributed tables are involved +-- The query plan has only one join +EXPLAIN (costs off) +select count(1) from sje_d1 INNER +JOIN sje_d2 u1 USING (id) INNER +JOIN sje_d2 u2 USING (id) INNER +JOIN sje_d2 u3 USING (id) INNER +JOIN sje_d2 u4 USING (id) INNER +JOIN sje_d2 u5 USING (id) INNER +JOIN sje_d2 u6 USING (id); + +select count(1) from sje_d1 INNER +JOIN sje_d2 u1 USING (id) INNER +JOIN sje_d2 u2 USING (id) INNER +JOIN sje_d2 u3 USING (id) INNER +JOIN sje_d2 u4 USING (id) INNER +JOIN sje_d2 u5 USING (id) INNER +JOIN sje_d2 u6 USING (id); + +-- Self-join elimination applied to from list join +EXPLAIN (costs off) +SELECT count(1) from sje_d1 d1, sje_d2 u1, sje_d2 u2, sje_d2 u3 +WHERE d1.id = u1.id and u1.id = u2.id and u3.id = d1.id; + +SELECT count(1) from sje_d1 d1, sje_d2 u1, sje_d2 u2, sje_d2 u3 +WHERE d1.id = u1.id and u1.id = u2.id and u3.id = d1.id; + +-- Self-join elimination is not applied when a local table is involved +-- This is a limitation that will be resolved in citus 14 +EXPLAIN (costs off) +select count(1) from sje_d1 INNER +JOIN sje_local u1 USING (id) INNER +JOIN sje_local u2 USING (id) INNER +JOIN sje_local u3 USING (id) INNER +JOIN sje_local u4 USING (id) INNER +JOIN sje_local u5 USING (id) INNER +JOIN sje_local u6 USING (id); + +select count(1) from sje_d1 INNER +JOIN sje_local u1 USING (id) INNER +JOIN sje_local u2 USING (id) INNER +JOIN sje_local u3 USING (id) INNER +JOIN sje_local u4 USING (id) INNER +JOIN sje_local u5 USING (id) INNER +JOIN sje_local u6 USING (id); + + +-- to test USING vs ON equivalence +EXPLAIN (costs off) +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 ON (d.id = u1.id) +JOIN sje_d2 u2 ON (u1.id = u2.id); + +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 ON (d.id = u1.id) +JOIN sje_d2 u2 ON (u1.id = u2.id); + +-- Null-introducing join can have SJE +EXPLAIN (costs off) +SELECT count(*) +FROM sje_d1 d +LEFT JOIN sje_d2 u1 USING (id) +LEFT JOIN sje_d2 u2 USING (id); + +SELECT count(*) +FROM sje_d1 d +LEFT JOIN sje_d2 u1 USING (id) +LEFT JOIN sje_d2 u2 USING (id); + +-- prepared statement +PREPARE sje_p(int,int) AS +SELECT count(1) +FROM sje_d1 d +JOIN sje_d2 u1 USING (id) +JOIN sje_d2 u2 USING (id) +WHERE d.id BETWEEN $1 AND $2; + +EXPLAIN (costs off) +EXECUTE sje_p(10,20); + +EXECUTE sje_p(10,20); + +-- cte +EXPLAIN (costs off) +WITH z AS (SELECT id FROM sje_d2 WHERE id % 2 = 0) +SELECT count(1) +FROM sje_d1 d +JOIN z USING (id) +JOIN sje_d2 u2 USING (id); + +WITH z AS (SELECT id FROM sje_d2 WHERE id % 2 = 0) +SELECT count(1) +FROM sje_d1 d +JOIN z USING (id) +JOIN sje_d2 u2 USING (id); + +-- cleanup with minimum verbosity +SET client_min_messages TO ERROR; RESET search_path; DROP SCHEMA pg18_nn CASCADE; +RESET client_min_messages; diff --git a/src/test/regress/sql/shard_move_constraints.sql b/src/test/regress/sql/shard_move_constraints.sql index 30fddada9..1b3ccef80 100644 --- a/src/test/regress/sql/shard_move_constraints.sql +++ b/src/test/regress/sql/shard_move_constraints.sql @@ -127,8 +127,19 @@ INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i; SET search_path TO "shard Move Fkeys Indexes", public, pg_catalog; -- show the current state of the constraints -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2; @@ -155,8 +166,19 @@ SELECT public.wait_for_resource_cleanup(); \c - postgres - :worker_2_port SET search_path TO "shard Move Fkeys Indexes", public, pg_catalog; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2; diff --git a/src/test/regress/sql/shard_move_constraints_blocking.sql b/src/test/regress/sql/shard_move_constraints_blocking.sql index df394820c..66b58f42b 100644 --- a/src/test/regress/sql/shard_move_constraints_blocking.sql +++ b/src/test/regress/sql/shard_move_constraints_blocking.sql @@ -121,8 +121,19 @@ INSERT INTO sensors SELECT i, '2020-01-05', '{}' FROM generate_series(0,1000)i; SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog; -- show the current state of the constraints -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; +-- separating generated child FK constraints since PG18 changed their naming (3db61db4) +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2; @@ -149,8 +160,19 @@ SELECT public.wait_for_resource_cleanup(); \c - postgres - :worker_2_port SET search_path TO "blocking shard Move Fkeys Indexes", public, pg_catalog; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass ORDER BY 1,2; -SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass ORDER BY 1,2; + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1, 2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_8970000'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + +SELECT "Constraint", "Definition" FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND "Constraint" NOT LIKE 'sensors%' AND "Constraint" NOT LIKE '%to\_parent%\_1' +ORDER BY 1,2; +SELECT count(*) AS generated_child_fk_constraints FROM table_fkeys WHERE relid='sensors_2020_01_01_8970008'::regclass +AND ("Constraint" LIKE 'sensors%' OR "Constraint" LIKE '%to\_parent%\_1'); + SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_8970000' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='sensors_2020_01_01_8970008' ORDER BY 1,2; SELECT tablename, indexdef FROM pg_indexes WHERE tablename ='index_backed_rep_identity_8970029' ORDER BY 1,2; diff --git a/src/test/regress/sql/sql_procedure.sql b/src/test/regress/sql/sql_procedure.sql index 63b9eed80..4be9706b9 100644 --- a/src/test/regress/sql/sql_procedure.sql +++ b/src/test/regress/sql/sql_procedure.sql @@ -27,6 +27,9 @@ SELECT * FROM test_table ORDER BY 1, 2; -- commit/rollback is not allowed in procedures in SQL -- following calls should fail + +\set VERBOSITY terse + CREATE PROCEDURE test_procedure_commit(tt_id int, tt_org_id int) LANGUAGE SQL AS $$ DELETE FROM test_table; COMMIT; @@ -52,6 +55,8 @@ DROP PROCEDURE test_procedure_delete_insert(int, int); DROP PROCEDURE test_procedure_commit(int, int); DROP PROCEDURE test_procedure_rollback(int, int); +\set VERBOSITY default + -- same tests with plpgsql -- test CREATE PROCEDURE diff --git a/src/test/regress/sql/subquery_in_where.sql b/src/test/regress/sql/subquery_in_where.sql index 3a07cdc75..60a69a3bb 100644 --- a/src/test/regress/sql/subquery_in_where.sql +++ b/src/test/regress/sql/subquery_in_where.sql @@ -34,7 +34,8 @@ SELECT * FROM (SELECT 1 AS id, 2 AS value_1, 3 AS value_3 UNION ALL SELECT 2 as id, 3 as value_1, 4 as value_3) AS tt1 WHERE id IN (SELECT user_id - FROM events_table); + FROM events_table) +ORDER BY 1; -- Recurring tuples in from clause as CTE and SET operation in WHERE clause SELECT Count(*) diff --git a/src/test/regress/sql/upgrade_basic_after.sql b/src/test/regress/sql/upgrade_basic_after.sql index 855c06008..10604f6c3 100644 --- a/src/test/regress/sql/upgrade_basic_after.sql +++ b/src/test/regress/sql/upgrade_basic_after.sql @@ -103,6 +103,7 @@ SELECT * FROM t_range ORDER BY id; ROLLBACK; -- There is a difference in partkey Var representation between PG16 and older versions +-- There is also a difference between PG18 and older versions -- Sanity check here that we can properly do column_to_column_name SELECT column_to_column_name(logicalrelid, partkey) FROM pg_dist_partition WHERE partkey IS NOT NULL ORDER BY 1 LIMIT 1; diff --git a/src/test/regress/sql/upgrade_basic_before.sql b/src/test/regress/sql/upgrade_basic_before.sql index 868483264..e81544d2a 100644 --- a/src/test/regress/sql/upgrade_basic_before.sql +++ b/src/test/regress/sql/upgrade_basic_before.sql @@ -53,6 +53,7 @@ UPDATE pg_dist_shard SET shardminvalue = '5', shardmaxvalue = '7' WHERE shardid \. -- There is a difference in partkey Var representation between PG16 and older versions +-- There is also a difference between PG18 and older versions -- Sanity check here that we can properly do column_to_column_name SELECT column_to_column_name(logicalrelid, partkey) FROM pg_dist_partition WHERE partkey IS NOT NULL ORDER BY 1 LIMIT 1; diff --git a/src/test/regress/sql/upgrade_citus_finish_citus_upgrade.sql b/src/test/regress/sql/upgrade_citus_finish_citus_upgrade.sql index 8d0405ea6..3200796cd 100644 --- a/src/test/regress/sql/upgrade_citus_finish_citus_upgrade.sql +++ b/src/test/regress/sql/upgrade_citus_finish_citus_upgrade.sql @@ -1,12 +1,4 @@ -- Citus upgrades are finished by calling a procedure - --- Note that pg_catalog.citus_finish_citus_upgrade() behaves differently --- when last upgrade citus version is less than 11 --- so we have two alternative outputs for this test -\set upgrade_test_old_citus_version `echo "$CITUS_OLD_VERSION"` -SELECT substring(:'upgrade_test_old_citus_version', 'v(\d+)\.\d+\.\d+')::int < 11 -AS upgrade_test_old_citus_version_lt_11_0; - -- this is a transactional procedure, so rollback should be fine BEGIN; CALL citus_finish_citus_upgrade();