From ab499649d570c008f368fe78caccb9a5f80a4c01 Mon Sep 17 00:00:00 2001 From: Greg Burd Date: Mon, 27 Jan 2025 13:28:59 -0500 Subject: [PATCH] Expand HOT update path to include expression and partial indexes Expression indexes have historically been considered "hot blocking", but this choice significanly impares the utility of the JSONB data type as all indexes referencing data within documents are formed using expressions. Thus an update to a JSONB column will prevent the HOT path and force all indexes across all columns to be updated. Updates to attributes referenced by partial indexes may fall entirely outside of the range of values maintained by an index, but despite that they are effectively "HOT blocking". This too is changed to allow for HOT updates in cases where the predicate on the index is not satisfied for either the old or the new tuple. It appears that the primary reason for not checking expression indexes or the expressions forming partial indexes, besides the overhead of the expression itself, was that the execution of expression could self-deadlock. Here we are careful to hold the pin, but not the buffer lock when evaluating the expressions. We are careful to only evaluate expressions when they are both in the modified set for the update and the modified attribute is only referenced by vars in those expressions. It is important to note that this patch was inspired by, but is a significant departure from, a previous patch. https://postgr.es/m/4d9928ee-a9e6-15f9-9c82-5981f13ffca6%40postgrespro.ru applied in c203d6cf81b4d7e43edb2b75ec1b741ba48e04e0 and later reverted in 05f84605dbeb9cf8279a157234b24bbb706c5256. Signed-off-by: Greg Burd --- doc/src/sgml/ref/create_table.sgml | 18 + doc/src/sgml/storage.sgml | 29 +- src/backend/access/common/reloptions.c | 12 +- src/backend/access/heap/README.HOT | 45 +- src/backend/access/heap/heapam.c | 71 +- src/backend/access/heap/heapam_handler.c | 15 +- src/backend/access/table/tableam.c | 5 +- src/backend/catalog/index.c | 48 + src/backend/catalog/indexing.c | 18 +- src/backend/commands/copyfrom.c | 2 +- src/backend/executor/execExpr.c | 7 +- src/backend/executor/execIndexing.c | 212 +++- src/backend/executor/execPartition.c | 2 +- src/backend/executor/execReplication.c | 10 +- src/backend/executor/nodeModifyTable.c | 31 +- src/backend/replication/logical/worker.c | 6 +- src/backend/utils/cache/relcache.c | 81 +- src/bin/psql/tab-complete.in.c | 2 +- src/include/access/heapam.h | 6 +- src/include/access/tableam.h | 36 +- src/include/catalog/index.h | 1 + src/include/executor/executor.h | 8 +- src/include/nodes/execnodes.h | 15 + src/include/utils/rel.h | 10 + src/include/utils/relcache.h | 1 + .../regress/expected/heap_hot_updates.out | 1048 +++++++++++++++++ src/test/regress/parallel_schedule | 5 + src/test/regress/sql/heap_hot_updates.sql | 718 +++++++++++ src/tools/pgindent/typedefs.list | 2 +- 29 files changed, 2321 insertions(+), 143 deletions(-) create mode 100644 src/test/regress/expected/heap_hot_updates.out create mode 100644 src/test/regress/sql/heap_hot_updates.sql diff --git a/doc/src/sgml/ref/create_table.sgml b/doc/src/sgml/ref/create_table.sgml index a157a244e4ef..02dcb20a845e 100644 --- a/doc/src/sgml/ref/create_table.sgml +++ b/doc/src/sgml/ref/create_table.sgml @@ -2012,6 +2012,24 @@ WITH ( MODULUS numeric_literal, REM + + expression_checks (boolean) + + expression_checks storage parameter + + + + + Enables or disables evaulation of predicate expressions on partial + indexes or expressions used to define indexes during updates. + If true, then these expressions are evaluated during + updates to data within the heap relation against the old and new values + and then compared to determine if HOT updates are + allowable or not. The default value is true. + + + + diff --git a/doc/src/sgml/storage.sgml b/doc/src/sgml/storage.sgml index 02ddfda834a2..581ac0a5a510 100644 --- a/doc/src/sgml/storage.sgml +++ b/doc/src/sgml/storage.sgml @@ -1101,10 +1101,10 @@ data. Empty in ordinary tables. - The update does not modify any columns referenced by the table's indexes, - not including summarizing indexes. The only summarizing index method in - the core PostgreSQL distribution is BRIN. + The update does not modify index keys, or when using a summarized + index. The only summarizing index method in the core + PostgreSQL distribution is + BRIN. @@ -1142,6 +1142,27 @@ data. Empty in ordinary tables. + + HOT updates can occur when the expression used to define + an index shows no changes to the indexed value. To determine this requires + that the expression be evaulated for the old and new values to be stored in + the index and then compared. This allows for HOT updates + when data indexed within JSONB columns is unchanged. To disable this + behavior and avoid the overhead of evaluating the expression during updates + set the expression_checks option to false for the table. + + + + HOT updates can also occur when updated values are not + within the predicate of a partial index. However, HOT + updates are not possible when the updated value and the current value differ + with regards to the predicate. To determine this requires that the predicate + expression be evaluated for the old and new values to be stored in the index + and then compared. To disable this behavior and avoid the overhead of + evaluating the expression during updates set + the expression_checks option to false for the table. + + You can increase the likelihood of sufficient page space for HOT updates by decreasing a table's lockmode; Bitmapset *hot_attrs; Bitmapset *sum_attrs; + Bitmapset *exp_attrs; Bitmapset *key_attrs; Bitmapset *id_attrs; Bitmapset *interesting_attrs; @@ -3293,6 +3294,8 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, bool checked_lockers; bool locker_remains; bool id_has_external = false; + bool expression_checks = RelationGetExpressionChecks(relation); + bool expr_idx_updated = false; TransactionId xmax_new_tuple, xmax_old_tuple; uint16 infomask_old_tuple, @@ -3342,12 +3345,15 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, INDEX_ATTR_BITMAP_HOT_BLOCKING); sum_attrs = RelationGetIndexAttrBitmap(relation, INDEX_ATTR_BITMAP_SUMMARIZED); + exp_attrs = RelationGetIndexAttrBitmap(relation, + INDEX_ATTR_BITMAP_EXPRESSION); key_attrs = RelationGetIndexAttrBitmap(relation, INDEX_ATTR_BITMAP_KEY); id_attrs = RelationGetIndexAttrBitmap(relation, INDEX_ATTR_BITMAP_IDENTITY_KEY); interesting_attrs = NULL; interesting_attrs = bms_add_members(interesting_attrs, hot_attrs); interesting_attrs = bms_add_members(interesting_attrs, sum_attrs); + interesting_attrs = bms_add_members(interesting_attrs, exp_attrs); interesting_attrs = bms_add_members(interesting_attrs, key_attrs); interesting_attrs = bms_add_members(interesting_attrs, id_attrs); @@ -3356,6 +3362,29 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, buffer = ReadBuffer(relation, block); page = BufferGetPage(buffer); + /* + * hot_attrs includes indexes with expressions and indexes with predicates + * that may not be impacted by this change. If the modified attributes in + * this update don't overlap with any attributes referenced by indexes on + * the relation then we can use the HOT update path. If they do overlap, + * then check to see if the overlap is exclusively due to attributes that + * are only referenced within expressions. If that is the case, the HOT + * update path may be possible iff the expression indexes are unchanged by + * this update or, with partial indexes, both the new and the old heap + * tuples don't satisfy the partial index predicate expression (meaning + * they are both outside of the scope of the index). + */ + if (expression_checks && + updateCxt->rri && + updateCxt->rri->ri_projectNew && + bms_is_subset(updateCxt->rri->ri_projectNew->pi_modifiedCols, exp_attrs)) + expr_idx_updated = ExecExprIndexesRequireUpdates(relation, + updateCxt->rri, + updateCxt->rri->ri_projectNew->pi_modifiedCols, + updateCxt->estate, + updateCxt->rri->ri_oldTupleSlot, + updateCxt->rri->ri_newTupleSlot); + /* * Before locking the buffer, pin the visibility map page if it appears to * be necessary. Since we haven't got the lock yet, someone else might be @@ -3403,10 +3432,11 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, tmfd->ctid = *otid; tmfd->xmax = InvalidTransactionId; tmfd->cmax = InvalidCommandId; - *update_indexes = TU_None; + updateCxt->updateIndexes = TU_None; bms_free(hot_attrs); bms_free(sum_attrs); + bms_free(exp_attrs); bms_free(key_attrs); bms_free(id_attrs); /* modified_attrs not yet initialized */ @@ -3704,10 +3734,11 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, UnlockTupleTuplock(relation, &(oldtup.t_self), *lockmode); if (vmbuffer != InvalidBuffer) ReleaseBuffer(vmbuffer); - *update_indexes = TU_None; + updateCxt->updateIndexes = TU_None; bms_free(hot_attrs); bms_free(sum_attrs); + bms_free(exp_attrs); bms_free(key_attrs); bms_free(id_attrs); bms_free(modified_attrs); @@ -4025,22 +4056,22 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, if (newbuf == buffer) { /* - * Since the new tuple is going into the same page, we might be able - * to do a HOT update. Check if any of the index columns have been - * changed. + * If all modified attributes were only referenced by summarizing + * indexes then we remain HOT, but we need to update those indexes to + * ensure that they are consistent with the new tuple. */ - if (!bms_overlap(modified_attrs, hot_attrs)) + if (!bms_overlap(modified_attrs, hot_attrs) || + (expression_checks && + (bms_is_subset(modified_attrs, exp_attrs) && !expr_idx_updated))) { use_hot_update = true; /* - * If none of the columns that are used in hot-blocking indexes - * were updated, we can apply HOT, but we do still need to check - * if we need to update the summarizing indexes, and update those - * indexes if the columns were updated, or we may fail to detect - * e.g. value bound changes in BRIN minmax indexes. + * If all modified attributes were only referenced by summarizing + * indexes then we remain HOT, but we need to update those indexes + * to ensure that they are consistent with the new tuple. */ - if (bms_overlap(modified_attrs, sum_attrs)) + if (bms_is_subset(modified_attrs, sum_attrs)) summarized_update = true; } } @@ -4211,18 +4242,19 @@ heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, if (use_hot_update) { if (summarized_update) - *update_indexes = TU_Summarizing; + updateCxt->updateIndexes = TU_Summarizing; else - *update_indexes = TU_None; + updateCxt->updateIndexes = TU_None; } else - *update_indexes = TU_All; + updateCxt->updateIndexes = TU_All; if (old_key_tuple != NULL && old_key_copied) heap_freetuple(old_key_tuple); bms_free(hot_attrs); bms_free(sum_attrs); + bms_free(exp_attrs); bms_free(key_attrs); bms_free(id_attrs); bms_free(modified_attrs); @@ -4500,16 +4532,15 @@ HeapDetermineColumnsInfo(Relation relation, */ void simple_heap_update(Relation relation, ItemPointer otid, HeapTuple tup, - TU_UpdateIndexes *update_indexes) + UpdateContext *updateCxt) { TM_Result result; TM_FailureData tmfd; - LockTupleMode lockmode; result = heap_update(relation, otid, tup, GetCurrentCommandId(true), InvalidSnapshot, true /* wait for commit */ , - &tmfd, &lockmode, update_indexes); + &tmfd, updateCxt); switch (result) { case TM_SelfModified: diff --git a/src/backend/access/heap/heapam_handler.c b/src/backend/access/heap/heapam_handler.c index bcbac844bb66..a7e65f7e2f60 100644 --- a/src/backend/access/heap/heapam_handler.c +++ b/src/backend/access/heap/heapam_handler.c @@ -316,8 +316,7 @@ heapam_tuple_delete(Relation relation, ItemPointer tid, CommandId cid, static TM_Result heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot, CommandId cid, Snapshot snapshot, Snapshot crosscheck, - bool wait, TM_FailureData *tmfd, - LockTupleMode *lockmode, TU_UpdateIndexes *update_indexes) + bool wait, TM_FailureData *tmfd, UpdateContext *updateCxt) { bool shouldFree = true; HeapTuple tuple = ExecFetchSlotHeapTuple(slot, true, &shouldFree); @@ -328,7 +327,7 @@ heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot, tuple->t_tableOid = slot->tts_tableOid; result = heap_update(relation, otid, tuple, cid, crosscheck, wait, - tmfd, lockmode, update_indexes); + tmfd, updateCxt); ItemPointerCopy(&tuple->t_self, &slot->tts_tid); /* @@ -343,14 +342,14 @@ heapam_tuple_update(Relation relation, ItemPointer otid, TupleTableSlot *slot, */ if (result != TM_Ok) { - Assert(*update_indexes == TU_None); - *update_indexes = TU_None; + Assert(updateCxt->updateIndexes == TU_None); + updateCxt->updateIndexes = TU_None; } else if (!HeapTupleIsHeapOnly(tuple)) - Assert(*update_indexes == TU_All); + Assert(updateCxt->updateIndexes == TU_All); else - Assert((*update_indexes == TU_Summarizing) || - (*update_indexes == TU_None)); + Assert((updateCxt->updateIndexes == TU_Summarizing) || + (updateCxt->updateIndexes == TU_None)); if (shouldFree) pfree(tuple); diff --git a/src/backend/access/table/tableam.c b/src/backend/access/table/tableam.c index 5e41404937eb..c1d41a1fb874 100644 --- a/src/backend/access/table/tableam.c +++ b/src/backend/access/table/tableam.c @@ -336,17 +336,16 @@ void simple_table_tuple_update(Relation rel, ItemPointer otid, TupleTableSlot *slot, Snapshot snapshot, - TU_UpdateIndexes *update_indexes) + UpdateContext *updateCxt) { TM_Result result; TM_FailureData tmfd; - LockTupleMode lockmode; result = table_tuple_update(rel, otid, slot, GetCurrentCommandId(true), snapshot, InvalidSnapshot, true /* wait for commit */ , - &tmfd, &lockmode, update_indexes); + &tmfd, updateCxt); switch (result) { diff --git a/src/backend/catalog/index.c b/src/backend/catalog/index.c index 5d9db167e595..205147fe341e 100644 --- a/src/backend/catalog/index.c +++ b/src/backend/catalog/index.c @@ -2467,6 +2467,8 @@ BuildIndexInfo(Relation index) &ii->ii_ExclusionStrats); } + ii->ii_IndexAttrByVal = NULL; + return ii; } @@ -2707,6 +2709,52 @@ BuildSpeculativeIndexInfo(Relation index, IndexInfo *ii) } } +/* ---------------- + * BuildExpressionIndexInfo + * Add extra state to IndexInfo record + * + * For expression indexes updates may not change the indexed value allowing + * for a HOT update. Add information to the IndexInfo to allow for checking + * if the indexed value has changed. + * + * Do this processing here rather than in BuildIndexInfo() to not incur the + * overhead in the common non-expression cases. + * ---------------- + */ +void +BuildExpressionIndexInfo(Relation index, IndexInfo *ii) +{ + int i; + int indnkeyatts; + + /* + * Expressions are not allowed on non-key attributes, so we can skip them + * as they should show up in the index HOT-blocking attributes. + */ + indnkeyatts = IndexRelationGetNumberOfKeyAttributes(index); + + /* + * Collect attributes used by the index, their len and if they are by + * value. + */ + for (i = 0; i < indnkeyatts; i++) + { + CompactAttribute *attr = TupleDescCompactAttr(RelationGetDescr(index), i); + + ii->ii_IndexAttrLen[i] = attr->attlen; + if (attr->attbyval) + ii->ii_IndexAttrByVal = bms_add_member(ii->ii_IndexAttrByVal, i); + } + + /* collect attributes used in the expression */ + if (ii->ii_Expressions) + pull_varattnos((Node *) ii->ii_Expressions, 1, &ii->ii_ExpressionsAttrs); + + /* collect attributes used in the predicate */ + if (ii->ii_Predicate) + pull_varattnos((Node *) ii->ii_Predicate, 1, &ii->ii_PredicateAttrs); +} + /* ---------------- * FormIndexDatum * Construct values[] and isnull[] arrays for a new index tuple. diff --git a/src/backend/catalog/indexing.c b/src/backend/catalog/indexing.c index 25c4b6bdc87f..c413c099da84 100644 --- a/src/backend/catalog/indexing.c +++ b/src/backend/catalog/indexing.c @@ -49,7 +49,7 @@ CatalogOpenIndexes(Relation heapRel) resultRelInfo->ri_RelationDesc = heapRel; resultRelInfo->ri_TrigDesc = NULL; /* we don't fire triggers */ - ExecOpenIndices(resultRelInfo, false); + ExecOpenIndices(resultRelInfo, false, false); return resultRelInfo; } @@ -313,15 +313,17 @@ void CatalogTupleUpdate(Relation heapRel, ItemPointer otid, HeapTuple tup) { CatalogIndexState indstate; - TU_UpdateIndexes updateIndexes = TU_All; + UpdateContext updateCxt = {0}; + + updateCxt.updateIndexes = TU_All; CatalogTupleCheckConstraints(heapRel, tup); indstate = CatalogOpenIndexes(heapRel); - simple_heap_update(heapRel, otid, tup, &updateIndexes); + simple_heap_update(heapRel, otid, tup, &updateCxt); - CatalogIndexInsert(indstate, tup, updateIndexes); + CatalogIndexInsert(indstate, tup, updateCxt.updateIndexes); CatalogCloseIndexes(indstate); } @@ -337,13 +339,15 @@ void CatalogTupleUpdateWithInfo(Relation heapRel, ItemPointer otid, HeapTuple tup, CatalogIndexState indstate) { - TU_UpdateIndexes updateIndexes = TU_All; + UpdateContext updateCxt = {0}; + + updateCxt.updateIndexes = TU_All; CatalogTupleCheckConstraints(heapRel, tup); - simple_heap_update(heapRel, otid, tup, &updateIndexes); + simple_heap_update(heapRel, otid, tup, &updateCxt); - CatalogIndexInsert(indstate, tup, updateIndexes); + CatalogIndexInsert(indstate, tup, updateCxt.updateIndexes); } /* diff --git a/src/backend/commands/copyfrom.c b/src/backend/commands/copyfrom.c index 12781963b4f9..aea42c495249 100644 --- a/src/backend/commands/copyfrom.c +++ b/src/backend/commands/copyfrom.c @@ -921,7 +921,7 @@ CopyFrom(CopyFromState cstate) /* Verify the named relation is a valid target for INSERT */ CheckValidResultRel(resultRelInfo, CMD_INSERT, ONCONFLICT_NONE, NIL); - ExecOpenIndices(resultRelInfo, false); + ExecOpenIndices(resultRelInfo, false, false); /* * Set up a ModifyTableState so we can let FDW(s) init themselves for diff --git a/src/backend/executor/execExpr.c b/src/backend/executor/execExpr.c index f1569879b529..8bb8692b46ea 100644 --- a/src/backend/executor/execExpr.c +++ b/src/backend/executor/execExpr.c @@ -610,8 +610,9 @@ ExecBuildUpdateProjection(List *targetList, { AttrNumber targetattnum = lfirst_int(lc); - assignedCols = bms_add_member(assignedCols, targetattnum); + assignedCols = bms_add_member(assignedCols, targetattnum - FirstLowInvalidHeapAttributeNumber); } + projInfo->pi_modifiedCols = assignedCols; /* * We need to insert EEOP_*_FETCHSOME steps to ensure the input tuples are @@ -624,7 +625,7 @@ ExecBuildUpdateProjection(List *targetList, if (attr->attisdropped) continue; - if (bms_is_member(attnum, assignedCols)) + if (bms_is_member(attnum - FirstLowInvalidHeapAttributeNumber, assignedCols)) continue; deform.last_scan = attnum; break; @@ -732,7 +733,7 @@ ExecBuildUpdateProjection(List *targetList, scratch.d.assign_tmp.resultnum = attnum - 1; ExprEvalPushStep(state, &scratch); } - else if (!bms_is_member(attnum, assignedCols)) + else if (!bms_is_member(attnum - FirstLowInvalidHeapAttributeNumber, assignedCols)) { /* Certainly the right type, so needn't check */ scratch.opcode = EEOP_ASSIGN_SCAN_VAR; diff --git a/src/backend/executor/execIndexing.c b/src/backend/executor/execIndexing.c index ca33a854278e..940311dc0d6b 100644 --- a/src/backend/executor/execIndexing.c +++ b/src/backend/executor/execIndexing.c @@ -113,10 +113,13 @@ #include "catalog/index.h" #include "executor/executor.h" #include "nodes/nodeFuncs.h" +#include "optimizer/optimizer.h" #include "storage/lmgr.h" #include "utils/multirangetypes.h" #include "utils/rangetypes.h" #include "utils/snapmgr.h" +#include "utils/datum.h" +#include "utils/lsyscache.h" /* waitMode argument to check_exclusion_or_unique_constraint() */ typedef enum @@ -157,7 +160,7 @@ static void ExecWithoutOverlapsNotEmpty(Relation rel, NameData attname, Datum at * ---------------------------------------------------------------- */ void -ExecOpenIndices(ResultRelInfo *resultRelInfo, bool speculative) +ExecOpenIndices(ResultRelInfo *resultRelInfo, bool speculative, bool update) { Relation resultRelation = resultRelInfo->ri_RelationDesc; List *indexoidlist; @@ -220,6 +223,13 @@ ExecOpenIndices(ResultRelInfo *resultRelInfo, bool speculative) if (speculative && ii->ii_Unique && !indexDesc->rd_index->indisexclusion) BuildSpeculativeIndexInfo(indexDesc, ii); + /* + * If the index uses expressions then let's populate the additional + * information nessaary to evaluate them for changes during updates. + */ + if (update && (ii->ii_Expressions || ii->ii_Predicate)) + BuildExpressionIndexInfo(indexDesc, ii); + relationDescs[i] = indexDesc; indexInfoArray[i] = ii; i++; @@ -382,19 +392,33 @@ ExecInsertIndexTuples(ResultRelInfo *resultRelInfo, ExprState *predicate; /* - * If predicate state not set up yet, create it (in the estate's - * per-query context) + * It is possible that we've already checked the predicate, if so + * then avoid the duplicate work. */ - predicate = indexInfo->ii_PredicateState; - if (predicate == NULL) + if (indexInfo->ii_CheckedPredicate) { - predicate = ExecPrepareQual(indexInfo->ii_Predicate, estate); - indexInfo->ii_PredicateState = predicate; + /* Skip this index-update if the predicate isn't satisfied */ + if (!indexInfo->ii_PredicateSatisfied) + continue; } + else + { - /* Skip this index-update if the predicate isn't satisfied */ - if (!ExecQual(predicate, econtext)) - continue; + /* + * If predicate state not set up yet, create it (in the + * estate's per-query context) + */ + predicate = indexInfo->ii_PredicateState; + if (predicate == NULL) + { + predicate = ExecPrepareQual(indexInfo->ii_Predicate, estate); + indexInfo->ii_PredicateState = predicate; + } + + /* Skip this index-update if the predicate isn't satisfied */ + if (!ExecQual(predicate, econtext)) + continue; + } } /* @@ -1095,6 +1119,9 @@ index_unchanged_by_update(ResultRelInfo *resultRelInfo, EState *estate, if (hasexpression) { + if (indexInfo->ii_IndexUnchanged) + return true; + indexInfo->ii_IndexUnchanged = false; return false; } @@ -1172,3 +1199,168 @@ ExecWithoutOverlapsNotEmpty(Relation rel, NameData attname, Datum attval, char t errmsg("empty WITHOUT OVERLAPS value found in column \"%s\" in relation \"%s\"", NameStr(attname), RelationGetRelationName(rel)))); } + +/* + * + * This will first determine if the index has a predicate and if so if the + * update satisfies that or not. Then, if necessary, we compare old and + * new values of the indexed expression and help determine if it is possible + * to use a HOT update or not. + * + * 'resultRelInfo' is the table with the indexes we should examine. + * 'modified' is the set of attributes that are modified by the update. + * 'estate' is the executor state for the update. + * 'old_tts' is a slot with the old tuple. + * 'new_tts' is a slot with the new tuple. + * + * Returns true iff none of the indexes on this relation require updating. + * + * When the changes in new tuple impact a value stored in an index we must + * return true. When an index has a predicate that is not satisfied by either + * the new or old tuples then that index is unchanged. When an index has a + * predicate that is satisfied by both the old and new tuples then we can + * proceed and check to see if the indexed values were changed or not. + */ +bool +ExecExprIndexesRequireUpdates(Relation relation, + ResultRelInfo *resultRelInfo, + Bitmapset *modifiedAttrs, + EState *estate, + TupleTableSlot *old_tts, + TupleTableSlot *new_tts) +{ + bool expression_checks = RelationGetExpressionChecks(relation); + bool result = false; + IndexInfo *indexInfo; + TupleTableSlot *save_scantuple; + ExprContext *econtext = NULL; + + if (resultRelInfo == NULL || estate == NULL || + old_tts == NULL || new_tts == NULL || + !expression_checks || IsolationIsSerializable()) + return true; + + econtext = GetPerTupleExprContext(estate); + + /* + * Examine each index on this relation to see if it is affected by the + * changes in newtup. If any index is changed, we must not use a HOT + * update. + */ + for (int i = 0; i < resultRelInfo->ri_NumIndices; i++) + { + indexInfo = resultRelInfo->ri_IndexRelationInfo[i]; + + /* + * If this is a partial index it has a predicate, evaluate the + * expression to determine if we need to include it or not. + */ + if (bms_overlap(indexInfo->ii_PredicateAttrs, modifiedAttrs)) + { + ExprState *pstate; + bool old_tuple_qualifies, + new_tuple_qualifies; + + pstate = ExecPrepareQual(indexInfo->ii_Predicate, estate); + + /* + * Here the term "qualifies" means "satisfies the predicate + * condition of the partial index". + */ + save_scantuple = econtext->ecxt_scantuple; + econtext->ecxt_scantuple = old_tts; + old_tuple_qualifies = ExecQual(pstate, econtext); + + econtext->ecxt_scantuple = new_tts; + new_tuple_qualifies = ExecQual(pstate, econtext); + econtext->ecxt_scantuple = save_scantuple; + + indexInfo->ii_CheckedPredicate = true; + indexInfo->ii_PredicateSatisfied = new_tuple_qualifies; + + /* + * If neither the old nor the new tuples satisfy the predicate we + * can be sure that this index doesn't need updating, continue to + * the next index. + */ + if ((new_tuple_qualifies == false) && (old_tuple_qualifies == false)) + continue; + + /* + * If there is a transition between indexed and not indexed, + * that's enough to require an index update. + */ + if (new_tuple_qualifies != old_tuple_qualifies) + { + result = true; + break; + } + + /* + * Otherwise the old and new values exist in the index, but did + * they get updated? We don't yet know, so proceed with the next + * statement in the loop to find out. + */ + } + + /* + * Indexes with expressions may or may not have changed, it is + * impossible to know without exercising their expression and + * reviewing index tuple state for changes. This is a lot of work, + * but because all indexes on JSONB columns fall into this category it + * can be worth it to avoid index updates and remain on the HOT update + * path when possible. + */ + if (bms_overlap(indexInfo->ii_ExpressionsAttrs, modifiedAttrs)) + { + Datum old_values[INDEX_MAX_KEYS]; + bool old_isnull[INDEX_MAX_KEYS]; + Datum new_values[INDEX_MAX_KEYS]; + bool new_isnull[INDEX_MAX_KEYS]; + + save_scantuple = econtext->ecxt_scantuple; + econtext->ecxt_scantuple = old_tts; + FormIndexDatum(indexInfo, + old_tts, + estate, + old_values, + old_isnull); + econtext->ecxt_scantuple = new_tts; + FormIndexDatum(indexInfo, + new_tts, + estate, + new_values, + new_isnull); + econtext->ecxt_scantuple = save_scantuple; + + for (int j = 0; j < indexInfo->ii_NumIndexKeyAttrs; j++) + { + if (old_isnull[j] != new_isnull[j]) + { + result = true; + break; + } + else if (!old_isnull[j]) + { + int16 elmlen = indexInfo->ii_IndexAttrLen[j]; + bool elmbyval = bms_is_member(j, indexInfo->ii_IndexAttrByVal); + + if (!datum_image_eq(old_values[j], new_values[j], + elmbyval, elmlen)) + { + result = true; + break; + } + } + } + + indexInfo->ii_CheckedUnchanged = true; + indexInfo->ii_IndexUnchanged = !result; + + if (result) + break; + } + } + + return result; +} diff --git a/src/backend/executor/execPartition.c b/src/backend/executor/execPartition.c index 1f2da072632e..2f48919a6206 100644 --- a/src/backend/executor/execPartition.c +++ b/src/backend/executor/execPartition.c @@ -544,7 +544,7 @@ ExecInitPartitionInfo(ModifyTableState *mtstate, EState *estate, leaf_part_rri->ri_IndexRelationDescs == NULL) ExecOpenIndices(leaf_part_rri, (node != NULL && - node->onConflictAction != ONCONFLICT_NONE)); + node->onConflictAction != ONCONFLICT_NONE), false); /* * Build WITH CHECK OPTION constraints for the partition. Note that we diff --git a/src/backend/executor/execReplication.c b/src/backend/executor/execReplication.c index def32774c90d..be26a2c76761 100644 --- a/src/backend/executor/execReplication.c +++ b/src/backend/executor/execReplication.c @@ -920,7 +920,7 @@ ExecSimpleRelationUpdate(ResultRelInfo *resultRelInfo, if (!skip_tuple) { List *recheckIndexes = NIL; - TU_UpdateIndexes update_indexes; + UpdateContext updateCxt = {0}; List *conflictindexes; bool conflict = false; @@ -936,17 +936,19 @@ ExecSimpleRelationUpdate(ResultRelInfo *resultRelInfo, if (rel->rd_rel->relispartition) ExecPartitionCheck(resultRelInfo, slot, estate, true); + updateCxt.estate = estate; + updateCxt.rri = resultRelInfo; simple_table_tuple_update(rel, tid, slot, estate->es_snapshot, - &update_indexes); + &updateCxt); conflictindexes = resultRelInfo->ri_onConflictArbiterIndexes; - if (resultRelInfo->ri_NumIndices > 0 && (update_indexes != TU_None)) + if (resultRelInfo->ri_NumIndices > 0 && (updateCxt.updateIndexes != TU_None)) recheckIndexes = ExecInsertIndexTuples(resultRelInfo, slot, estate, true, conflictindexes ? true : false, &conflict, conflictindexes, - (update_indexes == TU_Summarizing)); + (updateCxt.updateIndexes == TU_Summarizing)); /* * Refer to the comments above the call to CheckAndReportConflict() in diff --git a/src/backend/executor/nodeModifyTable.c b/src/backend/executor/nodeModifyTable.c index 4c5647ac38a1..db3d8789846e 100644 --- a/src/backend/executor/nodeModifyTable.c +++ b/src/backend/executor/nodeModifyTable.c @@ -116,21 +116,6 @@ typedef struct ModifyTableContext TupleTableSlot *cpUpdateReturningSlot; } ModifyTableContext; -/* - * Context struct containing output data specific to UPDATE operations. - */ -typedef struct UpdateContext -{ - bool crossPartUpdate; /* was it a cross-partition update? */ - TU_UpdateIndexes updateIndexes; /* Which index updates are required? */ - - /* - * Lock mode to acquire on the latest tuple version before performing - * EvalPlanQual on it - */ - LockTupleMode lockmode; -} UpdateContext; - static void ExecBatchInsert(ModifyTableState *mtstate, ResultRelInfo *resultRelInfo, @@ -890,7 +875,7 @@ ExecInsert(ModifyTableContext *context, */ if (resultRelationDesc->rd_rel->relhasindex && resultRelInfo->ri_IndexRelationDescs == NULL) - ExecOpenIndices(resultRelInfo, onconflict != ONCONFLICT_NONE); + ExecOpenIndices(resultRelInfo, onconflict != ONCONFLICT_NONE, false); /* * BEFORE ROW INSERT Triggers. @@ -2106,7 +2091,7 @@ ExecUpdatePrologue(ModifyTableContext *context, ResultRelInfo *resultRelInfo, */ if (resultRelationDesc->rd_rel->relhasindex && resultRelInfo->ri_IndexRelationDescs == NULL) - ExecOpenIndices(resultRelInfo, false); + ExecOpenIndices(resultRelInfo, false, true); /* BEFORE ROW UPDATE triggers */ if (resultRelInfo->ri_TrigDesc && @@ -2305,8 +2290,7 @@ ExecUpdateAct(ModifyTableContext *context, ResultRelInfo *resultRelInfo, estate->es_snapshot, estate->es_crosscheck_snapshot, true /* wait for commit */ , - &context->tmfd, &updateCxt->lockmode, - &updateCxt->updateIndexes); + &context->tmfd, updateCxt); return result; } @@ -2324,6 +2308,7 @@ ExecUpdateEpilogue(ModifyTableContext *context, UpdateContext *updateCxt, { ModifyTableState *mtstate = context->mtstate; List *recheckIndexes = NIL; + bool onlySummarizing = updateCxt->updateIndexes == TU_Summarizing; /* insert index entries for tuple if necessary */ if (resultRelInfo->ri_NumIndices > 0 && (updateCxt->updateIndexes != TU_None)) @@ -2331,7 +2316,7 @@ ExecUpdateEpilogue(ModifyTableContext *context, UpdateContext *updateCxt, slot, context->estate, true, false, NULL, NIL, - (updateCxt->updateIndexes == TU_Summarizing)); + onlySummarizing); /* AFTER ROW UPDATE Triggers */ ExecARUpdateTriggers(context->estate, resultRelInfo, @@ -2467,6 +2452,9 @@ ExecUpdate(ModifyTableContext *context, ResultRelInfo *resultRelInfo, UpdateContext updateCxt = {0}; TM_Result result; + updateCxt.estate = estate; + updateCxt.rri = resultRelInfo; + /* * abort the operation if not running transactions */ @@ -3155,6 +3143,9 @@ ExecMergeMatched(ModifyTableContext *context, ResultRelInfo *resultRelInfo, TM_Result result; UpdateContext updateCxt = {0}; + updateCxt.rri = resultRelInfo; + updateCxt.estate = estate; + /* * Test condition, if any. * diff --git a/src/backend/replication/logical/worker.c b/src/backend/replication/logical/worker.c index 7edd1c9cf060..71be29da71b6 100644 --- a/src/backend/replication/logical/worker.c +++ b/src/backend/replication/logical/worker.c @@ -2674,7 +2674,7 @@ apply_handle_insert(StringInfo s) { ResultRelInfo *relinfo = edata->targetRelInfo; - ExecOpenIndices(relinfo, false); + ExecOpenIndices(relinfo, false, false); apply_handle_insert_internal(edata, relinfo, remoteslot); ExecCloseIndices(relinfo); } @@ -2897,7 +2897,7 @@ apply_handle_update_internal(ApplyExecutionData *edata, MemoryContext oldctx; EvalPlanQualInit(&epqstate, estate, NULL, NIL, -1, NIL); - ExecOpenIndices(relinfo, false); + ExecOpenIndices(relinfo, false, true); found = FindReplTupleInLocalRel(edata, localrel, &relmapentry->remoterel, @@ -3055,7 +3055,7 @@ apply_handle_delete(StringInfo s) { ResultRelInfo *relinfo = edata->targetRelInfo; - ExecOpenIndices(relinfo, false); + ExecOpenIndices(relinfo, false, false); apply_handle_delete_internal(edata, relinfo, remoteslot, rel->localindexoid); ExecCloseIndices(relinfo); diff --git a/src/backend/utils/cache/relcache.c b/src/backend/utils/cache/relcache.c index 915d0bc90842..a442ff215a72 100644 --- a/src/backend/utils/cache/relcache.c +++ b/src/backend/utils/cache/relcache.c @@ -64,6 +64,7 @@ #include "catalog/pg_type.h" #include "catalog/schemapg.h" #include "catalog/storage.h" +#include "catalog/index.h" #include "commands/policy.h" #include "commands/publicationcmds.h" #include "commands/trigger.h" @@ -2482,6 +2483,7 @@ RelationDestroyRelation(Relation relation, bool remember_tupdesc) bms_free(relation->rd_idattr); bms_free(relation->rd_hotblockingattr); bms_free(relation->rd_summarizedattr); + bms_free(relation->rd_expressionattr); if (relation->rd_pubdesc) pfree(relation->rd_pubdesc); if (relation->rd_options) @@ -5283,6 +5285,7 @@ RelationGetIndexPredicate(Relation relation) * index (empty if FULL) * INDEX_ATTR_BITMAP_HOT_BLOCKING Columns that block updates from being HOT * INDEX_ATTR_BITMAP_SUMMARIZED Columns included in summarizing indexes + * INDEX_ATTR_BITMAP_EXPRESSION Columns included in expresion indexes * * Attribute numbers are offset by FirstLowInvalidHeapAttributeNumber so that * we can include system attributes (e.g., OID) in the bitmap representation. @@ -5305,8 +5308,9 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) Bitmapset *uindexattrs; /* columns in unique indexes */ Bitmapset *pkindexattrs; /* columns in the primary index */ Bitmapset *idindexattrs; /* columns in the replica identity */ - Bitmapset *hotblockingattrs; /* columns with HOT blocking indexes */ - Bitmapset *summarizedattrs; /* columns with summarizing indexes */ + Bitmapset *idx_attrs; /* columns referenced by indexes */ + Bitmapset *expr_attrs; /* columns referenced by index expressions */ + Bitmapset *sum_attrs; /* columns with summarizing indexes */ List *indexoidlist; List *newindexoidlist; Oid relpkindex; @@ -5329,6 +5333,8 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) return bms_copy(relation->rd_hotblockingattr); case INDEX_ATTR_BITMAP_SUMMARIZED: return bms_copy(relation->rd_summarizedattr); + case INDEX_ATTR_BITMAP_EXPRESSION: + return bms_copy(relation->rd_expressionattr); default: elog(ERROR, "unknown attrKind %u", attrKind); } @@ -5371,8 +5377,9 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) uindexattrs = NULL; pkindexattrs = NULL; idindexattrs = NULL; - hotblockingattrs = NULL; - summarizedattrs = NULL; + idx_attrs = NULL; + expr_attrs = NULL; + sum_attrs = NULL; foreach(l, indexoidlist) { Oid indexOid = lfirst_oid(l); @@ -5386,6 +5393,7 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) bool isPK; /* primary key */ bool isIDKey; /* replica identity index */ Bitmapset **attrs; + Bitmapset **exprattrs; indexDesc = index_open(indexOid, AccessShareLock); @@ -5429,20 +5437,26 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) * decide which bitmap we'll update in the following loop. */ if (indexDesc->rd_indam->amsummarizing) - attrs = &summarizedattrs; + { + attrs = &sum_attrs; + exprattrs = &sum_attrs; + } else - attrs = &hotblockingattrs; + { + attrs = &idx_attrs; + exprattrs = &expr_attrs; + } /* Collect simple attribute references */ for (i = 0; i < indexDesc->rd_index->indnatts; i++) { - int attrnum = indexDesc->rd_index->indkey.values[i]; + int attridx = indexDesc->rd_index->indkey.values[i]; /* * Since we have covering indexes with non-key columns, we must * handle them accurately here. non-key columns must be added into - * hotblockingattrs or summarizedattrs, since they are in index, - * and update shouldn't miss them. + * idx_attrs or sum_attrs, since they are in index, and update + * shouldn't miss them. * * Summarizing indexes do not block HOT, but do need to be updated * when the column value changes, thus require a separate @@ -5452,30 +5466,28 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) * key or identity key. Hence we do not include them into * uindexattrs, pkindexattrs and idindexattrs bitmaps. */ - if (attrnum != 0) + if (attridx != 0) { - *attrs = bms_add_member(*attrs, - attrnum - FirstLowInvalidHeapAttributeNumber); + AttrNumber attrnum = attridx - FirstLowInvalidHeapAttributeNumber; + + *attrs = bms_add_member(*attrs, attrnum); if (isKey && i < indexDesc->rd_index->indnkeyatts) - uindexattrs = bms_add_member(uindexattrs, - attrnum - FirstLowInvalidHeapAttributeNumber); + uindexattrs = bms_add_member(uindexattrs, attrnum); if (isPK && i < indexDesc->rd_index->indnkeyatts) - pkindexattrs = bms_add_member(pkindexattrs, - attrnum - FirstLowInvalidHeapAttributeNumber); + pkindexattrs = bms_add_member(pkindexattrs, attrnum); if (isIDKey && i < indexDesc->rd_index->indnkeyatts) - idindexattrs = bms_add_member(idindexattrs, - attrnum - FirstLowInvalidHeapAttributeNumber); + idindexattrs = bms_add_member(idindexattrs, attrnum); } } /* Collect all attributes used in expressions, too */ - pull_varattnos(indexExpressions, 1, attrs); + pull_varattnos(indexExpressions, 1, exprattrs); /* Collect all attributes in the index predicate, too */ - pull_varattnos(indexPredicate, 1, attrs); + pull_varattnos(indexPredicate, 1, exprattrs); index_close(indexDesc, AccessShareLock); } @@ -5503,12 +5515,24 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) bms_free(uindexattrs); bms_free(pkindexattrs); bms_free(idindexattrs); - bms_free(hotblockingattrs); - bms_free(summarizedattrs); + bms_free(idx_attrs); + bms_free(expr_attrs); + bms_free(sum_attrs); goto restart; } + /* + * HOT-blocking attributes should include all columns that are part of the + * index except attributes only referenced in expressions, including + * expressions used to form partial indexes. So, we need to remove the + * expression-only attributes from the HOT-blocking columns bitmap as + * those will be checked separately. + */ + expr_attrs = bms_del_members(expr_attrs, idx_attrs); + idx_attrs = bms_add_members(idx_attrs, expr_attrs); + expr_attrs = bms_add_members(expr_attrs, sum_attrs); + /* Don't leak the old values of these bitmaps, if any */ relation->rd_attrsvalid = false; bms_free(relation->rd_keyattr); @@ -5521,6 +5545,8 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) relation->rd_hotblockingattr = NULL; bms_free(relation->rd_summarizedattr); relation->rd_summarizedattr = NULL; + bms_free(relation->rd_expressionattr); + relation->rd_expressionattr = NULL; /* * Now save copies of the bitmaps in the relcache entry. We intentionally @@ -5533,8 +5559,9 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) relation->rd_keyattr = bms_copy(uindexattrs); relation->rd_pkattr = bms_copy(pkindexattrs); relation->rd_idattr = bms_copy(idindexattrs); - relation->rd_hotblockingattr = bms_copy(hotblockingattrs); - relation->rd_summarizedattr = bms_copy(summarizedattrs); + relation->rd_hotblockingattr = bms_copy(idx_attrs); + relation->rd_summarizedattr = bms_copy(sum_attrs); + relation->rd_expressionattr = bms_copy(expr_attrs); relation->rd_attrsvalid = true; MemoryContextSwitchTo(oldcxt); @@ -5548,9 +5575,11 @@ RelationGetIndexAttrBitmap(Relation relation, IndexAttrBitmapKind attrKind) case INDEX_ATTR_BITMAP_IDENTITY_KEY: return idindexattrs; case INDEX_ATTR_BITMAP_HOT_BLOCKING: - return hotblockingattrs; + return idx_attrs; case INDEX_ATTR_BITMAP_SUMMARIZED: - return summarizedattrs; + return sum_attrs; + case INDEX_ATTR_BITMAP_EXPRESSION: + return expr_attrs; default: elog(ERROR, "unknown attrKind %u", attrKind); return NULL; diff --git a/src/bin/psql/tab-complete.in.c b/src/bin/psql/tab-complete.in.c index 36ea6a4d5570..11de9cd434e5 100644 --- a/src/bin/psql/tab-complete.in.c +++ b/src/bin/psql/tab-complete.in.c @@ -3046,7 +3046,7 @@ match_previous_words(int pattern_id, COMPLETE_WITH("("); /* ALTER TABLESPACE SET|RESET ( */ else if (Matches("ALTER", "TABLESPACE", MatchAny, "SET|RESET", "(")) - COMPLETE_WITH("seq_page_cost", "random_page_cost", + COMPLETE_WITH("seq_page_cost", "random_page_cost", "expression_checks", "effective_io_concurrency", "maintenance_io_concurrency"); /* ALTER TEXT SEARCH */ diff --git a/src/include/access/heapam.h b/src/include/access/heapam.h index 8cbff6ab0eb1..3ca8ace66641 100644 --- a/src/include/access/heapam.h +++ b/src/include/access/heapam.h @@ -22,6 +22,7 @@ #include "access/table.h" /* for backward compatibility */ #include "access/tableam.h" #include "commands/vacuum.h" +#include "executor/executor.h" #include "nodes/lockoptions.h" #include "nodes/primnodes.h" #include "storage/bufpage.h" @@ -324,8 +325,7 @@ extern void heap_abort_speculative(Relation relation, ItemPointer tid); extern TM_Result heap_update(Relation relation, ItemPointer otid, HeapTuple newtup, CommandId cid, Snapshot crosscheck, bool wait, - TM_FailureData *tmfd, LockTupleMode *lockmode, - TU_UpdateIndexes *update_indexes); + TM_FailureData *tmfd, UpdateContext *updateCxt); extern TM_Result heap_lock_tuple(Relation relation, HeapTuple tuple, CommandId cid, LockTupleMode mode, LockWaitPolicy wait_policy, bool follow_updates, @@ -360,7 +360,7 @@ extern bool heap_tuple_needs_eventual_freeze(HeapTupleHeader tuple); extern void simple_heap_insert(Relation relation, HeapTuple tup); extern void simple_heap_delete(Relation relation, ItemPointer tid); extern void simple_heap_update(Relation relation, ItemPointer otid, - HeapTuple tup, TU_UpdateIndexes *update_indexes); + HeapTuple tup, UpdateContext *updateCxt); extern TransactionId heap_index_delete_tuples(Relation rel, TM_IndexDeleteOp *delstate); diff --git a/src/include/access/tableam.h b/src/include/access/tableam.h index e16bf0256928..5a9685eb83ad 100644 --- a/src/include/access/tableam.h +++ b/src/include/access/tableam.h @@ -119,6 +119,31 @@ typedef enum TU_UpdateIndexes TU_Summarizing, } TU_UpdateIndexes; +typedef struct ResultRelInfo ResultRelInfo; +typedef struct EState EState; + +/* + * Data specific to processing UPDATE operations. + * + * When table_tuple_update is called some storage managers, notably heapam, + * can at times avoid index updates. In the heapam this is known as a HOT + * update. This struct is used to provide the state required to test for + * HOT updates and to communicate that decision on to the index AMs. + */ +typedef struct UpdateContext +{ + TU_UpdateIndexes updateIndexes; /* Which index updates are required? */ + ResultRelInfo *rri; /* ResultRelInfo for the updated table. */ + EState *estate; /* EState used within the update. */ + bool crossPartUpdate; /* Was it a cross-partition update? */ + + /* + * Lock mode to acquire on the latest tuple version before performing + * EvalPlanQual on it + */ + LockTupleMode lockmode; +} UpdateContext; + /* * When table_tuple_update, table_tuple_delete, or table_tuple_lock fail * because the target tuple is already outdated, they fill in this struct to @@ -548,8 +573,7 @@ typedef struct TableAmRoutine Snapshot crosscheck, bool wait, TM_FailureData *tmfd, - LockTupleMode *lockmode, - TU_UpdateIndexes *update_indexes); + UpdateContext *updateCxt); /* see table_tuple_lock() for reference about parameters */ TM_Result (*tuple_lock) (Relation rel, @@ -1501,13 +1525,11 @@ table_tuple_delete(Relation rel, ItemPointer tid, CommandId cid, static inline TM_Result table_tuple_update(Relation rel, ItemPointer otid, TupleTableSlot *slot, CommandId cid, Snapshot snapshot, Snapshot crosscheck, - bool wait, TM_FailureData *tmfd, LockTupleMode *lockmode, - TU_UpdateIndexes *update_indexes) + bool wait, TM_FailureData *tmfd, UpdateContext *updateCxt) { return rel->rd_tableam->tuple_update(rel, otid, slot, cid, snapshot, crosscheck, - wait, tmfd, - lockmode, update_indexes); + wait, tmfd, updateCxt); } /* @@ -2010,7 +2032,7 @@ extern void simple_table_tuple_delete(Relation rel, ItemPointer tid, Snapshot snapshot); extern void simple_table_tuple_update(Relation rel, ItemPointer otid, TupleTableSlot *slot, Snapshot snapshot, - TU_UpdateIndexes *update_indexes); + UpdateContext *updateCxt); /* ---------------------------------------------------------------------------- diff --git a/src/include/catalog/index.h b/src/include/catalog/index.h index 4daa8bef5eea..fdbf47f607be 100644 --- a/src/include/catalog/index.h +++ b/src/include/catalog/index.h @@ -132,6 +132,7 @@ extern bool CompareIndexInfo(const IndexInfo *info1, const IndexInfo *info2, const AttrMap *attmap); extern void BuildSpeculativeIndexInfo(Relation index, IndexInfo *ii); +extern void BuildExpressionIndexInfo(Relation index, IndexInfo *indexInfo); extern void FormIndexDatum(IndexInfo *indexInfo, TupleTableSlot *slot, diff --git a/src/include/executor/executor.h b/src/include/executor/executor.h index 0ba86c2ad723..e0495c3c529f 100644 --- a/src/include/executor/executor.h +++ b/src/include/executor/executor.h @@ -734,7 +734,7 @@ extern Bitmapset *ExecGetAllUpdatedCols(ResultRelInfo *relinfo, EState *estate); /* * prototypes from functions in execIndexing.c */ -extern void ExecOpenIndices(ResultRelInfo *resultRelInfo, bool speculative); +extern void ExecOpenIndices(ResultRelInfo *resultRelInfo, bool speculative, bool update); extern void ExecCloseIndices(ResultRelInfo *resultRelInfo); extern List *ExecInsertIndexTuples(ResultRelInfo *resultRelInfo, TupleTableSlot *slot, EState *estate, @@ -752,6 +752,12 @@ extern void check_exclusion_constraint(Relation heap, Relation index, ItemPointer tupleid, const Datum *values, const bool *isnull, EState *estate, bool newIndex); +extern bool ExecExprIndexesRequireUpdates(Relation relation, + ResultRelInfo *resultRelInfo, + Bitmapset *modifiedAttrs, + EState *estate, + TupleTableSlot *old_tts, + TupleTableSlot *new_tts); /* * prototypes from functions in execReplication.c diff --git a/src/include/nodes/execnodes.h b/src/include/nodes/execnodes.h index a36653c37f9e..e529587a6f11 100644 --- a/src/include/nodes/execnodes.h +++ b/src/include/nodes/execnodes.h @@ -178,11 +178,20 @@ typedef struct IndexInfo List *ii_Expressions; /* list of Expr */ /* exec state for expressions, or NIL if none */ List *ii_ExpressionsState; /* list of ExprState */ + /* attributes referenced by expressions, or NULL if none */ + Bitmapset *ii_ExpressionsAttrs; + + /* index attribute length */ + uint16 ii_IndexAttrLen[INDEX_MAX_KEYS]; + /* is the index attribute by-value */ + Bitmapset *ii_IndexAttrByVal; /* partial-index predicate, or NIL if none */ List *ii_Predicate; /* list of Expr */ /* exec state for expressions, or NIL if none */ ExprState *ii_PredicateState; + /* attributes referenced by the predicate, or NULL if none */ + Bitmapset *ii_PredicateAttrs; /* Per-column exclusion operators, or NULL if none */ Oid *ii_ExclusionOps; /* array with one entry per column */ @@ -206,6 +215,10 @@ typedef struct IndexInfo bool ii_CheckedUnchanged; /* aminsert hint, cached for retail inserts */ bool ii_IndexUnchanged; + /* partial index predicate determined yet? */ + bool ii_CheckedPredicate; + /* amupdate hint used to avoid rechecking predicate */ + bool ii_PredicateSatisfied; /* are we doing a concurrent index build? */ bool ii_Concurrent; /* did we detect any broken HOT chains? */ @@ -386,6 +399,8 @@ typedef struct ProjectionInfo ExprState pi_state; /* expression context in which to evaluate expression */ ExprContext *pi_exprContext; + /* the set of modified columns (attributes) */ + Bitmapset *pi_modifiedCols; } ProjectionInfo; /* ---------------- diff --git a/src/include/utils/rel.h b/src/include/utils/rel.h index 80286076a111..219e7197bb2a 100644 --- a/src/include/utils/rel.h +++ b/src/include/utils/rel.h @@ -164,6 +164,7 @@ typedef struct RelationData Bitmapset *rd_idattr; /* included in replica identity index */ Bitmapset *rd_hotblockingattr; /* cols blocking HOT update */ Bitmapset *rd_summarizedattr; /* cols indexed by summarizing indexes */ + Bitmapset *rd_expressionattr; /* indexed cols referenced by expressions */ PublicationDesc *rd_pubdesc; /* publication descriptor, or NULL */ @@ -349,6 +350,7 @@ typedef struct StdRdOptions StdRdOptIndexCleanup vacuum_index_cleanup; /* controls index vacuuming */ bool vacuum_truncate; /* enables vacuum to truncate a relation */ bool vacuum_truncate_set; /* whether vacuum_truncate is set */ + bool expression_checks; /* use expression to checks for changes */ /* * Fraction of pages in a relation that vacuum can eagerly scan and fail @@ -410,6 +412,14 @@ typedef struct StdRdOptions ((relation)->rd_options ? \ ((StdRdOptions *) (relation)->rd_options)->parallel_workers : (defaultpw)) +/* + * RelationGetExpressionChecks + * Returns the relation's expression_checks reloption setting. + */ +#define RelationGetExpressionChecks(relation) \ + ((relation)->rd_options ? \ + ((StdRdOptions *) (relation)->rd_options)->expression_checks : true) + /* ViewOptions->check_option values */ typedef enum ViewOptCheckOption { diff --git a/src/include/utils/relcache.h b/src/include/utils/relcache.h index 3561c6bef0bf..4b312bc8d06c 100644 --- a/src/include/utils/relcache.h +++ b/src/include/utils/relcache.h @@ -71,6 +71,7 @@ typedef enum IndexAttrBitmapKind INDEX_ATTR_BITMAP_IDENTITY_KEY, INDEX_ATTR_BITMAP_HOT_BLOCKING, INDEX_ATTR_BITMAP_SUMMARIZED, + INDEX_ATTR_BITMAP_EXPRESSION, } IndexAttrBitmapKind; extern Bitmapset *RelationGetIndexAttrBitmap(Relation relation, diff --git a/src/test/regress/expected/heap_hot_updates.out b/src/test/regress/expected/heap_hot_updates.out new file mode 100644 index 000000000000..7d22befc34a6 --- /dev/null +++ b/src/test/regress/expected/heap_hot_updates.out @@ -0,0 +1,1048 @@ +-- Create a function to measure HOT updates +CREATE OR REPLACE FUNCTION check_hot_updates( + expected INT, + p_table_name TEXT DEFAULT 't', + p_schema_name TEXT DEFAULT current_schema() +) +RETURNS TABLE ( + table_name TEXT, + total_updates BIGINT, + hot_updates BIGINT, + hot_update_percentage NUMERIC, + matches_expected BOOLEAN, + has_indexes BOOLEAN, + index_count INT, + fillfactor INT +) +LANGUAGE plpgsql +AS $$ +DECLARE + v_relid oid; + v_qualified_name TEXT; + v_hot_updates BIGINT; + v_updates BIGINT; + v_xact_hot_updates BIGINT; + v_xact_updates BIGINT; +BEGIN + + -- We need to wait for statistics to update + PERFORM pg_stat_force_next_flush(); + + -- Construct qualified name + v_qualified_name := quote_ident(p_schema_name) || '.' || quote_ident(p_table_name); + + -- Get the OID using regclass + v_relid := v_qualified_name::regclass; + + IF v_relid IS NULL THEN + RAISE EXCEPTION 'Table %.% not found', p_schema_name, p_table_name; + END IF; + + -- Get cumulative stats + v_hot_updates := COALESCE(pg_stat_get_tuples_hot_updated(v_relid), 0); + v_updates := COALESCE(pg_stat_get_tuples_updated(v_relid), 0); + + -- Get current transaction stats + v_xact_hot_updates := COALESCE(pg_stat_get_xact_tuples_hot_updated(v_relid), 0); + v_xact_updates := COALESCE(pg_stat_get_xact_tuples_updated(v_relid), 0); + + -- Combine stats + v_hot_updates := v_hot_updates + v_xact_hot_updates; + v_updates := v_updates + v_xact_updates; + + RETURN QUERY + SELECT + p_table_name::TEXT, + v_updates::BIGINT as total_updates, + v_hot_updates::BIGINT as hot_updates, + CASE + WHEN v_updates > 0 THEN + ROUND((v_hot_updates::numeric / v_updates::numeric * 100)::numeric, 2) + ELSE 0 + END as hot_update_percentage, + (v_hot_updates = expected)::BOOLEAN as matches_expected, + (EXISTS ( + SELECT 1 FROM pg_index WHERE indrelid = v_relid + ))::BOOLEAN as has_indexes, + ( + SELECT COUNT(*)::INT + FROM pg_index + WHERE indrelid = v_relid + ) as index_count, + COALESCE( + ( + SELECT (regexp_match(array_to_string(reloptions, ','), 'fillfactor=(\d+)'))[1]::int + FROM pg_class + WHERE oid = v_relid + ), + 100 + ) as fillfactor; +END; +$$; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table will have two columns and two indexes, one on the primary key +-- id and one on the expression (docs->>'name'). That means that the indexed +-- attributes are 'id' and 'docs'. +CREATE TABLE t(id INT PRIMARY KEY, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->>'name')); +INSERT INTO t VALUES (1, '{"name": "john", "data": "some data"}'); +-- Disable expression checks. +ALTER TABLE t SET (expression_checks = false); +SELECT reloptions FROM pg_class WHERE relname = 't'; + reloptions +---------------------------------------------------------------- + {autovacuum_enabled=off,fillfactor=70,expression_checks=false} +(1 row) + +-- While the indexed attribute "name" is unchanged we've disabled expression +-- checks so this update should not go HOT as the system can't determine if +-- the indexed attribute has changed without evaluating the expression. +update t set docs='{"name": "john", "data": "something else"}' where id=1; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 2 | 70 +(1 row) + +-- Re-enable expression checks. +ALTER TABLE t SET (expression_checks = true); +SELECT reloptions FROM pg_class WHERE relname = 't'; + reloptions +--------------------------------------------------------------- + {autovacuum_enabled=off,fillfactor=70,expression_checks=true} +(1 row) + +-- The indexed attribute "name" with value "john" is unchanged, expect a HOT update. +UPDATE t SET docs='{"name": "john", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 2 | 1 | 50.00 | t | t | 2 | 70 +(1 row) + +-- The following update changes the indexed attribute "name", this should not be a HOT update. +UPDATE t SET docs='{"name": "smith", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 3 | 1 | 33.33 | t | t | 2 | 70 +(1 row) + +-- Now, this update does not change the indexed attribute "name" from "smith", this should be HOT. +UPDATE t SET docs='{"name": "smith", "data": "some more data"}' WHERE id=1; +SELECT * FROM check_hot_updates(2); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 4 | 2 | 50.00 | t | t | 2 | 70 +(1 row) + +DROP TABLE t; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table is the same as the previous one but it has a third index. The +-- index 'colindex' isn't an expression index, it indexes the entire value +-- in the docs column. There are still only two indexed attributes for this +-- relation, the same two as before. The presence of an index on the entire +-- value of the docs column should prevent HOT updates for any updates to any +-- portion of JSONB content in that column. +CREATE TABLE t(id INT PRIMARY KEY, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->>'name')); +CREATE INDEX t_docs_col_idx ON t(docs); +INSERT INTO t VALUES (1, '{"name": "john", "data": "some data"}'); +-- This update doesn't change the value of the expression index, but it does +-- change the content of the docs column and so should not be HOT because the +-- indexed value changed as a result of the update. +UPDATE t SET docs='{"name": "john", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 3 | 70 +(1 row) + +DROP TABLE t; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- The table has one column docs and two indexes. They are both expression +-- indexes referencing the same column attribute (docs) but one is a partial +-- index. +CREATE TABLE t (docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +INSERT INTO t (docs) VALUES ('{"a": 0, "b": 0}'); +INSERT INTO t (docs) SELECT jsonb_build_object('b', n) FROM generate_series(100, 10000) as n; +CREATE INDEX t_idx_a ON t ((docs->>'a')); +CREATE INDEX t_idx_b ON t ((docs->>'b')) WHERE (docs->>'b')::numeric > 9; +-- We're using BTREE indexes and for this test we want to make sure that they remain +-- in sync with changes to our relation. Force the choice of index scans below so +-- that we know we're checking the index's understanding of what values should be +-- in the index or not. +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; +-- Leave 'a' unchanged but modify 'b' to a value outside of the index predicate. +-- This should be a HOT update because neither index is changed. +UPDATE t SET docs = jsonb_build_object('a', 0, 'b', 1) WHERE (docs->>'a')::numeric = 0; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 1 | 100.00 | t | t | 2 | 70 +(1 row) + +-- Let's check to make sure that the index does not contain a value for 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + QUERY PLAN +-------------------------------------------------------------- + Index Scan using t_idx_b on t + Filter: (((docs ->> 'b'::text))::numeric < '100'::numeric) +(2 rows) + +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + docs +------ +(0 rows) + +-- Leave 'a' unchanged but modify 'b' to a value within the index predicate. +-- This represents a change for field 'b' from unindexed to indexed and so +-- this should not take the HOT path. +UPDATE t SET docs = jsonb_build_object('a', 0, 'b', 10) WHERE (docs->>'a')::numeric = 0; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 2 | 1 | 50.00 | t | t | 2 | 70 +(1 row) + +-- Let's check to make sure that the index contains the new value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + QUERY PLAN +-------------------------------------------------------------- + Index Scan using t_idx_b on t + Filter: (((docs ->> 'b'::text))::numeric < '100'::numeric) +(2 rows) + +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + docs +------------------- + {"a": 0, "b": 10} +(1 row) + +-- This update modifies the value of 'a', an indexed field, so it also cannot +-- be a HOT update. +UPDATE t SET docs = jsonb_build_object('a', 1, 'b', 10) WHERE (docs->>'b')::numeric = 10; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 3 | 1 | 33.33 | t | t | 2 | 70 +(1 row) + +-- This update changes both 'a' and 'b' to new values that require index updates, +-- this cannot use the HOT path. +UPDATE t SET docs = jsonb_build_object('a', 2, 'b', 12) WHERE (docs->>'b')::numeric = 10; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 4 | 1 | 25.00 | t | t | 2 | 70 +(1 row) + +-- Let's check to make sure that the index contains the new value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + QUERY PLAN +-------------------------------------------------------------- + Index Scan using t_idx_b on t + Filter: (((docs ->> 'b'::text))::numeric < '100'::numeric) +(2 rows) + +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + docs +------------------- + {"a": 2, "b": 12} +(1 row) + +-- This update changes 'b' to a value outside its predicate requiring that +-- we remove it from the index. That's a transition that can't be done +-- during a HOT update. +UPDATE t SET docs = jsonb_build_object('a', 2, 'b', 1) WHERE (docs->>'b')::numeric = 12; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 5 | 1 | 20.00 | t | t | 2 | 70 +(1 row) + +-- Let's check to make sure that the index no longer contains the value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + QUERY PLAN +-------------------------------------------------------------- + Index Scan using t_idx_b on t + Filter: (((docs ->> 'b'::text))::numeric < '100'::numeric) +(2 rows) + +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + docs +------ +(0 rows) + +DROP TABLE t; +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests to ensure that HOT updates are not performed when multiple indexed +-- attributes are updated. +CREATE TABLE t(a INT, b INT) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_idx_a ON t(a); +CREATE INDEX t_idx_b ON t(abs(b)); +INSERT INTO t VALUES (1, -1); +-- Both are updated, the second is an expression index with an unchanged +-- index value. The change to the index on a should prevent HOT updates. +UPDATE t SET a = 2, b = 1 WHERE a = 1; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 2 | 70 +(1 row) + +DROP TABLE t; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests to check the expression_checks reloption behavior. +-- +CREATE TABLE t(a INT, b INT) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_idx_a ON t(abs(a)) WHERE abs(a) > 10; +CREATE INDEX t_idx_b ON t(abs(b)); +INSERT INTO t VALUES (-1, -1), (-2, -2), (-3, -3), (-4, -4); +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; +-- Disable expression checks on indexes and partial index predicates. +ALTER TABLE t SET (expression_checks = false); +-- Before and after values of a are outside the predicate of the index and +-- the indexed value of b hasn't changed however we've disabled expression +-- checks so this should not be a HOT update. +-- (-1, -1) -> (-5, -1) +UPDATE t SET a = -5, b = -1 WHERE a = -1; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 2 | 70 +(1 row) + +-- Enable expression checks on indexes, but not on predicates yet. +ALTER TABLE t SET (expression_checks = true); +-- The indexed value of b hasn't changed, this should be a HOT update. +-- (-5, -1) -> (-5, 1) +UPDATE t SET b = 1 WHERE a = -5; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 2 | 1 | 50.00 | t | t | 2 | 70 +(1 row) + +-- Now that we're not checking the predicate of the partial index, this +-- update of a from -5 to 5 should be HOT because we should ignore the +-- predicate and check the expression and find it unchanged. +-- (-5, 1) -> (5, 1) +UPDATE t SET a = 5 WHERE a = -5; +SELECT * FROM check_hot_updates(2); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 3 | 2 | 66.67 | t | t | 2 | 70 +(1 row) + +-- This update meets the critera for the partial index and should not +-- be HOT. Let's make sure of that and check the index as well. +-- (-4, -4) -> (-11, -4) +UPDATE t SET a = -11 WHERE a = -4; +SELECT * FROM check_hot_updates(2); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 4 | 2 | 50.00 | t | t | 2 | 70 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; + QUERY PLAN +------------------------------- + Index Scan using t_idx_a on t +(1 row) + +SELECT * FROM t WHERE abs(a) > 10; + a | b +-----+---- + -11 | -4 +(1 row) + +-- (-11, -4) -> (11, -4) +UPDATE t SET a = 11 WHERE a = -11; +SELECT * FROM check_hot_updates(3); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 5 | 3 | 60.00 | t | t | 2 | 70 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; + QUERY PLAN +------------------------------- + Index Scan using t_idx_a on t +(1 row) + +SELECT * FROM t WHERE abs(a) > 10; + a | b +----+---- + 11 | -4 +(1 row) + +-- (11, -4) -> (-4, -4) +UPDATE t SET a = -4 WHERE a = 11; +SELECT * FROM check_hot_updates(3); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 6 | 3 | 50.00 | t | t | 2 | 70 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; + QUERY PLAN +------------------------------- + Index Scan using t_idx_a on t +(1 row) + +SELECT * FROM t WHERE abs(a) > 10; + a | b +---+--- +(0 rows) + +-- This update of a from 5 to -1 is HOT despite that attribute +-- being indexed because the before and after values for the +-- partial index predicate are outside the index definition. +-- (5, 1) -> (-1, 1) +UPDATE t SET a = -1 WHERE a = 5; +SELECT * FROM check_hot_updates(4); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 7 | 4 | 57.14 | t | t | 2 | 70 +(1 row) + +-- This update of a from -2 to -1 with predicate checks enabled should be +-- HOT because the before/after values of a are both outside the predicate +-- of the partial index. +-- (-1, 1) -> (-2, 1) +UPDATE t SET a = -2 WHERE a = -1; +SELECT * FROM check_hot_updates(5); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 8 | 5 | 62.50 | t | t | 2 | 70 +(1 row) + +-- The indexed value for b isn't changing, this should be HOT. +-- (-2, -2) -> (-2, 2) +UPDATE t SET b = 2 WHERE b = -2; +SELECT * FROM check_hot_updates(6); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 9 | 6 | 66.67 | t | t | 2 | 70 +(1 row) + +EXPLAIN (COSTS OFF) SELECT abs(b) FROM t; + QUERY PLAN +------------------ + Seq Scan on t + Disabled: true +(2 rows) + +SELECT abs(b) FROM t; + abs +----- + 3 + 4 + 1 + 2 +(4 rows) + +-- Before and after values for a are outside the predicate of the index, +-- and because we're checking this should be HOT. +-- (-2, 1) -> (5, 1) +-- (-2, -2) -> (5, -2) +UPDATE t SET a = 5 WHERE a = -2; +SELECT * FROM check_hot_updates(8); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 11 | 8 | 72.73 | t | t | 2 | 70 +(1 row) + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; + QUERY PLAN +------------------------------- + Index Scan using t_idx_a on t +(1 row) + +SELECT * FROM t WHERE abs(a) > 10; + a | b +---+--- +(0 rows) + +SELECT * FROM t; + a | b +----+---- + -3 | -3 + -4 | -4 + 5 | 1 + 5 | 2 +(4 rows) + +DROP TABLE t; +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- The tests here examines the behavior of HOT updates when the relation +-- has a JSONB column with an index on the field 'a' and the partial index +-- expression on a different JSONB field 'b'. +CREATE TABLE t(docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->'a')) WHERE (docs->'b')::integer = 1; +INSERT INTO t VALUES ('{"a": 1, "b": 1}'); +EXPLAIN (COSTS OFF) SELECT * FROM t; + QUERY PLAN +--------------- + Seq Scan on t +(1 row) + +SELECT * FROM t; + docs +------------------ + {"a": 1, "b": 1} +(1 row) + +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->'b')::integer = 1; + QUERY PLAN +---------------------------------- + Index Scan using t_docs_idx on t +(1 row) + +SELECT * FROM t WHERE (docs->'b')::integer = 1; + docs +------------------ + {"a": 1, "b": 1} +(1 row) + +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 0 | 0 | 0 | t | t | 1 | 70 +(1 row) + +UPDATE t SET docs='{"a": 1, "b": 0}'; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 1 | 70 +(1 row) + +SELECT * FROM t WHERE (docs->'b')::integer = 1; + docs +------ +(0 rows) + +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; +DROP TABLE t; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests for multi-column indexes +-- +CREATE TABLE t(id INT, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t(id, (docs->'a')); +INSERT INTO t VALUES (1, '{"a": 1, "b": 1}'); +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + QUERY PLAN +------------------------------------------------ + Index Scan using t_docs_idx on t + Index Cond: (id > 0) + Filter: (((docs -> 'a'::text))::integer > 0) +(3 rows) + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + id | docs +----+------------------ + 1 | {"a": 1, "b": 1} +(1 row) + +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 0 | 0 | 0 | t | t | 1 | 70 +(1 row) + +-- Changing the id attribute which is an indexed attribute should +-- prevent HOT updates. +UPDATE t SET id = 2; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 1 | 0 | 0.00 | t | t | 1 | 70 +(1 row) + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + id | docs +----+------------------ + 2 | {"a": 1, "b": 1} +(1 row) + +-- Changing the docs->'a' field in the indexed attribute 'docs' +-- should prevent HOT updates. +UPDATE t SET docs='{"a": -2, "b": 1}'; +SELECT * FROM check_hot_updates(0); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 2 | 0 | 0.00 | t | t | 1 | 70 +(1 row) + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer < 0; + id | docs +----+------------------- + 2 | {"a": -2, "b": 1} +(1 row) + +-- Leaving the docs->'a' attribute unchanged means that the expression +-- is unchanged and because the 'id' attribute isn't in the modified +-- set the indexed tuple is unchanged, this can go HOT. +UPDATE t SET docs='{"a": -2, "b": 2}'; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 3 | 1 | 33.33 | t | t | 1 | 70 +(1 row) + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer < 0; + id | docs +----+------------------- + 2 | {"a": -2, "b": 2} +(1 row) + +-- Here we change the 'id' attribute and the 'docs' attribute setting +-- the expression docs->'a' to a new value, this cannot be a HOT update. +UPDATE t SET id = 3, docs='{"a": 3, "b": 3}'; +SELECT * FROM check_hot_updates(1); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + t | 4 | 1 | 25.00 | t | t | 1 | 70 +(1 row) + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + id | docs +----+------------------ + 3 | {"a": 3, "b": 3} +(1 row) + +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; +DROP TABLE t; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table has a single column 'email' and a unique constraint on it that +-- should preclude HOT updates. +CREATE TABLE users ( + user_id serial primary key, + name VARCHAR(255) NOT NULL, + email VARCHAR(255) NOT NULL, + EXCLUDE USING btree (lower(email) WITH =) +); +-- Add some data to the table and then update it in ways that should and should +-- not be HOT updates. +INSERT INTO users (name, email) VALUES +('user1', 'user1@example.com'), +('user2', 'user2@example.com'), +('taken', 'taken@EXAMPLE.com'), +('you', 'you@domain.com'), +('taken', 'taken@domain.com'); +-- Should fail because of the unique constraint on the email column. +UPDATE users SET email = 'user1@example.com' WHERE email = 'user2@example.com'; +ERROR: conflicting key value violates exclusion constraint "users_lower_excl" +DETAIL: Key (lower(email::text))=(user1@example.com) conflicts with existing key (lower(email::text))=(user1@example.com). +SELECT * FROM check_hot_updates(0, 'users'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + users | 1 | 0 | 0.00 | t | t | 2 | 100 +(1 row) + +-- Should succeed because the email column is not being updated and should go HOT. +UPDATE users SET name = 'foo' WHERE email = 'user1@example.com'; +SELECT * FROM check_hot_updates(1, 'users'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + users | 2 | 1 | 50.00 | t | t | 2 | 100 +(1 row) + +-- Create a partial index on the email column, updates +CREATE INDEX idx_users_email_no_example ON users (lower(email)) WHERE lower(email) LIKE '%@example.com%'; +-- An update that changes the email column but not the indexed portion of it and falls outside the constraint. +-- Shouldn't be a HOT update because of the exclusion constraint. +UPDATE users SET email = 'you+2@domain.com' WHERE name = 'you'; +SELECT * FROM check_hot_updates(1, 'users'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + users | 3 | 1 | 33.33 | t | t | 3 | 100 +(1 row) + +-- An update that changes the email column but not the indexed portion of it and falls within the constraint. +-- Again, should fail constraint and fail to be a HOT update. +UPDATE users SET email = 'taken@domain.com' WHERE name = 'you'; +ERROR: conflicting key value violates exclusion constraint "users_lower_excl" +DETAIL: Key (lower(email::text))=(taken@domain.com) conflicts with existing key (lower(email::text))=(taken@domain.com). +SELECT * FROM check_hot_updates(1, 'users'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + users | 4 | 1 | 25.00 | t | t | 3 | 100 +(1 row) + +DROP TABLE users; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Another test of constraints spoiling HOT updates, this time with a range. +CREATE TABLE events ( + id serial primary key, + name VARCHAR(255) NOT NULL, + event_time tstzrange, + constraint no_screening_time_overlap exclude using gist ( + event_time WITH && + ) +); +-- Add two non-overlapping events. +INSERT INTO events (id, event_time, name) +VALUES + (1, '["2023-01-01 19:00:00", "2023-01-01 20:45:00"]', 'event1'), + (2, '["2023-01-01 21:00:00", "2023-01-01 21:45:00"]', 'event2'); +-- Update the first event to overlap with the second, should fail the constraint and not be HOT. +UPDATE events SET event_time = '["2023-01-01 20:00:00", "2023-01-01 21:45:00"]' WHERE id = 1; +ERROR: conflicting key value violates exclusion constraint "no_screening_time_overlap" +DETAIL: Key (event_time)=(["Sun Jan 01 20:00:00 2023 PST","Sun Jan 01 21:45:00 2023 PST"]) conflicts with existing key (event_time)=(["Sun Jan 01 21:00:00 2023 PST","Sun Jan 01 21:45:00 2023 PST"]). +SELECT * FROM check_hot_updates(0, 'events'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + events | 1 | 0 | 0.00 | t | t | 2 | 100 +(1 row) + +-- Update the first event to not overlap with the second, again not HOT due to the constraint. +UPDATE events SET event_time = '["2023-01-01 22:00:00", "2023-01-01 22:45:00"]' WHERE id = 1; +SELECT * FROM check_hot_updates(0, 'events'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + events | 2 | 0 | 0.00 | t | t | 2 | 100 +(1 row) + +-- Update the first event to not overlap with the second, this time we're HOT because we don't overlap with the constraint. +UPDATE events SET name = 'new name here' WHERE id = 1; +SELECT * FROM check_hot_updates(1, 'events'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + events | 3 | 1 | 33.33 | t | t | 2 | 100 +(1 row) + +DROP TABLE events; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- A test to ensure that only modified summarizing indexes are updated, not +-- all of them. +CREATE TABLE ex (id SERIAL primary key, att1 JSONB, att2 text, att3 text, att4 text) WITH (fillfactor = 60); +CREATE INDEX ex_expr1_idx ON ex USING btree((att1->'data')); +CREATE INDEX ex_sumr1_idx ON ex USING BRIN(att2); +CREATE INDEX ex_expr2_idx ON ex USING btree((att1->'a')); +CREATE INDEX ex_expr3_idx ON ex USING btree((att1->'b')); +CREATE INDEX ex_expr4_idx ON ex USING btree((att1->'c')); +CREATE INDEX ex_sumr2_idx ON ex USING BRIN(att3); +CREATE INDEX ex_sumr3_idx ON ex USING BRIN(att4); +CREATE INDEX ex_expr5_idx ON ex USING btree((att1->'d')); +INSERT INTO ex (att1, att2) VALUES ('{"data": []}'::json, 'nothing special'); +SELECT * FROM ex; + id | att1 | att2 | att3 | att4 +----+--------------+-----------------+------+------ + 1 | {"data": []} | nothing special | | +(1 row) + +-- Update att2 and att4 both are BRIN/summarizing indexes, this should be a HOT update and +-- only update two of the three summarizing indexes. +UPDATE ex SET att2 = 'special indeed', att4 = 'whatever'; +SELECT * FROM check_hot_updates(1, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 1 | 1 | 100.00 | t | t | 9 | 60 +(1 row) + +SELECT * FROM ex; + id | att1 | att2 | att3 | att4 +----+--------------+----------------+------+---------- + 1 | {"data": []} | special indeed | | whatever +(1 row) + +-- Update att1 and att2, only one is BRIN/summarizing, this should NOT be a HOT update. +UPDATE ex SET att1 = att1 || '{"data": "howdy"}', att2 = 'special, so special'; +SELECT * FROM check_hot_updates(1, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 2 | 1 | 50.00 | t | t | 9 | 60 +(1 row) + +SELECT * FROM ex; + id | att1 | att2 | att3 | att4 +----+-------------------+---------------------+------+---------- + 1 | {"data": "howdy"} | special, so special | | whatever +(1 row) + +-- Update att2, att3, and att4 all are BRIN/summarizing indexes, this should be a HOT update +-- and yet still update all three summarizing indexes. +UPDATE ex SET att2 = 'a', att3 = 'b', att4 = 'c'; +SELECT * FROM check_hot_updates(2, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 3 | 2 | 66.67 | t | t | 9 | 60 +(1 row) + +SELECT * FROM ex; + id | att1 | att2 | att3 | att4 +----+-------------------+------+------+------ + 1 | {"data": "howdy"} | a | b | c +(1 row) + +-- Update att1, att2, and att3 all modified values are BRIN/summarizing indexes, this should be a HOT update +-- and yet still update all three summarizing indexes. +UPDATE ex SET att1 = '{"data": "howdy"}', att2 = 'd', att3 = 'e'; +SELECT * FROM check_hot_updates(3, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 4 | 3 | 75.00 | t | t | 9 | 60 +(1 row) + +SELECT * FROM ex; + id | att1 | att2 | att3 | att4 +----+-------------------+------+------+------ + 1 | {"data": "howdy"} | d | e | c +(1 row) + +DROP TABLE ex; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- A test to ensure that summarizing indexes are not updated when they don't +-- change, but are updated when they do while not prefent HOT updates. +CREATE TABLE ex (att1 JSONB, att2 text) WITH (fillfactor = 60); +CREATE INDEX ex_expr1_idx ON ex USING btree((att1->'data')); +CREATE INDEX ex_sumr1_idx ON ex USING BRIN(att2); +INSERT INTO ex VALUES ('{"data": []}', 'nothing special'); +-- Update the unindexed value of att1, this should be a HOT update and and should +-- update the summarizing index. +UPDATE ex SET att1 = att1 || '{"status": "stalemate"}'; +SELECT * FROM check_hot_updates(1, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 1 | 1 | 100.00 | t | t | 2 | 60 +(1 row) + +-- Update the indexed value of att2, a summarized value, this is a summarized +-- only update and should use the HOT path while still triggering an update to +-- the summarizing BRIN index. +UPDATE ex SET att2 = 'special indeed'; +SELECT * FROM check_hot_updates(2, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 2 | 2 | 100.00 | t | t | 2 | 60 +(1 row) + +-- Update to att1 doesn't change the indexed value while the update to att2 does, +-- this again is a summarized only update and should use the HOT path as well as +-- trigger an update to the BRIN index. +UPDATE ex SET att1 = att1 || '{"status": "checkmate"}', att2 = 'special, so special'; +SELECT * FROM check_hot_updates(3, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 3 | 3 | 100.00 | t | t | 2 | 60 +(1 row) + +-- This updates both indexes, the expression index on att1 and the summarizing +-- index on att2. This should not be a HOT update because there are modified +-- indexes and only some are summarized, not all. This should force all +-- indexes to be updated. +UPDATE ex SET att1 = att1 || '{"data": [1,2,3]}', att2 = 'do you want to play a game?'; +SELECT * FROM check_hot_updates(4, 'ex'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + ex | 4 | 3 | 75.00 | f | t | 2 | 60 +(1 row) + +DROP TABLE ex; +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This test is for a table with a custom type and a custom operators on +-- the BTREE index. The question is, when comparing values for equality +-- to determine if there are changes on the index or not... shouldn't we +-- be using the custom operators? +-- Create a type +CREATE TYPE my_custom_type AS (val int); +-- Comparison functions (returns boolean) +CREATE FUNCTION my_custom_lt(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val < b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +CREATE FUNCTION my_custom_le(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val <= b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +CREATE FUNCTION my_custom_eq(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val = b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +CREATE FUNCTION my_custom_ge(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val >= b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +CREATE FUNCTION my_custom_gt(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val > b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +CREATE FUNCTION my_custom_ne(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val != b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +-- Comparison function (returns -1, 0, 1) +CREATE FUNCTION my_custom_cmp(a my_custom_type, b my_custom_type) RETURNS int AS $$ +BEGIN + IF a.val < b.val THEN + RETURN -1; + ELSIF a.val > b.val THEN + RETURN 1; + ELSE + RETURN 0; + END IF; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +-- Create the operators +CREATE OPERATOR < ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_lt, + COMMUTATOR = >, + NEGATOR = >= +); +CREATE OPERATOR <= ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_le, + COMMUTATOR = >=, + NEGATOR = > +); +CREATE OPERATOR = ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_eq, + COMMUTATOR = =, + NEGATOR = <> +); +CREATE OPERATOR >= ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_ge, + COMMUTATOR = <=, + NEGATOR = < +); +CREATE OPERATOR > ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_gt, + COMMUTATOR = <, + NEGATOR = <= +); +CREATE OPERATOR <> ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_ne, + COMMUTATOR = <>, + NEGATOR = = +); +-- Create the operator class (including the support function) +CREATE OPERATOR CLASS my_custom_ops + DEFAULT FOR TYPE my_custom_type USING btree AS + OPERATOR 1 <, + OPERATOR 2 <=, + OPERATOR 3 =, + OPERATOR 4 >=, + OPERATOR 5 >, + FUNCTION 1 my_custom_cmp(my_custom_type, my_custom_type); +-- Create the table +CREATE TABLE my_table ( + id int, + custom_val my_custom_type +); +-- Insert some data +INSERT INTO my_table (id, custom_val) VALUES +(1, ROW(3)::my_custom_type), +(2, ROW(1)::my_custom_type), +(3, ROW(4)::my_custom_type), +(4, ROW(2)::my_custom_type); +-- Create a function to use when indexing +CREATE OR REPLACE FUNCTION abs_val(val my_custom_type) RETURNS int AS $$ +BEGIN + RETURN abs(val.val); +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; +-- Create the index +CREATE INDEX idx_custom_val_abs ON my_table (abs_val(custom_val)); +-- Update 1 +UPDATE my_table SET custom_val = ROW(5)::my_custom_type WHERE id = 1; +SELECT * FROM check_hot_updates(0, 'my_table'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + my_table | 1 | 0 | 0.00 | t | t | 1 | 100 +(1 row) + +-- Update 2 +UPDATE my_table SET custom_val = ROW(0)::my_custom_type WHERE custom_val < ROW(3)::my_custom_type; +SELECT * FROM check_hot_updates(0, 'my_table'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + my_table | 3 | 0 | 0.00 | t | t | 1 | 100 +(1 row) + +-- Update 3 +UPDATE my_table SET custom_val = ROW(6)::my_custom_type WHERE id = 3; +SELECT * FROM check_hot_updates(0, 'my_table'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + my_table | 4 | 0 | 0.00 | t | t | 1 | 100 +(1 row) + +-- Update 4 +UPDATE my_table SET id = 5 WHERE id = 1; +SELECT pg_stat_get_xact_tuples_hot_updated('my_table'::regclass); + pg_stat_get_xact_tuples_hot_updated +------------------------------------- + 1 +(1 row) + +SELECT * FROM check_hot_updates(0, 'my_table'); + table_name | total_updates | hot_updates | hot_update_percentage | matches_expected | has_indexes | index_count | fillfactor +------------+---------------+-------------+-----------------------+------------------+-------------+-------------+------------ + my_table | 5 | 1 | 20.00 | f | t | 1 | 100 +(1 row) + +-- Query using the index +EXPLAIN (COSTS OFF) SELECT * FROM my_table WHERE abs_val(custom_val) = 6; + QUERY PLAN +------------------------------------- + Seq Scan on my_table + Filter: (abs_val(custom_val) = 6) +(2 rows) + +SELECT * FROM my_table WHERE abs_val(custom_val) = 6; + id | custom_val +----+------------ + 3 | (6) +(1 row) + +-- Clean up +DROP TABLE my_table CASCADE; +DROP OPERATOR CLASS my_custom_ops USING btree CASCADE; +DROP OPERATOR < (my_custom_type, my_custom_type); +DROP OPERATOR <= (my_custom_type, my_custom_type); +DROP OPERATOR = (my_custom_type, my_custom_type); +DROP OPERATOR >= (my_custom_type, my_custom_type); +DROP OPERATOR > (my_custom_type, my_custom_type); +DROP OPERATOR <> (my_custom_type, my_custom_type); +DROP FUNCTION my_custom_lt(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_le(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_eq(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_ge(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_gt(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_ne(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_cmp(my_custom_type, my_custom_type); +DROP FUNCTION abs_val(my_custom_type); +DROP TYPE my_custom_type CASCADE; +DROP FUNCTION check_hot_updates(int, text, text); diff --git a/src/test/regress/parallel_schedule b/src/test/regress/parallel_schedule index a0f5fab0f5df..8b609517a37a 100644 --- a/src/test/regress/parallel_schedule +++ b/src/test/regress/parallel_schedule @@ -68,6 +68,11 @@ test: select_into select_distinct select_distinct_on select_implicit select_havi # ---------- test: brin gin gist spgist privileges init_privs security_label collate matview lock replica_identity rowsecurity object_address tablesample groupingsets drop_operator password identity generated_stored join_hash +# ---------- +# Another group of parallel tests +# ---------- +test: heap_hot_updates + # ---------- # Additional BRIN tests # ---------- diff --git a/src/test/regress/sql/heap_hot_updates.sql b/src/test/regress/sql/heap_hot_updates.sql new file mode 100644 index 000000000000..7016e9eabd01 --- /dev/null +++ b/src/test/regress/sql/heap_hot_updates.sql @@ -0,0 +1,718 @@ +-- Create a function to measure HOT updates +CREATE OR REPLACE FUNCTION check_hot_updates( + expected INT, + p_table_name TEXT DEFAULT 't', + p_schema_name TEXT DEFAULT current_schema() +) +RETURNS TABLE ( + table_name TEXT, + total_updates BIGINT, + hot_updates BIGINT, + hot_update_percentage NUMERIC, + matches_expected BOOLEAN, + has_indexes BOOLEAN, + index_count INT, + fillfactor INT +) +LANGUAGE plpgsql +AS $$ +DECLARE + v_relid oid; + v_qualified_name TEXT; + v_hot_updates BIGINT; + v_updates BIGINT; + v_xact_hot_updates BIGINT; + v_xact_updates BIGINT; +BEGIN + + -- We need to wait for statistics to update + PERFORM pg_stat_force_next_flush(); + + -- Construct qualified name + v_qualified_name := quote_ident(p_schema_name) || '.' || quote_ident(p_table_name); + + -- Get the OID using regclass + v_relid := v_qualified_name::regclass; + + IF v_relid IS NULL THEN + RAISE EXCEPTION 'Table %.% not found', p_schema_name, p_table_name; + END IF; + + -- Get cumulative stats + v_hot_updates := COALESCE(pg_stat_get_tuples_hot_updated(v_relid), 0); + v_updates := COALESCE(pg_stat_get_tuples_updated(v_relid), 0); + + -- Get current transaction stats + v_xact_hot_updates := COALESCE(pg_stat_get_xact_tuples_hot_updated(v_relid), 0); + v_xact_updates := COALESCE(pg_stat_get_xact_tuples_updated(v_relid), 0); + + -- Combine stats + v_hot_updates := v_hot_updates + v_xact_hot_updates; + v_updates := v_updates + v_xact_updates; + + RETURN QUERY + SELECT + p_table_name::TEXT, + v_updates::BIGINT as total_updates, + v_hot_updates::BIGINT as hot_updates, + CASE + WHEN v_updates > 0 THEN + ROUND((v_hot_updates::numeric / v_updates::numeric * 100)::numeric, 2) + ELSE 0 + END as hot_update_percentage, + (v_hot_updates = expected)::BOOLEAN as matches_expected, + (EXISTS ( + SELECT 1 FROM pg_index WHERE indrelid = v_relid + ))::BOOLEAN as has_indexes, + ( + SELECT COUNT(*)::INT + FROM pg_index + WHERE indrelid = v_relid + ) as index_count, + COALESCE( + ( + SELECT (regexp_match(array_to_string(reloptions, ','), 'fillfactor=(\d+)'))[1]::int + FROM pg_class + WHERE oid = v_relid + ), + 100 + ) as fillfactor; +END; +$$; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table will have two columns and two indexes, one on the primary key +-- id and one on the expression (docs->>'name'). That means that the indexed +-- attributes are 'id' and 'docs'. +CREATE TABLE t(id INT PRIMARY KEY, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->>'name')); +INSERT INTO t VALUES (1, '{"name": "john", "data": "some data"}'); + +-- Disable expression checks. +ALTER TABLE t SET (expression_checks = false); +SELECT reloptions FROM pg_class WHERE relname = 't'; + +-- While the indexed attribute "name" is unchanged we've disabled expression +-- checks so this update should not go HOT as the system can't determine if +-- the indexed attribute has changed without evaluating the expression. +update t set docs='{"name": "john", "data": "something else"}' where id=1; +SELECT * FROM check_hot_updates(0); + +-- Re-enable expression checks. +ALTER TABLE t SET (expression_checks = true); +SELECT reloptions FROM pg_class WHERE relname = 't'; + +-- The indexed attribute "name" with value "john" is unchanged, expect a HOT update. +UPDATE t SET docs='{"name": "john", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(1); + +-- The following update changes the indexed attribute "name", this should not be a HOT update. +UPDATE t SET docs='{"name": "smith", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(1); + +-- Now, this update does not change the indexed attribute "name" from "smith", this should be HOT. +UPDATE t SET docs='{"name": "smith", "data": "some more data"}' WHERE id=1; +SELECT * FROM check_hot_updates(2); + +DROP TABLE t; + + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table is the same as the previous one but it has a third index. The +-- index 'colindex' isn't an expression index, it indexes the entire value +-- in the docs column. There are still only two indexed attributes for this +-- relation, the same two as before. The presence of an index on the entire +-- value of the docs column should prevent HOT updates for any updates to any +-- portion of JSONB content in that column. +CREATE TABLE t(id INT PRIMARY KEY, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->>'name')); +CREATE INDEX t_docs_col_idx ON t(docs); +INSERT INTO t VALUES (1, '{"name": "john", "data": "some data"}'); + +-- This update doesn't change the value of the expression index, but it does +-- change the content of the docs column and so should not be HOT because the +-- indexed value changed as a result of the update. +UPDATE t SET docs='{"name": "john", "data": "some other data"}' WHERE id=1; +SELECT * FROM check_hot_updates(0); +DROP TABLE t; + + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- The table has one column docs and two indexes. They are both expression +-- indexes referencing the same column attribute (docs) but one is a partial +-- index. +CREATE TABLE t (docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +INSERT INTO t (docs) VALUES ('{"a": 0, "b": 0}'); +INSERT INTO t (docs) SELECT jsonb_build_object('b', n) FROM generate_series(100, 10000) as n; +CREATE INDEX t_idx_a ON t ((docs->>'a')); +CREATE INDEX t_idx_b ON t ((docs->>'b')) WHERE (docs->>'b')::numeric > 9; + +-- We're using BTREE indexes and for this test we want to make sure that they remain +-- in sync with changes to our relation. Force the choice of index scans below so +-- that we know we're checking the index's understanding of what values should be +-- in the index or not. +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; + +-- Leave 'a' unchanged but modify 'b' to a value outside of the index predicate. +-- This should be a HOT update because neither index is changed. +UPDATE t SET docs = jsonb_build_object('a', 0, 'b', 1) WHERE (docs->>'a')::numeric = 0; +SELECT * FROM check_hot_updates(1); +-- Let's check to make sure that the index does not contain a value for 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + +-- Leave 'a' unchanged but modify 'b' to a value within the index predicate. +-- This represents a change for field 'b' from unindexed to indexed and so +-- this should not take the HOT path. +UPDATE t SET docs = jsonb_build_object('a', 0, 'b', 10) WHERE (docs->>'a')::numeric = 0; +SELECT * FROM check_hot_updates(1); +-- Let's check to make sure that the index contains the new value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + +-- This update modifies the value of 'a', an indexed field, so it also cannot +-- be a HOT update. +UPDATE t SET docs = jsonb_build_object('a', 1, 'b', 10) WHERE (docs->>'b')::numeric = 10; +SELECT * FROM check_hot_updates(1); + +-- This update changes both 'a' and 'b' to new values that require index updates, +-- this cannot use the HOT path. +UPDATE t SET docs = jsonb_build_object('a', 2, 'b', 12) WHERE (docs->>'b')::numeric = 10; +SELECT * FROM check_hot_updates(1); +-- Let's check to make sure that the index contains the new value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + +-- This update changes 'b' to a value outside its predicate requiring that +-- we remove it from the index. That's a transition that can't be done +-- during a HOT update. +UPDATE t SET docs = jsonb_build_object('a', 2, 'b', 1) WHERE (docs->>'b')::numeric = 12; +SELECT * FROM check_hot_updates(1); +-- Let's check to make sure that the index no longer contains the value of 'b' +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; +SELECT * FROM t WHERE (docs->>'b')::numeric > 9 AND (docs->>'b')::numeric < 100; + +DROP TABLE t; +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests to ensure that HOT updates are not performed when multiple indexed +-- attributes are updated. +CREATE TABLE t(a INT, b INT) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_idx_a ON t(a); +CREATE INDEX t_idx_b ON t(abs(b)); +INSERT INTO t VALUES (1, -1); + +-- Both are updated, the second is an expression index with an unchanged +-- index value. The change to the index on a should prevent HOT updates. +UPDATE t SET a = 2, b = 1 WHERE a = 1; +SELECT * FROM check_hot_updates(0); + +DROP TABLE t; + + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests to check the expression_checks reloption behavior. +-- +CREATE TABLE t(a INT, b INT) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_idx_a ON t(abs(a)) WHERE abs(a) > 10; +CREATE INDEX t_idx_b ON t(abs(b)); +INSERT INTO t VALUES (-1, -1), (-2, -2), (-3, -3), (-4, -4); + +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; + +-- Disable expression checks on indexes and partial index predicates. +ALTER TABLE t SET (expression_checks = false); + +-- Before and after values of a are outside the predicate of the index and +-- the indexed value of b hasn't changed however we've disabled expression +-- checks so this should not be a HOT update. +-- (-1, -1) -> (-5, -1) +UPDATE t SET a = -5, b = -1 WHERE a = -1; +SELECT * FROM check_hot_updates(0); + +-- Enable expression checks on indexes, but not on predicates yet. +ALTER TABLE t SET (expression_checks = true); + +-- The indexed value of b hasn't changed, this should be a HOT update. +-- (-5, -1) -> (-5, 1) +UPDATE t SET b = 1 WHERE a = -5; +SELECT * FROM check_hot_updates(1); + +-- Now that we're not checking the predicate of the partial index, this +-- update of a from -5 to 5 should be HOT because we should ignore the +-- predicate and check the expression and find it unchanged. +-- (-5, 1) -> (5, 1) +UPDATE t SET a = 5 WHERE a = -5; +SELECT * FROM check_hot_updates(2); + +-- This update meets the critera for the partial index and should not +-- be HOT. Let's make sure of that and check the index as well. +-- (-4, -4) -> (-11, -4) +UPDATE t SET a = -11 WHERE a = -4; +SELECT * FROM check_hot_updates(2); +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; +SELECT * FROM t WHERE abs(a) > 10; + +-- (-11, -4) -> (11, -4) +UPDATE t SET a = 11 WHERE a = -11; +SELECT * FROM check_hot_updates(3); +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; +SELECT * FROM t WHERE abs(a) > 10; + +-- (11, -4) -> (-4, -4) +UPDATE t SET a = -4 WHERE a = 11; +SELECT * FROM check_hot_updates(3); +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; +SELECT * FROM t WHERE abs(a) > 10; + +-- This update of a from 5 to -1 is HOT despite that attribute +-- being indexed because the before and after values for the +-- partial index predicate are outside the index definition. +-- (5, 1) -> (-1, 1) +UPDATE t SET a = -1 WHERE a = 5; +SELECT * FROM check_hot_updates(4); + +-- This update of a from -2 to -1 with predicate checks enabled should be +-- HOT because the before/after values of a are both outside the predicate +-- of the partial index. +-- (-1, 1) -> (-2, 1) +UPDATE t SET a = -2 WHERE a = -1; +SELECT * FROM check_hot_updates(5); + +-- The indexed value for b isn't changing, this should be HOT. +-- (-2, -2) -> (-2, 2) +UPDATE t SET b = 2 WHERE b = -2; +SELECT * FROM check_hot_updates(6); +EXPLAIN (COSTS OFF) SELECT abs(b) FROM t; +SELECT abs(b) FROM t; + +-- Before and after values for a are outside the predicate of the index, +-- and because we're checking this should be HOT. +-- (-2, 1) -> (5, 1) +-- (-2, -2) -> (5, -2) +UPDATE t SET a = 5 WHERE a = -2; +SELECT * FROM check_hot_updates(8); + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE abs(a) > 10; +SELECT * FROM t WHERE abs(a) > 10; + +SELECT * FROM t; + +DROP TABLE t; +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; + + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- The tests here examines the behavior of HOT updates when the relation +-- has a JSONB column with an index on the field 'a' and the partial index +-- expression on a different JSONB field 'b'. +CREATE TABLE t(docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t((docs->'a')) WHERE (docs->'b')::integer = 1; +INSERT INTO t VALUES ('{"a": 1, "b": 1}'); + +EXPLAIN (COSTS OFF) SELECT * FROM t; +SELECT * FROM t; + +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE (docs->'b')::integer = 1; +SELECT * FROM t WHERE (docs->'b')::integer = 1; + +SELECT * FROM check_hot_updates(0); + +UPDATE t SET docs='{"a": 1, "b": 0}'; +SELECT * FROM check_hot_updates(0); + +SELECT * FROM t WHERE (docs->'b')::integer = 1; + +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; + +DROP TABLE t; + + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Tests for multi-column indexes +-- +CREATE TABLE t(id INT, docs JSONB) WITH (autovacuum_enabled = off, fillfactor = 70); +CREATE INDEX t_docs_idx ON t(id, (docs->'a')); +INSERT INTO t VALUES (1, '{"a": 1, "b": 1}'); + +SET SESSION enable_seqscan = OFF; +SET SESSION enable_bitmapscan = OFF; + +EXPLAIN (COSTS OFF) SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + +SELECT * FROM check_hot_updates(0); + +-- Changing the id attribute which is an indexed attribute should +-- prevent HOT updates. +UPDATE t SET id = 2; +SELECT * FROM check_hot_updates(0); + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + +-- Changing the docs->'a' field in the indexed attribute 'docs' +-- should prevent HOT updates. +UPDATE t SET docs='{"a": -2, "b": 1}'; +SELECT * FROM check_hot_updates(0); + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer < 0; + +-- Leaving the docs->'a' attribute unchanged means that the expression +-- is unchanged and because the 'id' attribute isn't in the modified +-- set the indexed tuple is unchanged, this can go HOT. +UPDATE t SET docs='{"a": -2, "b": 2}'; +SELECT * FROM check_hot_updates(1); + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer < 0; + +-- Here we change the 'id' attribute and the 'docs' attribute setting +-- the expression docs->'a' to a new value, this cannot be a HOT update. +UPDATE t SET id = 3, docs='{"a": 3, "b": 3}'; +SELECT * FROM check_hot_updates(1); + +SELECT * FROM t WHERE id > 0 AND (docs->'a')::integer > 0; + +SET SESSION enable_seqscan = ON; +SET SESSION enable_bitmapscan = ON; + +DROP TABLE t; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This table has a single column 'email' and a unique constraint on it that +-- should preclude HOT updates. +CREATE TABLE users ( + user_id serial primary key, + name VARCHAR(255) NOT NULL, + email VARCHAR(255) NOT NULL, + EXCLUDE USING btree (lower(email) WITH =) +); + +-- Add some data to the table and then update it in ways that should and should +-- not be HOT updates. +INSERT INTO users (name, email) VALUES +('user1', 'user1@example.com'), +('user2', 'user2@example.com'), +('taken', 'taken@EXAMPLE.com'), +('you', 'you@domain.com'), +('taken', 'taken@domain.com'); + +-- Should fail because of the unique constraint on the email column. +UPDATE users SET email = 'user1@example.com' WHERE email = 'user2@example.com'; +SELECT * FROM check_hot_updates(0, 'users'); + +-- Should succeed because the email column is not being updated and should go HOT. +UPDATE users SET name = 'foo' WHERE email = 'user1@example.com'; +SELECT * FROM check_hot_updates(1, 'users'); + +-- Create a partial index on the email column, updates +CREATE INDEX idx_users_email_no_example ON users (lower(email)) WHERE lower(email) LIKE '%@example.com%'; + +-- An update that changes the email column but not the indexed portion of it and falls outside the constraint. +-- Shouldn't be a HOT update because of the exclusion constraint. +UPDATE users SET email = 'you+2@domain.com' WHERE name = 'you'; +SELECT * FROM check_hot_updates(1, 'users'); + +-- An update that changes the email column but not the indexed portion of it and falls within the constraint. +-- Again, should fail constraint and fail to be a HOT update. +UPDATE users SET email = 'taken@domain.com' WHERE name = 'you'; +SELECT * FROM check_hot_updates(1, 'users'); + +DROP TABLE users; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- Another test of constraints spoiling HOT updates, this time with a range. +CREATE TABLE events ( + id serial primary key, + name VARCHAR(255) NOT NULL, + event_time tstzrange, + constraint no_screening_time_overlap exclude using gist ( + event_time WITH && + ) +); + +-- Add two non-overlapping events. +INSERT INTO events (id, event_time, name) +VALUES + (1, '["2023-01-01 19:00:00", "2023-01-01 20:45:00"]', 'event1'), + (2, '["2023-01-01 21:00:00", "2023-01-01 21:45:00"]', 'event2'); + +-- Update the first event to overlap with the second, should fail the constraint and not be HOT. +UPDATE events SET event_time = '["2023-01-01 20:00:00", "2023-01-01 21:45:00"]' WHERE id = 1; +SELECT * FROM check_hot_updates(0, 'events'); + +-- Update the first event to not overlap with the second, again not HOT due to the constraint. +UPDATE events SET event_time = '["2023-01-01 22:00:00", "2023-01-01 22:45:00"]' WHERE id = 1; +SELECT * FROM check_hot_updates(0, 'events'); + +-- Update the first event to not overlap with the second, this time we're HOT because we don't overlap with the constraint. +UPDATE events SET name = 'new name here' WHERE id = 1; +SELECT * FROM check_hot_updates(1, 'events'); + +DROP TABLE events; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- A test to ensure that only modified summarizing indexes are updated, not +-- all of them. +CREATE TABLE ex (id SERIAL primary key, att1 JSONB, att2 text, att3 text, att4 text) WITH (fillfactor = 60); +CREATE INDEX ex_expr1_idx ON ex USING btree((att1->'data')); +CREATE INDEX ex_sumr1_idx ON ex USING BRIN(att2); +CREATE INDEX ex_expr2_idx ON ex USING btree((att1->'a')); +CREATE INDEX ex_expr3_idx ON ex USING btree((att1->'b')); +CREATE INDEX ex_expr4_idx ON ex USING btree((att1->'c')); +CREATE INDEX ex_sumr2_idx ON ex USING BRIN(att3); +CREATE INDEX ex_sumr3_idx ON ex USING BRIN(att4); +CREATE INDEX ex_expr5_idx ON ex USING btree((att1->'d')); +INSERT INTO ex (att1, att2) VALUES ('{"data": []}'::json, 'nothing special'); + +SELECT * FROM ex; + +-- Update att2 and att4 both are BRIN/summarizing indexes, this should be a HOT update and +-- only update two of the three summarizing indexes. +UPDATE ex SET att2 = 'special indeed', att4 = 'whatever'; +SELECT * FROM check_hot_updates(1, 'ex'); +SELECT * FROM ex; + +-- Update att1 and att2, only one is BRIN/summarizing, this should NOT be a HOT update. +UPDATE ex SET att1 = att1 || '{"data": "howdy"}', att2 = 'special, so special'; +SELECT * FROM check_hot_updates(1, 'ex'); +SELECT * FROM ex; + +-- Update att2, att3, and att4 all are BRIN/summarizing indexes, this should be a HOT update +-- and yet still update all three summarizing indexes. +UPDATE ex SET att2 = 'a', att3 = 'b', att4 = 'c'; +SELECT * FROM check_hot_updates(2, 'ex'); +SELECT * FROM ex; + +-- Update att1, att2, and att3 all modified values are BRIN/summarizing indexes, this should be a HOT update +-- and yet still update all three summarizing indexes. +UPDATE ex SET att1 = '{"data": "howdy"}', att2 = 'd', att3 = 'e'; +SELECT * FROM check_hot_updates(3, 'ex'); +SELECT * FROM ex; + +DROP TABLE ex; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- A test to ensure that summarizing indexes are not updated when they don't +-- change, but are updated when they do while not prefent HOT updates. +CREATE TABLE ex (att1 JSONB, att2 text) WITH (fillfactor = 60); +CREATE INDEX ex_expr1_idx ON ex USING btree((att1->'data')); +CREATE INDEX ex_sumr1_idx ON ex USING BRIN(att2); +INSERT INTO ex VALUES ('{"data": []}', 'nothing special'); + +-- Update the unindexed value of att1, this should be a HOT update and and should +-- update the summarizing index. +UPDATE ex SET att1 = att1 || '{"status": "stalemate"}'; +SELECT * FROM check_hot_updates(1, 'ex'); + +-- Update the indexed value of att2, a summarized value, this is a summarized +-- only update and should use the HOT path while still triggering an update to +-- the summarizing BRIN index. +UPDATE ex SET att2 = 'special indeed'; +SELECT * FROM check_hot_updates(2, 'ex'); + +-- Update to att1 doesn't change the indexed value while the update to att2 does, +-- this again is a summarized only update and should use the HOT path as well as +-- trigger an update to the BRIN index. +UPDATE ex SET att1 = att1 || '{"status": "checkmate"}', att2 = 'special, so special'; +SELECT * FROM check_hot_updates(3, 'ex'); + +-- This updates both indexes, the expression index on att1 and the summarizing +-- index on att2. This should not be a HOT update because there are modified +-- indexes and only some are summarized, not all. This should force all +-- indexes to be updated. +UPDATE ex SET att1 = att1 || '{"data": [1,2,3]}', att2 = 'do you want to play a game?'; +SELECT * FROM check_hot_updates(4, 'ex'); + +DROP TABLE ex; + +-- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- -- +-- This test is for a table with a custom type and a custom operators on +-- the BTREE index. The question is, when comparing values for equality +-- to determine if there are changes on the index or not... shouldn't we +-- be using the custom operators? + +-- Create a type +CREATE TYPE my_custom_type AS (val int); + +-- Comparison functions (returns boolean) +CREATE FUNCTION my_custom_lt(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val < b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +CREATE FUNCTION my_custom_le(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val <= b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +CREATE FUNCTION my_custom_eq(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val = b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +CREATE FUNCTION my_custom_ge(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val >= b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +CREATE FUNCTION my_custom_gt(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val > b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +CREATE FUNCTION my_custom_ne(a my_custom_type, b my_custom_type) RETURNS boolean AS $$ +BEGIN + RETURN a.val != b.val; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +-- Comparison function (returns -1, 0, 1) +CREATE FUNCTION my_custom_cmp(a my_custom_type, b my_custom_type) RETURNS int AS $$ +BEGIN + IF a.val < b.val THEN + RETURN -1; + ELSIF a.val > b.val THEN + RETURN 1; + ELSE + RETURN 0; + END IF; +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +-- Create the operators +CREATE OPERATOR < ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_lt, + COMMUTATOR = >, + NEGATOR = >= +); + +CREATE OPERATOR <= ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_le, + COMMUTATOR = >=, + NEGATOR = > +); + +CREATE OPERATOR = ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_eq, + COMMUTATOR = =, + NEGATOR = <> +); + +CREATE OPERATOR >= ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_ge, + COMMUTATOR = <=, + NEGATOR = < +); + +CREATE OPERATOR > ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_gt, + COMMUTATOR = <, + NEGATOR = <= +); + +CREATE OPERATOR <> ( + LEFTARG = my_custom_type, + RIGHTARG = my_custom_type, + PROCEDURE = my_custom_ne, + COMMUTATOR = <>, + NEGATOR = = +); + +-- Create the operator class (including the support function) +CREATE OPERATOR CLASS my_custom_ops + DEFAULT FOR TYPE my_custom_type USING btree AS + OPERATOR 1 <, + OPERATOR 2 <=, + OPERATOR 3 =, + OPERATOR 4 >=, + OPERATOR 5 >, + FUNCTION 1 my_custom_cmp(my_custom_type, my_custom_type); + +-- Create the table +CREATE TABLE my_table ( + id int, + custom_val my_custom_type +); + +-- Insert some data +INSERT INTO my_table (id, custom_val) VALUES +(1, ROW(3)::my_custom_type), +(2, ROW(1)::my_custom_type), +(3, ROW(4)::my_custom_type), +(4, ROW(2)::my_custom_type); + +-- Create a function to use when indexing +CREATE OR REPLACE FUNCTION abs_val(val my_custom_type) RETURNS int AS $$ +BEGIN + RETURN abs(val.val); +END; +$$ LANGUAGE plpgsql IMMUTABLE STRICT; + +-- Create the index +CREATE INDEX idx_custom_val_abs ON my_table (abs_val(custom_val)); + +-- Update 1 +UPDATE my_table SET custom_val = ROW(5)::my_custom_type WHERE id = 1; +SELECT * FROM check_hot_updates(0, 'my_table'); + +-- Update 2 +UPDATE my_table SET custom_val = ROW(0)::my_custom_type WHERE custom_val < ROW(3)::my_custom_type; +SELECT * FROM check_hot_updates(0, 'my_table'); + +-- Update 3 +UPDATE my_table SET custom_val = ROW(6)::my_custom_type WHERE id = 3; +SELECT * FROM check_hot_updates(0, 'my_table'); + +-- Update 4 +UPDATE my_table SET id = 5 WHERE id = 1; +SELECT pg_stat_get_xact_tuples_hot_updated('my_table'::regclass); +SELECT * FROM check_hot_updates(0, 'my_table'); + +-- Query using the index +EXPLAIN (COSTS OFF) SELECT * FROM my_table WHERE abs_val(custom_val) = 6; +SELECT * FROM my_table WHERE abs_val(custom_val) = 6; + +-- Clean up +DROP TABLE my_table CASCADE; +DROP OPERATOR CLASS my_custom_ops USING btree CASCADE; +DROP OPERATOR < (my_custom_type, my_custom_type); +DROP OPERATOR <= (my_custom_type, my_custom_type); +DROP OPERATOR = (my_custom_type, my_custom_type); +DROP OPERATOR >= (my_custom_type, my_custom_type); +DROP OPERATOR > (my_custom_type, my_custom_type); +DROP OPERATOR <> (my_custom_type, my_custom_type); +DROP FUNCTION my_custom_lt(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_le(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_eq(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_ge(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_gt(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_ne(my_custom_type, my_custom_type); +DROP FUNCTION my_custom_cmp(my_custom_type, my_custom_type); +DROP FUNCTION abs_val(my_custom_type); +DROP TYPE my_custom_type CASCADE; + +DROP FUNCTION check_hot_updates(int, text, text); diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list index 018b5919cf66..e1a586b72e42 100644 --- a/src/tools/pgindent/typedefs.list +++ b/src/tools/pgindent/typedefs.list @@ -2988,6 +2988,7 @@ TSVectorStat TState TStatus TStoreState +UpdateContext TU_UpdateIndexes TXNEntryFile TYPCATEGORY @@ -3175,7 +3176,6 @@ UniqueState UnlistenStmt UnresolvedTup UnresolvedTupData -UpdateContext UpdateStmt UpgradeTask UpgradeTaskProcessCB