diff --git a/Makefile b/Makefile index 5ddf0c5..0e57e5d 100644 --- a/Makefile +++ b/Makefile @@ -28,6 +28,7 @@ REGRESS = basic \ cmd_type \ error \ rows \ + squashing \ tags \ user \ level_tracking \ diff --git a/meson.build b/meson.build index 8e1e3e7..afca8bb 100644 --- a/meson.build +++ b/meson.build @@ -44,6 +44,7 @@ tests += { 'pgsqm_query_id', 'relations', 'rows', + 'squashing', 'state', 'tags', 'top_query', diff --git a/pg_stat_monitor.c b/pg_stat_monitor.c index ae63a7a..9dc550f 100644 --- a/pg_stat_monitor.c +++ b/pg_stat_monitor.c @@ -3431,13 +3431,15 @@ generate_normalized_query(JumbleState *jstate, const char *query, { char *norm_query; int query_len = *query_len_p; - int i, - norm_query_buflen, /* Space allowed for norm_query */ + int norm_query_buflen, /* Space allowed for norm_query */ len_to_wrt, /* Length (in bytes) to write */ quer_loc = 0, /* Source query byte location */ n_quer_loc = 0, /* Normalized query byte location */ last_off = 0, /* Offset from start for previous tok */ last_tok_len = 0; /* Length (in bytes) of that tok */ +#if PG_VERSION_NUM >= 180000 + int num_constants_replaced = 0; +#endif /* * Get constants' lengths (core system only gives us locations). Note @@ -3457,11 +3459,24 @@ generate_normalized_query(JumbleState *jstate, const char *query, /* Allocate result buffer */ norm_query = palloc(norm_query_buflen + 1); - for (i = 0; i < jstate->clocations_count; i++) + for (int i = 0; i < jstate->clocations_count; i++) { int off, /* Offset from start for cur tok */ tok_len; /* Length (in bytes) of that tok */ +#if PG_VERSION_NUM >= 180000 + + /* + * If we have an external param at this location, but no lists are + * being squashed across the query, then we skip here; this will make + * us print the characters found in the original query that represent + * the parameter in the next iteration (or after the loop is done), + * which is a bit odd but seems to work okay in most cases. + */ + if (jstate->clocations[i].extern_param && !jstate->has_squashed_lists) + continue; +#endif + off = jstate->clocations[i].location; /* Adjust recorded location if we're dealing with partial string */ off -= query_loc; @@ -3479,10 +3494,24 @@ generate_normalized_query(JumbleState *jstate, const char *query, memcpy(norm_query + n_quer_loc, query + quer_loc, len_to_wrt); n_quer_loc += len_to_wrt; +#if PG_VERSION_NUM >= 180000 + + /* + * And insert a param symbol in place of the constant token; and, if + * we have a squashable list, insert a placeholder comment starting + * from the list's second value. + */ + n_quer_loc += sprintf(norm_query + n_quer_loc, "$%d%s", + num_constants_replaced + 1 + jstate->highest_extern_param_id, + jstate->clocations[i].squashed ? " /*, ... */" : ""); + num_constants_replaced++; +#else /* And insert a param symbol in place of the constant token */ n_quer_loc += sprintf(norm_query + n_quer_loc, "$%d", i + 1 + jstate->highest_extern_param_id); +#endif + /* move forward */ quer_loc = off + tok_len; last_off = off; last_tok_len = tok_len; @@ -3573,6 +3602,11 @@ fill_in_constant_lengths(JumbleState *jstate, const char *query, Assert(loc >= 0); +#if PG_VERSION_NUM >= 180000 + if (locs[i].squashed) + continue; /* squashable list, ignore */ +#endif + if (loc <= last_loc) continue; /* Duplicate constant, ignore */ diff --git a/regression/expected/squashing.out b/regression/expected/squashing.out new file mode 100644 index 0000000..e12a4f3 --- /dev/null +++ b/regression/expected/squashing.out @@ -0,0 +1,6 @@ +-- +-- Const squashing functionality +-- +SELECT setting::integer < 180000 AS skip_test FROM pg_settings where name = 'server_version_num' \gset +\if :skip_test +\quit diff --git a/regression/expected/squashing_1.out b/regression/expected/squashing_1.out new file mode 100644 index 0000000..697c61a --- /dev/null +++ b/regression/expected/squashing_1.out @@ -0,0 +1,792 @@ +-- +-- Const squashing functionality +-- +SELECT setting::integer < 180000 AS skip_test FROM pg_settings where name = 'server_version_num' \gset +\if :skip_test +\quit +\endif +CREATE EXTENSION pg_stat_monitor; +SET pg_stat_monitor.pgsm_normalized_query = TRUE; +-- +-- Simple Lists +-- +CREATE TABLE test_squash (id int, data int); +-- single element will not be squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash WHERE id IN (1); + id | data +----+------ +(0 rows) + +SELECT ARRAY[1]; + array +------- + {1} +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN ($1) | 1 + SELECT ARRAY[$1] | 1 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- more than 1 element in a list will be squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5); + id | data +----+------ +(0 rows) + +SELECT ARRAY[1, 2, 3]; + array +--------- + {1,2,3} +(1 row) + +SELECT ARRAY[1, 2, 3, 4]; + array +----------- + {1,2,3,4} +(1 row) + +SELECT ARRAY[1, 2, 3, 4, 5]; + array +------------- + {1,2,3,4,5} +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN ($1 /*, ... */) | 3 + SELECT ARRAY[$1 /*, ... */] | 3 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- built-in functions will be squashed +-- the IN and ARRAY forms of this statement will have the same queryId +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT WHERE 1 IN (1, int4(1), int4(2), 2); +-- +(1 row) + +SELECT WHERE 1 = ANY (ARRAY[1, int4(1), int4(2), 2]); +-- +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT WHERE $1 IN ($2 /*, ... */) | 2 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- This tests are disabled due bug in PGSM, see: https://perconadev.atlassian.net/browse/PG-1936 +-- -- external parameters will be squashed +-- SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- SELECT * FROM test_squash WHERE id IN ($1, $2, $3, $4, $5) \bind 1 2 3 4 5 +-- ; +-- SELECT * FROM test_squash WHERE id::text = ANY(ARRAY[$1, $2, $3, $4, $5]) \bind 1 2 3 4 5 +-- ; +-- SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; +-- -- prepared statements will also be squashed +-- -- the IN and ARRAY forms of this statement will have the same queryId +-- SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- PREPARE p1(int, int, int, int, int) AS +-- SELECT * FROM test_squash WHERE id IN ($1, $2, $3, $4, $5); +-- EXECUTE p1(1, 2, 3, 4, 5); +-- DEALLOCATE p1; +-- PREPARE p1(int, int, int, int, int) AS +-- SELECT * FROM test_squash WHERE id = ANY(ARRAY[$1, $2, $3, $4, $5]); +-- EXECUTE p1(1, 2, 3, 4, 5); +-- DEALLOCATE p1; +-- SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C";SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; +-- More conditions in the query +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]) AND data = 2; + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +---------------------------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN ($1 /*, ... */) AND data = $2 | 6 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Multiple squashed intervals +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN ($1 /*, ... */)+| 6 + AND data IN ($2 /*, ... */) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +-- No constants squashing for OpExpr +-- The IN and ARRAY forms of this statement will have the same queryId +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash WHERE id IN + (1 + 1, 2 + 2, 3 + 3, 4 + 4, 5 + 5, 6 + 6, 7 + 7, 8 + 8, 9 + 9); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id IN + (@ '-1', @ '-2', @ '-3', @ '-4', @ '-5', @ '-6', @ '-7', @ '-8', @ '-9'); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY(ARRAY + [1 + 1, 2 + 2, 3 + 3, 4 + 4, 5 + 5, 6 + 6, 7 + 7, 8 + 8, 9 + 9]); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY(ARRAY + [@ '-1', @ '-2', @ '-3', @ '-4', @ '-5', @ '-6', @ '-7', @ '-8', @ '-9']); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +----------------------------------------------------------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN +| 2 + ($1 + $2, $3 + $4, $5 + $6, $7 + $8, $9 + $10, $11 + $12, $13 + $14, $15 + $16, $17 + $18) | + SELECT * FROM test_squash WHERE id IN +| 2 + (@ $1, @ $2, @ $3, @ $4, @ $5, @ $6, @ $7, @ $8, @ $9) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- +-- FuncExpr +-- +-- Verify multiple type representation end up with the same query_id +CREATE TABLE test_float (data float); +-- The casted ARRAY expressions will have the same queryId as the IN clause +-- form of the query +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT data FROM test_float WHERE data IN (1, 2); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data IN (1, '2'); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data IN ('1', 2); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data IN ('1', '2'); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data IN (1.0, 1.0); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data = ANY(ARRAY['1'::double precision, '2'::double precision]); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data = ANY(ARRAY[1.0::double precision, 1.0::double precision]); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data = ANY(ARRAY[1, 2]); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data = ANY(ARRAY[1, '2']); + data +------ +(0 rows) + +SELECT data FROM test_float WHERE data = ANY(ARRAY['1', 2]); + data +------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +--------------------------------------------------------------------+------- + SELECT data FROM test_float WHERE data = ANY(ARRAY[$1 /*, ... */]) | 3 + SELECT data FROM test_float WHERE data IN ($1 /*, ... */) | 7 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- Numeric type, implicit cast is squashed +CREATE TABLE test_squash_numeric (id int, data numeric(5, 2)); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_numeric WHERE data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_numeric WHERE data = ANY(ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +--------------------------------------------------------------------------+------- + SELECT * FROM test_squash_numeric WHERE data = ANY(ARRAY[$1 /*, ... */]) | 1 + SELECT * FROM test_squash_numeric WHERE data IN ($1 /*, ... */) | 1 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- Bigint, implicit cast is squashed +CREATE TABLE test_squash_bigint (id int, data bigint); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_bigint WHERE data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_bigint WHERE data = ANY(ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------------------------------+------- + SELECT * FROM test_squash_bigint WHERE data = ANY(ARRAY[$1 /*, ... */]) | 1 + SELECT * FROM test_squash_bigint WHERE data IN ($1 /*, ... */) | 1 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- Bigint, explicit cast is squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_bigint WHERE data IN + (1::bigint, 2::bigint, 3::bigint, 4::bigint, 5::bigint, 6::bigint, + 7::bigint, 8::bigint, 9::bigint, 10::bigint, 11::bigint); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_bigint WHERE data = ANY(ARRAY[ + 1::bigint, 2::bigint, 3::bigint, 4::bigint, 5::bigint, 6::bigint, + 7::bigint, 8::bigint, 9::bigint, 10::bigint, 11::bigint]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT * FROM test_squash_bigint WHERE data IN +| 2 + ($1 /*, ... */) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Bigint, long tokens with parenthesis, will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_bigint WHERE id IN + (abs(100), abs(200), abs(300), abs(400), abs(500), abs(600), abs(700), + abs(800), abs(900), abs(1000), ((abs(1100)))); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_bigint WHERE id = ANY(ARRAY[ + abs(100), abs(200), abs(300), abs(400), abs(500), abs(600), abs(700), + abs(800), abs(900), abs(1000), ((abs(1100)))]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------------------------------+------- + SELECT * FROM test_squash_bigint WHERE id IN +| 2 + (abs($1), abs($2), abs($3), abs($4), abs($5), abs($6), abs($7),+| + abs($8), abs($9), abs($10), ((abs($11)))) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Multiple FuncExpr's. Will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT WHERE 1 IN (1::int::bigint::int, 2::int::bigint::int); +-- +(1 row) + +SELECT WHERE 1 = ANY(ARRAY[1::int::bigint::int, 2::int::bigint::int]); +-- +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT WHERE $1 IN ($2 /*, ... */) | 2 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- +-- CoerceViaIO +-- +-- Create some dummy type to force CoerceViaIO +CREATE TYPE casttesttype; +CREATE FUNCTION casttesttype_in(cstring) + RETURNS casttesttype + AS 'textin' + LANGUAGE internal STRICT IMMUTABLE; +NOTICE: return type casttesttype is only a shell +CREATE FUNCTION casttesttype_out(casttesttype) + RETURNS cstring + AS 'textout' + LANGUAGE internal STRICT IMMUTABLE; +NOTICE: argument type casttesttype is only a shell +LINE 1: CREATE FUNCTION casttesttype_out(casttesttype) + ^ +CREATE TYPE casttesttype ( + internallength = variable, + input = casttesttype_in, + output = casttesttype_out, + alignment = int4 +); +CREATE CAST (int4 AS casttesttype) WITH INOUT; +CREATE FUNCTION casttesttype_eq(casttesttype, casttesttype) +returns boolean language sql immutable as $$ + SELECT true +$$; +CREATE OPERATOR = ( + leftarg = casttesttype, + rightarg = casttesttype, + procedure = casttesttype_eq, + commutator = =); +CREATE TABLE test_squash_cast (id int, data casttesttype); +-- Use the introduced type to construct a list of CoerceViaIO around Const +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_cast WHERE data IN + (1::int4::casttesttype, 2::int4::casttesttype, 3::int4::casttesttype, + 4::int4::casttesttype, 5::int4::casttesttype, 6::int4::casttesttype, + 7::int4::casttesttype, 8::int4::casttesttype, 9::int4::casttesttype, + 10::int4::casttesttype, 11::int4::casttesttype); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_cast WHERE data = ANY (ARRAY + [1::int4::casttesttype, 2::int4::casttesttype, 3::int4::casttesttype, + 4::int4::casttesttype, 5::int4::casttesttype, 6::int4::casttesttype, + 7::int4::casttesttype, 8::int4::casttesttype, 9::int4::casttesttype, + 10::int4::casttesttype, 11::int4::casttesttype]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT * FROM test_squash_cast WHERE data IN +| 2 + ($1 /*, ... */) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Some casting expression are simplified to Const +CREATE TABLE test_squash_jsonb (id int, data jsonb); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_jsonb WHERE data IN + (('"1"')::jsonb, ('"2"')::jsonb, ('"3"')::jsonb, ('"4"')::jsonb, + ('"5"')::jsonb, ('"6"')::jsonb, ('"7"')::jsonb, ('"8"')::jsonb, + ('"9"')::jsonb, ('"10"')::jsonb); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_jsonb WHERE data = ANY (ARRAY + [('"1"')::jsonb, ('"2"')::jsonb, ('"3"')::jsonb, ('"4"')::jsonb, + ('"5"')::jsonb, ('"6"')::jsonb, ('"7"')::jsonb, ('"8"')::jsonb, + ('"9"')::jsonb, ('"10"')::jsonb]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT * FROM test_squash_jsonb WHERE data IN +| 2 + ($1 /*, ... */) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- CoerceViaIO, SubLink instead of a Const. Will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT * FROM test_squash_jsonb WHERE data IN + ((SELECT '"1"')::jsonb, (SELECT '"2"')::jsonb, (SELECT '"3"')::jsonb, + (SELECT '"4"')::jsonb, (SELECT '"5"')::jsonb, (SELECT '"6"')::jsonb, + (SELECT '"7"')::jsonb, (SELECT '"8"')::jsonb, (SELECT '"9"')::jsonb, + (SELECT '"10"')::jsonb); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash_jsonb WHERE data = ANY(ARRAY + [(SELECT '"1"')::jsonb, (SELECT '"2"')::jsonb, (SELECT '"3"')::jsonb, + (SELECT '"4"')::jsonb, (SELECT '"5"')::jsonb, (SELECT '"6"')::jsonb, + (SELECT '"7"')::jsonb, (SELECT '"8"')::jsonb, (SELECT '"9"')::jsonb, + (SELECT '"10"')::jsonb]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +----------------------------------------------------------------------+------- + SELECT * FROM test_squash_jsonb WHERE data IN +| 2 + ((SELECT $1)::jsonb, (SELECT $2)::jsonb, (SELECT $3)::jsonb,+| + (SELECT $4)::jsonb, (SELECT $5)::jsonb, (SELECT $6)::jsonb,+| + (SELECT $7)::jsonb, (SELECT $8)::jsonb, (SELECT $9)::jsonb,+| + (SELECT $10)::jsonb) | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Multiple CoerceViaIO are squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +SELECT WHERE 1 IN (1::text::int::text::int, 1::text::int::text::int); +-- +(1 row) + +SELECT WHERE 1 = ANY(ARRAY[1::text::int::text::int, 1::text::int::text::int]); +-- +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT WHERE $1 IN ($2 /*, ... */) | 2 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- +-- RelabelType +-- +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +-- However many layers of RelabelType there are, the list will be squashable. +SELECT * FROM test_squash WHERE id IN + (1::oid, 2::oid, 3::oid, 4::oid, 5::oid, 6::oid, 7::oid, 8::oid, 9::oid); + id | data +----+------ +(0 rows) + +SELECT ARRAY[1::oid, 2::oid, 3::oid, 4::oid, 5::oid, 6::oid, 7::oid, 8::oid, 9::oid]; + array +--------------------- + {1,2,3,4,5,6,7,8,9} +(1 row) + +SELECT * FROM test_squash WHERE id IN (1::oid, 2::oid::int::oid); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::oid, 2::oid::int::oid]); + id | data +----+------ +(0 rows) + +-- RelabelType together with CoerceViaIO is also squashable +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::oid::text::int::oid, 2::oid::int::oid]); + id | data +----+------ +(0 rows) + +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::text::int::oid, 2::oid::int::oid]); + id | data +----+------ +(0 rows) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT * FROM test_squash WHERE id IN +| 5 + ($1 /*, ... */) | + SELECT ARRAY[$1 /*, ... */] | 1 + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(3 rows) + +-- +-- edge cases +-- +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +-- for nested arrays, only constants are squashed +SELECT ARRAY[ + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10] + ]; + array +----------------------------------------------------------------------------------------------- + {{1,2,3,4,5,6,7,8,9,10},{1,2,3,4,5,6,7,8,9,10},{1,2,3,4,5,6,7,8,9,10},{1,2,3,4,5,6,7,8,9,10}} +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT ARRAY[ +| 1 + ARRAY[$1 /*, ... */], +| + ARRAY[$2 /*, ... */], +| + ARRAY[$3 /*, ... */], +| + ARRAY[$4 /*, ... */] +| + ] | + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 +(2 rows) + +-- Test constants evaluation in a CTE, which was causing issues in the past +WITH cte AS ( + SELECT 'const' as const FROM test_squash +) +SELECT ARRAY['a', 'b', 'c', const::varchar] AS result +FROM cte; + result +-------- +(0 rows) + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +-- Rewritten as an OpExpr, so it will not be squashed +select where '1' IN ('1'::int, '2'::int::text); +-- +(1 row) + +-- Rewritten as an ArrayExpr, so it will be squashed +select where '1' IN ('1'::int, '2'::int); +-- +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 + select where $1 IN ($2 /*, ... */) | 1 + select where $1 IN ($2::int, $3::int::text) | 1 +(3 rows) + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + t +--- + t +(1 row) + +-- Both of these queries will be rewritten as an ArrayExpr, so they +-- will be squashed, and have a similar queryId +select where '1' IN ('1'::int::text, '2'::int::text); +-- +(1 row) + +select where '1' = ANY (array['1'::int::text, '2'::int::text]); +-- +(1 row) + +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + query | calls +-------------------------------------------------+------- + SELECT pg_stat_monitor_reset() IS NOT NULL AS t | 1 + select where $1 IN ($2 /*, ... */) | 2 +(2 rows) + +-- +-- cleanup +-- +DROP TABLE test_squash; +DROP TABLE test_float; +DROP TABLE test_squash_numeric; +DROP TABLE test_squash_bigint; +DROP TABLE test_squash_cast CASCADE; +DROP TABLE test_squash_jsonb; +SELECT pg_stat_monitor_reset(); + pg_stat_monitor_reset +----------------------- + +(1 row) + +DROP EXTENSION pg_stat_monitor; diff --git a/regression/sql/squashing.sql b/regression/sql/squashing.sql new file mode 100644 index 0000000..c519383 --- /dev/null +++ b/regression/sql/squashing.sql @@ -0,0 +1,312 @@ +-- +-- Const squashing functionality +-- + +SELECT setting::integer < 180000 AS skip_test FROM pg_settings where name = 'server_version_num' \gset +\if :skip_test +\quit +\endif + +CREATE EXTENSION pg_stat_monitor; +SET pg_stat_monitor.pgsm_normalized_query = TRUE; + +-- +-- Simple Lists +-- + +CREATE TABLE test_squash (id int, data int); + +-- single element will not be squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash WHERE id IN (1); +SELECT ARRAY[1]; +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- more than 1 element in a list will be squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash WHERE id IN (1, 2, 3); +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4); +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5); +SELECT ARRAY[1, 2, 3]; +SELECT ARRAY[1, 2, 3, 4]; +SELECT ARRAY[1, 2, 3, 4, 5]; +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- built-in functions will be squashed +-- the IN and ARRAY forms of this statement will have the same queryId +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT WHERE 1 IN (1, int4(1), int4(2), 2); +SELECT WHERE 1 = ANY (ARRAY[1, int4(1), int4(2), 2]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- This tests are disabled due bug in PGSM, see: https://perconadev.atlassian.net/browse/PG-1936 +-- -- external parameters will be squashed +-- SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- SELECT * FROM test_squash WHERE id IN ($1, $2, $3, $4, $5) \bind 1 2 3 4 5 +-- ; +-- SELECT * FROM test_squash WHERE id::text = ANY(ARRAY[$1, $2, $3, $4, $5]) \bind 1 2 3 4 5 +-- ; +-- SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- -- prepared statements will also be squashed +-- -- the IN and ARRAY forms of this statement will have the same queryId +-- SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- PREPARE p1(int, int, int, int, int) AS +-- SELECT * FROM test_squash WHERE id IN ($1, $2, $3, $4, $5); +-- EXECUTE p1(1, 2, 3, 4, 5); +-- DEALLOCATE p1; +-- PREPARE p1(int, int, int, int, int) AS +-- SELECT * FROM test_squash WHERE id = ANY(ARRAY[$1, $2, $3, $4, $5]); +-- EXECUTE p1(1, 2, 3, 4, 5); +-- DEALLOCATE p1; +-- SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C";SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- More conditions in the query +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9) AND data = 2; +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10) AND data = 2; +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11) AND data = 2; +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]) AND data = 2; +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) AND data = 2; +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]) AND data = 2; +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Multiple squashed intervals +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9); +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10); +SELECT * FROM test_squash WHERE id IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11) + AND data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9]); +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10]); +SELECT * FROM test_squash WHERE id = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]) + AND data = ANY (ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; + +-- No constants squashing for OpExpr +-- The IN and ARRAY forms of this statement will have the same queryId +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash WHERE id IN + (1 + 1, 2 + 2, 3 + 3, 4 + 4, 5 + 5, 6 + 6, 7 + 7, 8 + 8, 9 + 9); +SELECT * FROM test_squash WHERE id IN + (@ '-1', @ '-2', @ '-3', @ '-4', @ '-5', @ '-6', @ '-7', @ '-8', @ '-9'); +SELECT * FROM test_squash WHERE id = ANY(ARRAY + [1 + 1, 2 + 2, 3 + 3, 4 + 4, 5 + 5, 6 + 6, 7 + 7, 8 + 8, 9 + 9]); +SELECT * FROM test_squash WHERE id = ANY(ARRAY + [@ '-1', @ '-2', @ '-3', @ '-4', @ '-5', @ '-6', @ '-7', @ '-8', @ '-9']); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- +-- FuncExpr +-- + +-- Verify multiple type representation end up with the same query_id +CREATE TABLE test_float (data float); +-- The casted ARRAY expressions will have the same queryId as the IN clause +-- form of the query +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT data FROM test_float WHERE data IN (1, 2); +SELECT data FROM test_float WHERE data IN (1, '2'); +SELECT data FROM test_float WHERE data IN ('1', 2); +SELECT data FROM test_float WHERE data IN ('1', '2'); +SELECT data FROM test_float WHERE data IN (1.0, 1.0); +SELECT data FROM test_float WHERE data = ANY(ARRAY['1'::double precision, '2'::double precision]); +SELECT data FROM test_float WHERE data = ANY(ARRAY[1.0::double precision, 1.0::double precision]); +SELECT data FROM test_float WHERE data = ANY(ARRAY[1, 2]); +SELECT data FROM test_float WHERE data = ANY(ARRAY[1, '2']); +SELECT data FROM test_float WHERE data = ANY(ARRAY['1', 2]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Numeric type, implicit cast is squashed +CREATE TABLE test_squash_numeric (id int, data numeric(5, 2)); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_numeric WHERE data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); +SELECT * FROM test_squash_numeric WHERE data = ANY(ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Bigint, implicit cast is squashed +CREATE TABLE test_squash_bigint (id int, data bigint); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_bigint WHERE data IN (1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11); +SELECT * FROM test_squash_bigint WHERE data = ANY(ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10, 11]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Bigint, explicit cast is squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_bigint WHERE data IN + (1::bigint, 2::bigint, 3::bigint, 4::bigint, 5::bigint, 6::bigint, + 7::bigint, 8::bigint, 9::bigint, 10::bigint, 11::bigint); +SELECT * FROM test_squash_bigint WHERE data = ANY(ARRAY[ + 1::bigint, 2::bigint, 3::bigint, 4::bigint, 5::bigint, 6::bigint, + 7::bigint, 8::bigint, 9::bigint, 10::bigint, 11::bigint]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Bigint, long tokens with parenthesis, will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_bigint WHERE id IN + (abs(100), abs(200), abs(300), abs(400), abs(500), abs(600), abs(700), + abs(800), abs(900), abs(1000), ((abs(1100)))); +SELECT * FROM test_squash_bigint WHERE id = ANY(ARRAY[ + abs(100), abs(200), abs(300), abs(400), abs(500), abs(600), abs(700), + abs(800), abs(900), abs(1000), ((abs(1100)))]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Multiple FuncExpr's. Will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT WHERE 1 IN (1::int::bigint::int, 2::int::bigint::int); +SELECT WHERE 1 = ANY(ARRAY[1::int::bigint::int, 2::int::bigint::int]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- +-- CoerceViaIO +-- + +-- Create some dummy type to force CoerceViaIO +CREATE TYPE casttesttype; + +CREATE FUNCTION casttesttype_in(cstring) + RETURNS casttesttype + AS 'textin' + LANGUAGE internal STRICT IMMUTABLE; + +CREATE FUNCTION casttesttype_out(casttesttype) + RETURNS cstring + AS 'textout' + LANGUAGE internal STRICT IMMUTABLE; + +CREATE TYPE casttesttype ( + internallength = variable, + input = casttesttype_in, + output = casttesttype_out, + alignment = int4 +); + +CREATE CAST (int4 AS casttesttype) WITH INOUT; + +CREATE FUNCTION casttesttype_eq(casttesttype, casttesttype) +returns boolean language sql immutable as $$ + SELECT true +$$; + +CREATE OPERATOR = ( + leftarg = casttesttype, + rightarg = casttesttype, + procedure = casttesttype_eq, + commutator = =); + +CREATE TABLE test_squash_cast (id int, data casttesttype); + +-- Use the introduced type to construct a list of CoerceViaIO around Const +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_cast WHERE data IN + (1::int4::casttesttype, 2::int4::casttesttype, 3::int4::casttesttype, + 4::int4::casttesttype, 5::int4::casttesttype, 6::int4::casttesttype, + 7::int4::casttesttype, 8::int4::casttesttype, 9::int4::casttesttype, + 10::int4::casttesttype, 11::int4::casttesttype); +SELECT * FROM test_squash_cast WHERE data = ANY (ARRAY + [1::int4::casttesttype, 2::int4::casttesttype, 3::int4::casttesttype, + 4::int4::casttesttype, 5::int4::casttesttype, 6::int4::casttesttype, + 7::int4::casttesttype, 8::int4::casttesttype, 9::int4::casttesttype, + 10::int4::casttesttype, 11::int4::casttesttype]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Some casting expression are simplified to Const +CREATE TABLE test_squash_jsonb (id int, data jsonb); +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_jsonb WHERE data IN + (('"1"')::jsonb, ('"2"')::jsonb, ('"3"')::jsonb, ('"4"')::jsonb, + ('"5"')::jsonb, ('"6"')::jsonb, ('"7"')::jsonb, ('"8"')::jsonb, + ('"9"')::jsonb, ('"10"')::jsonb); +SELECT * FROM test_squash_jsonb WHERE data = ANY (ARRAY + [('"1"')::jsonb, ('"2"')::jsonb, ('"3"')::jsonb, ('"4"')::jsonb, + ('"5"')::jsonb, ('"6"')::jsonb, ('"7"')::jsonb, ('"8"')::jsonb, + ('"9"')::jsonb, ('"10"')::jsonb]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- CoerceViaIO, SubLink instead of a Const. Will not squash +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT * FROM test_squash_jsonb WHERE data IN + ((SELECT '"1"')::jsonb, (SELECT '"2"')::jsonb, (SELECT '"3"')::jsonb, + (SELECT '"4"')::jsonb, (SELECT '"5"')::jsonb, (SELECT '"6"')::jsonb, + (SELECT '"7"')::jsonb, (SELECT '"8"')::jsonb, (SELECT '"9"')::jsonb, + (SELECT '"10"')::jsonb); +SELECT * FROM test_squash_jsonb WHERE data = ANY(ARRAY + [(SELECT '"1"')::jsonb, (SELECT '"2"')::jsonb, (SELECT '"3"')::jsonb, + (SELECT '"4"')::jsonb, (SELECT '"5"')::jsonb, (SELECT '"6"')::jsonb, + (SELECT '"7"')::jsonb, (SELECT '"8"')::jsonb, (SELECT '"9"')::jsonb, + (SELECT '"10"')::jsonb]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Multiple CoerceViaIO are squashed +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +SELECT WHERE 1 IN (1::text::int::text::int, 1::text::int::text::int); +SELECT WHERE 1 = ANY(ARRAY[1::text::int::text::int, 1::text::int::text::int]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- +-- RelabelType +-- + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- However many layers of RelabelType there are, the list will be squashable. +SELECT * FROM test_squash WHERE id IN + (1::oid, 2::oid, 3::oid, 4::oid, 5::oid, 6::oid, 7::oid, 8::oid, 9::oid); +SELECT ARRAY[1::oid, 2::oid, 3::oid, 4::oid, 5::oid, 6::oid, 7::oid, 8::oid, 9::oid]; +SELECT * FROM test_squash WHERE id IN (1::oid, 2::oid::int::oid); +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::oid, 2::oid::int::oid]); +-- RelabelType together with CoerceViaIO is also squashable +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::oid::text::int::oid, 2::oid::int::oid]); +SELECT * FROM test_squash WHERE id = ANY(ARRAY[1::text::int::oid, 2::oid::int::oid]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- +-- edge cases +-- + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- for nested arrays, only constants are squashed +SELECT ARRAY[ + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10], + ARRAY[1, 2, 3, 4, 5, 6, 7, 8, 9, 10] + ]; +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- Test constants evaluation in a CTE, which was causing issues in the past +WITH cte AS ( + SELECT 'const' as const FROM test_squash +) +SELECT ARRAY['a', 'b', 'c', const::varchar] AS result +FROM cte; + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- Rewritten as an OpExpr, so it will not be squashed +select where '1' IN ('1'::int, '2'::int::text); +-- Rewritten as an ArrayExpr, so it will be squashed +select where '1' IN ('1'::int, '2'::int); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +SELECT pg_stat_monitor_reset() IS NOT NULL AS t; +-- Both of these queries will be rewritten as an ArrayExpr, so they +-- will be squashed, and have a similar queryId +select where '1' IN ('1'::int::text, '2'::int::text); +select where '1' = ANY (array['1'::int::text, '2'::int::text]); +SELECT query, calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; + +-- +-- cleanup +-- +DROP TABLE test_squash; +DROP TABLE test_float; +DROP TABLE test_squash_numeric; +DROP TABLE test_squash_bigint; +DROP TABLE test_squash_cast CASCADE; +DROP TABLE test_squash_jsonb; +SELECT pg_stat_monitor_reset(); +DROP EXTENSION pg_stat_monitor;