From b57e3c6f6f6a39ecddff36a602c37b0dce9c4439 Mon Sep 17 00:00:00 2001 From: Karthik Ramanathan Date: Mon, 2 Sep 2024 12:02:12 -0700 Subject: [PATCH] [#23490] YSQL: Tighten notion of equality for update optimizations MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit Summary: ### Background Data undergoes multiple transformations during the lifetime of a query. The data that is input by a query may be type modified (`typmod`), padded and aligned (`typalign`), type casted, compressed (`typstorage`) and normalized before being stored in a Datum as part of a Postgres Tuple. This Datum is then massaged into a network format (`protobuf`) as it is sent over the network to a tserver. Finally, the Datum is unpacked and stored in persistent storage in a format that is supported by DocDB/RocksDB. The reverse process happens when the same piece of data needs to be output back to the user. Each of these formats have their own notion of equality: Postgres has the notion of semantic/logical equality (`{"a": 1, "b": 2}` and `{"b": 2, "a": 1}` are equivalent) and storage/binary equality (the binary representations of `{"a": 1, "b": 2}` and `{"b": 2, "a": 1}` maybe different if alternative representations of a value are not normalized). Similarly DocDB has its own notion of semantic and storage equality. In most cases, these notions of equality can be used interchangeably and with good reason: - There is a 1:1 correspondence between the data stored in different formats. That is, a datum’s representation in postgres has exactly one corresponding representation in DocDB that allows the datum to be transformed seamlessly between the formats. This also implies that two datums whose binary representations are identical in postgres will also have identical representations in DocDB. This property is ubiquitously exploited to pushdown postgres operations to DocDB, and to indeed use DocDB as a storage engine for postgres. - Postgres also normalizes the representation of a datum’s value when it is packed into a Datum prior to storage. That is, if a given value of a given data type has multiple representations (the json from the example above), postgres converts the value into a normalized representation, which allows semantic equality to be interchangeably used with storage equality (if multiple representations of a value are represented in-memory/on-disk identically, they will also be stored identically). For data types that are not normalized, postgres does not define an equality operator (`json` data type is not normalized and does not have an equality operator, while `jsonb` data type is normalized and has an equality operator) This leads to a couple of problems: - There are occasions where we may want to know if two datums are stored identically when the data type that the datums belong to, does not have an equality operator. On such occasions, there is a distinction between semantic (not defined) and storage equality (defined). - Postgres is a highly extensible database that allows users to define custom data types and equality operators. In user-defined scenarios, it is also possible to end up with a difference between semantic and storage equality. ### This revision We perform the following optimizations on UPDATE queries that rely on *some* notion of equality: 1. If a BEFORE UPDATE FOR EACH ROW trigger is defined, we skip redundant index updates by comparing the old (pre-update) and new (post-update) values of a column. 2. With D34040, we also have a framework to skip index updates and constraint checking in cases where the value of a column remains unchanged by the update process. Both of these optimizations rely on semantic equality today. However, they should rely on storage/binary equality to correctly handle the problems mentioned above: - A given data type may not define an equality operator. In the absence of storage equality, for correctness in such cases, we must assume that the columns of such data types always change in value. - A user-defined data type may have funky notions of semantic equality (and set membership). This can lead to correctness issues in cases such as partial indexes, when two representations of a given value are considered semantically equal, but are not stored identically (not normalized) and membership to the partial index relies on a membership function that is sensitive to the storage representation. (eg: `{"a": 1, "b": 2}` and `{"b": 2, "a": 1}` are not stored identically and a partial index is defined on `begins with '{”a”: 1’`) This revision switches to the use of storage equality for the above optimizations with the caveat that the function used for the comparison (`datumIsEqual`) does not support TOASTed storage. Jira: DB-12404 Test Plan: ``` ./yb_build.sh --java-test 'org.yb.pgsql.TestPgRegressUpdateOptimized#schedule' ``` Reviewers: amartsinchyk, mihnea, smishra Reviewed By: amartsinchyk Subscribers: yql Tags: #jenkins-ready Differential Revision: https://phorge.dev.yugabyte.com/D37384 --- .../backend/executor/ybOptimizeModifyTable.c | 84 +- .../expected/yb_update_optimize_indices.out | 1019 +++++++++++++++++ .../sql/yb_update_optimize_indices.sql | 184 +++ 3 files changed, 1261 insertions(+), 26 deletions(-) diff --git a/src/postgres/src/backend/executor/ybOptimizeModifyTable.c b/src/postgres/src/backend/executor/ybOptimizeModifyTable.c index 3fcd9765b4f9..8308ced5e199 100644 --- a/src/postgres/src/backend/executor/ybOptimizeModifyTable.c +++ b/src/postgres/src/backend/executor/ybOptimizeModifyTable.c @@ -126,41 +126,74 @@ YbIsColumnComparisonAllowed(const Bitmapset *modified_cols, } /* ---------------------------------------------------------------- - * YBEqualDatums + * YBAreDatumsStoredIdentically * - * Function compares values of lhs and rhs datums with respect to value type - * and collation. + * Function determines if the underlying storage representation of the two + * datums is identical. * - * Returns true in case value of lhs and rhs datums match. + * Notes: + * - This function assumes that the value held in both datums are of the same + * data type ('attdesc->atttypid'). This function does not account for type + * casting. + * - This function returns true if both datums are NULL. Semantically, NULL + * values are always treated as distinct, unless supplied with a NULLS NOT + * DISTINCT modifier. However, the storage representation of NULL values is + * identical. + * - Data types may have multiple representations for a value. Examples include + * - NaNs in floating point data types + * - {"a": 1, "b": 2}, {"b": 2, "a": 1} in jsonb. + * Postgres normalizes the representation of these values for primitive data + * types. This function does not normalize the representation of datums before + * comparing them. Beware if you are using user-defined data types! + * - Similarly, this function does not account for type modifiers and alignment + * rules. Input datums are expected to be modified and aligned. + * - Additionally, this function assumes that both datums are either compressed + * or uncompressed. It does not handle the case where one datum is compressed + * and the other is not. + * - Furthermore, this function assumes that both data types have the same + * collation. * ---------------------------------------------------------------- */ static bool -YBEqualDatums(Datum lhs, Datum rhs, Oid atttypid, Oid collation) +YBAreDatumsStoredIdentically(Datum lhs, + Datum rhs, + const FormData_pg_attribute *attdesc) { - TypeCacheEntry *typentry = - lookup_type_cache(atttypid, TYPECACHE_CMP_PROC_FINFO); - if (!OidIsValid(typentry->cmp_proc_finfo.fn_oid)) - ereport(ERROR, (errcode(ERRCODE_UNDEFINED_FUNCTION), - errmsg("could not identify a comparison function for " - "type %s", - format_type_be(typentry->type_id)))); - - /* To ensure that there is an upper bound on the size of data compared */ - const int lhslength = datumGetSize(lhs, typentry->typbyval, typentry->typlen); - const int rhslength = datumGetSize(rhs, typentry->typbyval, typentry->typlen); + /* + * Within a tuple, postgres may store a field's data in 3 different ways: + * 1. Inline/byval within the tuple. This is used for fixed length types. + * 2. Out-of-line/by reference but on the same page. Postgres uses fixed + * page sizes (usually 8 KB). If the data fits within the page, it is + * preferred to be stored on the same page, with a reference from the + * tuple to its location. This is used for variable length data types. + * 3. Out-of-line and TOASTed. If the data is too large to fit within the + * page, it is stored in a TOAST table with a reference from the + * tuple to its location. + * + * For fields with inline data (1), it can be determined if the two datums + * are identical by casting the datums to machine-word sized integers and + * comparing their values. + * For fields with out-of-line data (2 and 3), the datums are pointers to + * variable length byte arrays which can be memcmp'd. + * Yugabyte does not TOAST oversized values, nor does it use the concept of + * storage pages, so we do not need to handle (3) in this function. + */ + + Assert(attdesc->attbyval || (attdesc->attstorage != 'e')); + /* + * To ensure that there is an upper bound on the size of data compared, + * compute the size of the datums. The length computation is repeated in + * datumIsEqual, but it does not accept an upper bound arg, and we would + * like to keep that function unchanged. + */ + const int lhslength = datumGetSize(lhs, attdesc->attbyval, attdesc->attlen); + const int rhslength = datumGetSize(rhs, attdesc->attbyval, attdesc->attlen); if (lhslength != rhslength || lhslength > yb_update_optimization_options.max_cols_size_to_compare) return false; - FunctionCallInfoData locfcinfo; - InitFunctionCallInfoData(locfcinfo, &typentry->cmp_proc_finfo, 2, collation, - NULL, NULL); - locfcinfo.arg[0] = lhs; - locfcinfo.arg[1] = rhs; - locfcinfo.argnull[0] = false; - locfcinfo.argnull[1] = false; - return DatumGetInt32(FunctionCallInvoke(&locfcinfo)) == 0; + return datumIsEqual(lhs, rhs, attdesc->attbyval, attdesc->attlen); } /* ---------------------------------------------------------------------------- @@ -192,8 +225,7 @@ YBIsColumnModified(Relation rel, HeapTuple oldtuple, HeapTuple newtuple, return ( (old_is_null != new_is_null) || - (!old_is_null && !YBEqualDatums(old_value, new_value, attdesc->atttypid, - attdesc->attcollation))); + (!old_is_null && !YBAreDatumsStoredIdentically(old_value, new_value, attdesc))); } /* ---------------------------------------------------------------- diff --git a/src/postgres/src/test/regress/expected/yb_update_optimize_indices.out b/src/postgres/src/test/regress/expected/yb_update_optimize_indices.out index ce79d961804d..a7f38c54db9b 100644 --- a/src/postgres/src/test/regress/expected/yb_update_optimize_indices.out +++ b/src/postgres/src/test/regress/expected/yb_update_optimize_indices.out @@ -521,3 +521,1022 @@ EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE non_number_type_table SET tscol = 'Jan Storage Write Requests: 0 Storage Flush Requests: 0 (8 rows) + +DROP TABLE pkey_only_table; +DROP TABLE secindex_only_table; +DROP TABLE nullable_table; +DROP TABLE non_number_type_table; +DROP TABLE number_type_table; +--- +--- Test to validate behavior of equality comparisons across data types +--- +-- Test for json data types +CREATE TABLE json_types_table (h INT PRIMARY KEY, v1 INT, v2 JSONB, v3 JSON); +CREATE INDEX NONCONCURRENTLY ON json_types_table (v1) INCLUDE (v2, v3); +INSERT INTO json_types_table VALUES (1, 1, '{"a": 1, "b": 2}'::jsonb, '{"a": 1, "b": 2}'::json); +INSERT INTO json_types_table VALUES (2, 2, '{"b": 2, "a": 1}', '{"b": 2, "a": 1}'); +-- Equality comparisons on data type with no equality operator (json) should succeed +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1 WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Two different representations of the same data type should be considered equal +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::jsonb WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- JSONB is normalized, while JSON is not, causing an index update +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v3 = '{"b": 2, "a": 1}'::json WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +-- One with white spaces +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{ "b" : 2 , "a" : 1}'::jsonb WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b":2,"a":1}'::json WHERE h = 1; , + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Casting via not specifying type +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}', v3 = '{"a": 1, "b": 1}' WHERE h = 2; +ERROR: syntax error at or near "," +LINE 1: , + ^ +-- Casting via specifying input as a castable type +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::json, v3 = '{"a": 1, "b": 2}'::jsonb WHERE h = 2; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 1 +(11 rows) + +-- Casting an un-normalized JSONB to JSON should cause an index update as the input will never be normalized +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::json, v3 = '{"a": 1, "b": 2}'::jsonb WHERE h = 2; + QUERY PLAN +------------------------------------------------------------------------------------------ + Update on json_types_table (actual rows=0 loops=1) + -> Index Scan using json_types_table_pkey on json_types_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- TODO(kramanathan): PG 15 has jsonpath support. Add tests for jsonpath +-- Tests for geometric data types +CREATE TABLE geometric_types_table (h INT PRIMARY KEY, v1 INT, v2 POINT, v3 LINE, v4 LSEG, v5 BOX, v6 PATH, v7 POLYGON, v8 CIRCLE); +CREATE INDEX NONCONCURRENTLY ON geometric_types_table (v1) INCLUDE (v2, v3, v4, v5, v6, v7, v8); +INSERT INTO geometric_types_table VALUES (1, 1, '(3.0, 4.0)'::point, '[(1.0, 2.0), (3.0, 4.0)]'::line, '[(1, 2), (3, 4)]'::lseg, '(1, 2), (3, 4)'::box, '[(1, 2), (3, 4)]'::path, '((1, 2), (3, 4), (5, 6))'::polygon, '<(1, 2), 3>'::circle); +-- Convert point and line from float representation to int representation (implicit casting) +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v2 = '(3, 4)'::point, v3 = '[(1.0, 2), (3, 4.0)]'::line WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Individual coordinates are stored as float8. Test cases where input has higher precision +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v2 = '(2.999999999999999999, 3.999999999999999999)'::point, v3 = '[(0.999999999999999999, 2.00), (2.999999999999999999, 4)]'::line WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Alternate line and line segment representations; note that line segment is directed +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(3, 4), (1, 2)]'::line, v4 = '[(1, 2), (3, 4)]'::lseg WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '((3, 4), (1, 2))'::line, v4 = '((1, 2), (3, 4))'::lseg WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '(3, 4), (1, 2)'::line, v4 = '(1, 2), (3, 4)'::lseg WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '3, 4, 1, 2'::line, v4 = '1, 2, 3, 4'::lseg WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(3, 4), (1, 2)]'::line, v4 = '[(1, 2), (3, 4)]'::lseg WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Line is equivalent to x - y + 1 = 0 => A = 1, B = -1, C = 1 +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '{1, -1, 1}'::line WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- A line can be represented by other points that lie outside the boundary of the supplied points +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(5, 6), (7, 8)]'::line WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Alternate box representations +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '(3, 2), (1, 4)'::box WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '((3, 2), (1, 4))'::box WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '3, 2, 1, 4'::box WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Alterate representations of a circle +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '(1, 2), 3'::circle WHERE h = 1; +ERROR: invalid input syntax for type circle: "(1, 2), 3" +LINE 1: ...FF) UPDATE geometric_types_table SET v1 = 1, v8 = '(1, 2), 3... + ^ +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '((1, 2), 3)'::circle WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '1, 2, 3'::circle WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------------------- + Update on geometric_types_table (actual rows=0 loops=1) + -> Index Scan using geometric_types_table_pkey on geometric_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Test for array data types +CREATE TABLE array_types_table (h INT PRIMARY KEY, v1 INT, v2 INT4[], v3 FLOAT4[], v4 TEXT[], v5 JSONB[], v6 BYTEA[]); +CREATE INDEX NONCONCURRENTLY ON array_types_table (v1) INCLUDE (v2, v3, v4, v5, v6); +INSERT INTO array_types_table VALUES (1, 1, ARRAY[1, 2, 3], ARRAY[1.0, 2.0, 3.0], ARRAY['a', 'b', 'c'], ARRAY['{"a": 1, "b": 2}', '{"c": 3, "d": 4}']::jsonb[], ARRAY['abc'::bytea, 'def'::bytea, 'ghi'::bytea]); +-- Replace the entire array +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2 = '{1, 2, 3}', v3 = '{1, 2, 3}', v4 = '{"a", "b", "c"}' WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2 = ARRAY[1, 2, 3], v3 = ARRAY[1, 2, 3], v4 = ARRAY['a', 'b', 'c'] WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v5 = ARRAY['{"a": 1, "b": 2}', '{"c": 3, "d": 4}']::jsonb[], v6 = ARRAY['abc', 'def', 'ghi']::bytea[] WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v6 = ARRAY['\x616263'::bytea, '\x646566'::bytea, '\x676869'::bytea] WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Replace specific elements in the array +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2[2] = 2, v3[2] = 1.999999999999999999, v4[3] = 'c' WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v6[1] = '\x616263'::bytea WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2[2:3] = '{2, 3}', v3[1:2] = '{0.999999999999999999, 1.999999999999999999}', v4[1:3] = ARRAY['a', 'b', 'c'] WHERE h = 1; + QUERY PLAN +-------------------------------------------------------------------------------------------- + Update on array_types_table (actual rows=0 loops=1) + -> Index Scan using array_types_table_pkey on array_types_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Test for type modifiers +-- REAL has 6 decimal digits of precision, NUMERIC has type modifiers 'precision' and 'scale'. +-- Precision is the total number of digits, scale is the number of digits after the decimal point. +CREATE TABLE numeric_table (h INT PRIMARY KEY, v1 REAL, v2 NUMERIC(4, 2), v3 NUMERIC(10, 4), v4 FLOAT4); +CREATE INDEX NONCONCURRENTLY ON numeric_table (v1) INCLUDE (v2, v3, v4); +INSERT INTO numeric_table VALUES (1, 1.234567, 12.34, 1.234567, 1.23456789012); +SELECT * FROM numeric_table; + h | v1 | v2 | v3 | v4 +---+---------+-------+--------+--------- + 1 | 1.23457 | 12.34 | 1.2346 | 1.23457 +(1 row) + +-- Query to check that the storage representation remains identical after type modifiers have been applied. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 1.2345670, v2 = 12.344, v4 = 1.23456789567 WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Query to check that casting from a wider type to a narrower type results in "rounding" behavior. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 1.2345670, v2 = 12.336, v3 = 1.234650 WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +-- Casting from infinity to infinity should not cause a change in representation. +-- Note that NUMERIC does not support infinity prior to PG 14. +INSERT INTO numeric_table VALUES (2, 'inf', 'Infinity', '-Infinity', '-inf'); +ERROR: invalid input syntax for type numeric: "Infinity" +LINE 1: INSERT INTO numeric_table VALUES (2, 'inf', 'Infinity', '-In... + ^ +INSERT INTO numeric_table VALUES (2, 'inf', 0, 0, '-inf'); +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 'inf'::real + 1, v4 = '-Infinity'::float4 + 1 WHERE h = 2; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 + 'inf'::real + 1, v4 = v4 + '-Infinity'::float4 + 1 WHERE h = 2; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Casting from infinity to NaN should however cause a change in representation. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 - 'inf'::real, v4 = v4 - '-Infinity'::float4 WHERE h = 2; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 1 +(11 rows) + +SELECT * FROM numeric_table; + h | v1 | v2 | v3 | v4 +---+---------+-------+--------+--------- + 1 | 1.23457 | 12.34 | 1.2347 | 1.23457 + 2 | NaN | 0.00 | 0.0000 | NaN +(2 rows) + +-- Casting from NaN to NaN should not cause a change in representation. +-- Similarly, note that NaN is not supported for NUMERIC types in Yugabyte (GH-711) does not support NaN prior to PG 14. +-- This should error out +INSERT INTO numeric_table VALUES (3, 'nan', 'NaN', 'naN', 'NaN'); +ERROR: DECIMAL does not support NaN yet +INSERT INTO numeric_table VALUES (3, 'nan', 0, 0, 'NaN'); +-- ('inf'::real - 'inf'::real) produces a different representation of NaN than 'NaN'::real in some +-- compilers/optimization levels. So the query below updates the index in some cases, but not in others. +-- Commenting it out to avoid test failures. +-- EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 'inf'::real - 'inf'::real, v4 = v4 - '-Infinity'::float4 - '+Inf'::float4 WHERE h = 3; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 - 'inf'::real, v4 = v4 - '-Infinity'::float4 - '+Inf'::float4 WHERE h = 3; + QUERY PLAN +------------------------------------------------------------------------------------ + Update on numeric_table (actual rows=0 loops=1) + -> Index Scan using numeric_table_pkey on numeric_table (actual rows=1 loops=1) + Index Cond: (h = 3) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +SELECT * FROM numeric_table; + h | v1 | v2 | v3 | v4 +---+---------+-------+--------+--------- + 1 | 1.23457 | 12.34 | 1.2347 | 1.23457 + 2 | NaN | 0.00 | 0.0000 | NaN + 3 | NaN | 0.00 | 0.0000 | NaN +(3 rows) + +-- Test for casting between data types +CREATE TABLE number_table (h INT PRIMARY KEY, v1 INT, v2 INT4, v3 INT8, v4 FLOAT4, v5 FLOAT8); +CREATE INDEX NONCONCURRENTLY ON number_table (v1) INCLUDE (v2, v3, v4, v5); +INSERT INTO number_table VALUES (1, 1, 1, 1, 1.0, 1.0); +-- Casting from a larger type to a smaller type should either retain the same representation +-- if the value is identical or produce an overflow. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (2147483647 + 1)::int8 WHERE h = 1; +ERROR: integer out of range +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = (3.4e39)::float8 WHERE h = 1; +ERROR: value out of range: overflow +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (1)::int8, v4 = (1.0)::float8 WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Casting from a smaller to a larger type should either retain the same representation when the +-- value is identical. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v3 = (1)::int4, v5 = (1.0)::float4 WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Casting between types should not cause an index update if the value remains the same. +INSERT INTO number_table VALUES (2, 2, 17, 15, 17.25, 15.75); +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (17.0)::float4, v3 = (15.0)::float8 WHERE h = 2; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = 17.0, v3 = 15.0 WHERE h = 2; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = 17::int4 + 0.25::float(8), v5 = 15::int8 + 0.75::float(4) WHERE h = 2; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = 17 + 0.25, v5 = 15 + 0.75 WHERE h = 2; + QUERY PLAN +---------------------------------------------------------------------------------- + Update on number_table (actual rows=0 loops=1) + -> Index Scan using number_table_pkey on number_table (actual rows=1 loops=1) + Index Cond: (h = 2) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Test for padding in text data types. +CREATE TABLE text_table (h INT PRIMARY KEY, v1 INT, v2 TEXT, v3 CHAR(8), v4 VARCHAR(8)); +CREATE INDEX NONCONCURRENTLY ON text_table (v1) INCLUDE (v2, v3, v4); +INSERT INTO text_table VALUES (1, 1, 'some-text', 'abcdef', 'abcde'); +-- The following queries should not cause an index update as the text type's value remains unmodified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = 'some-text', v3 = 'abcdef', v4 = 'abcde' WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------ + Update on text_table (actual rows=0 loops=1) + -> Index Scan using text_table_pkey on text_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Postgres does not support NULL characters in strings. The padding does not end up adding any characters. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = rpad('some-text'::char(12), 12, ''), v3 = rpad('abcdef'::char(8), 8, ''), v4 = rpad('abcde'::char(8), 8, '') WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------ + Update on text_table (actual rows=0 loops=1) + -> Index Scan using text_table_pkey on text_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = lpad('some-text'::text, 12, ''), v3 = lpad('abcdef'::text, 8, ''), v4 = lpad('abcde'::text, 8, '') WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------ + Update on text_table (actual rows=0 loops=1) + -> Index Scan using text_table_pkey on text_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = ''::char(4) || 'some-text' || ''::char(4), v3 = 'abcdef' || ''::char(2), v4 = 'abcde' || ''::char(3) WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------ + Update on text_table (actual rows=0 loops=1) + -> Index Scan using text_table_pkey on text_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- The following query ends up updating the index because postgres truncates the trailing NULL characters. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v4 = 'abcde'::char(8) || '000' WHERE h = 1; + QUERY PLAN +------------------------------------------------------------------------------ + Update on text_table (actual rows=0 loops=1) + -> Index Scan using text_table_pkey on text_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +SELECT * FROM text_table; + h | v1 | v2 | v3 | v4 +---+----+-----------+----------+---------- + 1 | 1 | some-text | abcdef | abcde000 +(1 row) + +-- Test for composite data types +CREATE TYPE complex1 AS (v1 INT4, v2 FLOAT4, v3 TEXT, v4 JSONB, v5 BYTEA); +CREATE TABLE composite_table (h INT PRIMARY KEY, v INT, c1 complex1); +CREATE INDEX NONCONCURRENTLY ON composite_table (v) INCLUDE (c1); +INSERT INTO composite_table VALUES (1, 1, ROW(100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea)); +-- The following queries should not cause an index update as the composite type's value remains unmodified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v1 = 100 WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = 1, c1.v3 = 'some-text' WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v2 = 123.45, c1.v5 = '{"c": 3, "d": 4}'::bytea, c1.v4 = '{"a": 1, "b": 2}'::jsonb WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = ROW(100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea) WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea) WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +-- Queries with implicit casting +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100, 123.45, 'some-text', '{"a": 1, "b": 2}', '{"c": 3, "d": 4}') WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100.40, 123.45, 'some-text', '{"b": 2, "a": 1}', '{"c": 3, "d": 4}') WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 1 + Storage Flush Requests: 1 +(10 rows) + +SELECT * FROM composite_table; + h | v | c1 +---+---+------------------------------------------------------------------------------------- + 1 | 1 | (100,123.45,some-text,"{""a"": 1, ""b"": 2}","\\x7b2263223a20332c202264223a20347d") +(1 row) + +-- The following queries should produce an index update as the composite type's value is modified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v1 = (c1).v2 + 1 WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = v + 1, c1.v3 = 'some-text' WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 1 +(11 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = v + 1, c1.v3 = 'someother-text' WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 1 +(11 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v2 = 123.451, c1.v5 = '{"d": 4, "c": 3}'::bytea, c1.v4 = '{"a": 2, "b": 1}'::jsonb WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = ROW((v) + 100, (c1).v1 + 123.45, 'someother-text', '{"a": 2, "b": 1}'::jsonb, '{"d": 4, "c": 3}'::bytea) WHERE h = 1; + QUERY PLAN +---------------------------------------------------------------------------------------- + Update on composite_table (actual rows=0 loops=1) + -> Index Scan using composite_table_pkey on composite_table (actual rows=1 loops=1) + Index Cond: (h = 1) + Storage Table Read Requests: 1 + Storage Table Rows Scanned: 1 + Storage Table Write Requests: 1 + Storage Index Write Requests: 2 + Storage Flush Requests: 1 + Storage Read Requests: 1 + Storage Rows Scanned: 1 + Storage Write Requests: 3 + Storage Flush Requests: 2 +(12 rows) + +SELECT * FROM composite_table; + h | v | c1 +---+---+------------------------------------------------------------------------------------------ + 1 | 3 | (103,247.45,someother-text,"{""a"": 2, ""b"": 1}","\\x7b2264223a20342c202263223a20337d") +(1 row) + +DROP TABLE composite_table; +DROP TABLE text_table; +DROP TABLE number_table; +DROP TABLE numeric_table; +DROP TABLE array_types_table; +DROP TABLE geometric_types_table; +DROP TABLE json_types_table; diff --git a/src/postgres/src/test/regress/sql/yb_update_optimize_indices.sql b/src/postgres/src/test/regress/sql/yb_update_optimize_indices.sql index c4c8766638a9..e6e330cab43f 100644 --- a/src/postgres/src/test/regress/sql/yb_update_optimize_indices.sql +++ b/src/postgres/src/test/regress/sql/yb_update_optimize_indices.sql @@ -96,3 +96,187 @@ CREATE INDEX NONCONCURRENTLY non_number_type_table_uuid_enum ON non_number_type_ INSERT INTO non_number_type_table VALUES('1999-01-08 04:05:06 -8:00', 'varchar1', 'charpad', 'I am batman', '{1, 2, 3}'::line, '1.2.3.0/24'::cidr, 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11'::uuid, 'happy'::mood_type); EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE non_number_type_table SET tscol = 'January 8 04:05:06 1999 PST', varcharcol = 'varchar1', charcol = 'charpad', textcol = 'I am not batman :(', linecol = '{1, 2, 3}'::line, ipcol = '1.2.3'::cidr, uuidcol = 'a0eebc99-9c0b-4ef8-bb6d-6bb9bd380a11'::uuid, enumcol = 'happy' WHERE tscol = 'January 8 07:05:06 1999 EST'; + +DROP TABLE pkey_only_table; +DROP TABLE secindex_only_table; +DROP TABLE nullable_table; +DROP TABLE non_number_type_table; +DROP TABLE number_type_table; + +--- +--- Test to validate behavior of equality comparisons across data types +--- +-- Test for json data types +CREATE TABLE json_types_table (h INT PRIMARY KEY, v1 INT, v2 JSONB, v3 JSON); +CREATE INDEX NONCONCURRENTLY ON json_types_table (v1) INCLUDE (v2, v3); + +INSERT INTO json_types_table VALUES (1, 1, '{"a": 1, "b": 2}'::jsonb, '{"a": 1, "b": 2}'::json); +INSERT INTO json_types_table VALUES (2, 2, '{"b": 2, "a": 1}', '{"b": 2, "a": 1}'); + +-- Equality comparisons on data type with no equality operator (json) should succeed +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1 WHERE h = 1; +-- Two different representations of the same data type should be considered equal +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::jsonb WHERE h = 1; +-- JSONB is normalized, while JSON is not, causing an index update +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v3 = '{"b": 2, "a": 1}'::json WHERE h = 1; +-- One with white spaces +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{ "b" : 2 , "a" : 1}'::jsonb WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b":2,"a":1}'::json WHERE h = 1; , +-- Casting via not specifying type +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}', v3 = '{"a": 1, "b": 1}' WHERE h = 2; +-- Casting via specifying input as a castable type +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::json, v3 = '{"a": 1, "b": 2}'::jsonb WHERE h = 2; +-- Casting an un-normalized JSONB to JSON should cause an index update as the input will never be normalized +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE json_types_table SET v1 = 1, v2 = '{"b": 2, "a": 1}'::json, v3 = '{"a": 1, "b": 2}'::jsonb WHERE h = 2; + +-- TODO(kramanathan): PG 15 has jsonpath support. Add tests for jsonpath + +-- Tests for geometric data types +CREATE TABLE geometric_types_table (h INT PRIMARY KEY, v1 INT, v2 POINT, v3 LINE, v4 LSEG, v5 BOX, v6 PATH, v7 POLYGON, v8 CIRCLE); +CREATE INDEX NONCONCURRENTLY ON geometric_types_table (v1) INCLUDE (v2, v3, v4, v5, v6, v7, v8); +INSERT INTO geometric_types_table VALUES (1, 1, '(3.0, 4.0)'::point, '[(1.0, 2.0), (3.0, 4.0)]'::line, '[(1, 2), (3, 4)]'::lseg, '(1, 2), (3, 4)'::box, '[(1, 2), (3, 4)]'::path, '((1, 2), (3, 4), (5, 6))'::polygon, '<(1, 2), 3>'::circle); + +-- Convert point and line from float representation to int representation (implicit casting) +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v2 = '(3, 4)'::point, v3 = '[(1.0, 2), (3, 4.0)]'::line WHERE h = 1; +-- Individual coordinates are stored as float8. Test cases where input has higher precision +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v2 = '(2.999999999999999999, 3.999999999999999999)'::point, v3 = '[(0.999999999999999999, 2.00), (2.999999999999999999, 4)]'::line WHERE h = 1; +-- Alternate line and line segment representations; note that line segment is directed +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(3, 4), (1, 2)]'::line, v4 = '[(1, 2), (3, 4)]'::lseg WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '((3, 4), (1, 2))'::line, v4 = '((1, 2), (3, 4))'::lseg WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '(3, 4), (1, 2)'::line, v4 = '(1, 2), (3, 4)'::lseg WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '3, 4, 1, 2'::line, v4 = '1, 2, 3, 4'::lseg WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(3, 4), (1, 2)]'::line, v4 = '[(1, 2), (3, 4)]'::lseg WHERE h = 1; +-- Line is equivalent to x - y + 1 = 0 => A = 1, B = -1, C = 1 +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '{1, -1, 1}'::line WHERE h = 1; +-- A line can be represented by other points that lie outside the boundary of the supplied points +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v3 = '[(5, 6), (7, 8)]'::line WHERE h = 1; +-- Alternate box representations +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '(3, 2), (1, 4)'::box WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '((3, 2), (1, 4))'::box WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v5 = '3, 2, 1, 4'::box WHERE h = 1; +-- Alterate representations of a circle +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '(1, 2), 3'::circle WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '((1, 2), 3)'::circle WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE geometric_types_table SET v1 = 1, v8 = '1, 2, 3'::circle WHERE h = 1; + +-- Test for array data types +CREATE TABLE array_types_table (h INT PRIMARY KEY, v1 INT, v2 INT4[], v3 FLOAT4[], v4 TEXT[], v5 JSONB[], v6 BYTEA[]); +CREATE INDEX NONCONCURRENTLY ON array_types_table (v1) INCLUDE (v2, v3, v4, v5, v6); +INSERT INTO array_types_table VALUES (1, 1, ARRAY[1, 2, 3], ARRAY[1.0, 2.0, 3.0], ARRAY['a', 'b', 'c'], ARRAY['{"a": 1, "b": 2}', '{"c": 3, "d": 4}']::jsonb[], ARRAY['abc'::bytea, 'def'::bytea, 'ghi'::bytea]); + +-- Replace the entire array +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2 = '{1, 2, 3}', v3 = '{1, 2, 3}', v4 = '{"a", "b", "c"}' WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2 = ARRAY[1, 2, 3], v3 = ARRAY[1, 2, 3], v4 = ARRAY['a', 'b', 'c'] WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v5 = ARRAY['{"a": 1, "b": 2}', '{"c": 3, "d": 4}']::jsonb[], v6 = ARRAY['abc', 'def', 'ghi']::bytea[] WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v6 = ARRAY['\x616263'::bytea, '\x646566'::bytea, '\x676869'::bytea] WHERE h = 1; +-- Replace specific elements in the array +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2[2] = 2, v3[2] = 1.999999999999999999, v4[3] = 'c' WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v6[1] = '\x616263'::bytea WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE array_types_table SET v1 = 1, v2[2:3] = '{2, 3}', v3[1:2] = '{0.999999999999999999, 1.999999999999999999}', v4[1:3] = ARRAY['a', 'b', 'c'] WHERE h = 1; + +-- Test for type modifiers +-- REAL has 6 decimal digits of precision, NUMERIC has type modifiers 'precision' and 'scale'. +-- Precision is the total number of digits, scale is the number of digits after the decimal point. +CREATE TABLE numeric_table (h INT PRIMARY KEY, v1 REAL, v2 NUMERIC(4, 2), v3 NUMERIC(10, 4), v4 FLOAT4); +CREATE INDEX NONCONCURRENTLY ON numeric_table (v1) INCLUDE (v2, v3, v4); +INSERT INTO numeric_table VALUES (1, 1.234567, 12.34, 1.234567, 1.23456789012); +SELECT * FROM numeric_table; + +-- Query to check that the storage representation remains identical after type modifiers have been applied. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 1.2345670, v2 = 12.344, v4 = 1.23456789567 WHERE h = 1; +-- Query to check that casting from a wider type to a narrower type results in "rounding" behavior. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 1.2345670, v2 = 12.336, v3 = 1.234650 WHERE h = 1; +-- Casting from infinity to infinity should not cause a change in representation. +-- Note that NUMERIC does not support infinity prior to PG 14. +INSERT INTO numeric_table VALUES (2, 'inf', 'Infinity', '-Infinity', '-inf'); +INSERT INTO numeric_table VALUES (2, 'inf', 0, 0, '-inf'); +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 'inf'::real + 1, v4 = '-Infinity'::float4 + 1 WHERE h = 2; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 + 'inf'::real + 1, v4 = v4 + '-Infinity'::float4 + 1 WHERE h = 2; +-- Casting from infinity to NaN should however cause a change in representation. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 - 'inf'::real, v4 = v4 - '-Infinity'::float4 WHERE h = 2; +SELECT * FROM numeric_table; +-- Casting from NaN to NaN should not cause a change in representation. +-- Similarly, note that NaN is not supported for NUMERIC types in Yugabyte (GH-711) does not support NaN prior to PG 14. +-- This should error out +INSERT INTO numeric_table VALUES (3, 'nan', 'NaN', 'naN', 'NaN'); +INSERT INTO numeric_table VALUES (3, 'nan', 0, 0, 'NaN'); +-- ('inf'::real - 'inf'::real) produces a different representation of NaN than 'NaN'::real in some +-- compilers/optimization levels. So the query below updates the index in some cases, but not in others. +-- Commenting it out to avoid test failures. +-- EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = 'inf'::real - 'inf'::real, v4 = v4 - '-Infinity'::float4 - '+Inf'::float4 WHERE h = 3; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE numeric_table SET v1 = v1 - 'inf'::real, v4 = v4 - '-Infinity'::float4 - '+Inf'::float4 WHERE h = 3; +SELECT * FROM numeric_table; + +-- Test for casting between data types +CREATE TABLE number_table (h INT PRIMARY KEY, v1 INT, v2 INT4, v3 INT8, v4 FLOAT4, v5 FLOAT8); +CREATE INDEX NONCONCURRENTLY ON number_table (v1) INCLUDE (v2, v3, v4, v5); +INSERT INTO number_table VALUES (1, 1, 1, 1, 1.0, 1.0); + +-- Casting from a larger type to a smaller type should either retain the same representation +-- if the value is identical or produce an overflow. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (2147483647 + 1)::int8 WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = (3.4e39)::float8 WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (1)::int8, v4 = (1.0)::float8 WHERE h = 1; + +-- Casting from a smaller to a larger type should either retain the same representation when the +-- value is identical. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v3 = (1)::int4, v5 = (1.0)::float4 WHERE h = 1; + +-- Casting between types should not cause an index update if the value remains the same. +INSERT INTO number_table VALUES (2, 2, 17, 15, 17.25, 15.75); +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = (17.0)::float4, v3 = (15.0)::float8 WHERE h = 2; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v2 = 17.0, v3 = 15.0 WHERE h = 2; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = 17::int4 + 0.25::float(8), v5 = 15::int8 + 0.75::float(4) WHERE h = 2; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE number_table SET v4 = 17 + 0.25, v5 = 15 + 0.75 WHERE h = 2; + +-- Test for padding in text data types. +CREATE TABLE text_table (h INT PRIMARY KEY, v1 INT, v2 TEXT, v3 CHAR(8), v4 VARCHAR(8)); +CREATE INDEX NONCONCURRENTLY ON text_table (v1) INCLUDE (v2, v3, v4); +INSERT INTO text_table VALUES (1, 1, 'some-text', 'abcdef', 'abcde'); + +-- The following queries should not cause an index update as the text type's value remains unmodified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = 'some-text', v3 = 'abcdef', v4 = 'abcde' WHERE h = 1; +-- Postgres does not support NULL characters in strings. The padding does not end up adding any characters. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = rpad('some-text'::char(12), 12, ''), v3 = rpad('abcdef'::char(8), 8, ''), v4 = rpad('abcde'::char(8), 8, '') WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = lpad('some-text'::text, 12, ''), v3 = lpad('abcdef'::text, 8, ''), v4 = lpad('abcde'::text, 8, '') WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v2 = ''::char(4) || 'some-text' || ''::char(4), v3 = 'abcdef' || ''::char(2), v4 = 'abcde' || ''::char(3) WHERE h = 1; + +-- The following query ends up updating the index because postgres truncates the trailing NULL characters. +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE text_table SET v4 = 'abcde'::char(8) || '000' WHERE h = 1; +SELECT * FROM text_table; + +-- Test for composite data types +CREATE TYPE complex1 AS (v1 INT4, v2 FLOAT4, v3 TEXT, v4 JSONB, v5 BYTEA); +CREATE TABLE composite_table (h INT PRIMARY KEY, v INT, c1 complex1); +CREATE INDEX NONCONCURRENTLY ON composite_table (v) INCLUDE (c1); + +INSERT INTO composite_table VALUES (1, 1, ROW(100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea)); + +-- The following queries should not cause an index update as the composite type's value remains unmodified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v1 = 100 WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = 1, c1.v3 = 'some-text' WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v2 = 123.45, c1.v5 = '{"c": 3, "d": 4}'::bytea, c1.v4 = '{"a": 1, "b": 2}'::jsonb WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = ROW(100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea) WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100, 123.45, 'some-text', '{"a": 1, "b": 2}'::jsonb, '{"c": 3, "d": 4}'::bytea) WHERE h = 1; +-- Queries with implicit casting +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100, 123.45, 'some-text', '{"a": 1, "b": 2}', '{"c": 3, "d": 4}') WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = (100.40, 123.45, 'some-text', '{"b": 2, "a": 1}', '{"c": 3, "d": 4}') WHERE h = 1; + +SELECT * FROM composite_table; + +-- The following queries should produce an index update as the composite type's value is modified +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v1 = (c1).v2 + 1 WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = v + 1, c1.v3 = 'some-text' WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET v = v + 1, c1.v3 = 'someother-text' WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1.v2 = 123.451, c1.v5 = '{"d": 4, "c": 3}'::bytea, c1.v4 = '{"a": 2, "b": 1}'::jsonb WHERE h = 1; +EXPLAIN (ANALYZE, DIST, COSTS OFF) UPDATE composite_table SET c1 = ROW((v) + 100, (c1).v1 + 123.45, 'someother-text', '{"a": 2, "b": 1}'::jsonb, '{"d": 4, "c": 3}'::bytea) WHERE h = 1; + +SELECT * FROM composite_table; + +DROP TABLE composite_table; +DROP TABLE text_table; +DROP TABLE number_table; +DROP TABLE numeric_table; +DROP TABLE array_types_table; +DROP TABLE geometric_types_table; +DROP TABLE json_types_table;