-
Notifications
You must be signed in to change notification settings - Fork 59
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
PG -156: replace query placeholders with actual arguments for prepare…
…d statements (#481) * Denormalize prepared statement queries Added support for extracting query arguments for prepared statements when `pg_stat_monitor.pgsm_normalized_query` is off. Previously pg_stat_monitor was unable to extract the arguments for prepared statements, thus leaving queries with placeholders $1 .. $N instead of the actual arguments. * Optmize query denormalization Instead of copying original query text byte by byte, copy data between query placeholders in chunks, example: `INSERT INTO foo(a, b, c) VALUES('test', 100, 'test again)'` Would result in normalized query: `INSERT INTO foo(a, b, c) VALUES($1, $2, $3)` The original patch would copy the parts between placeholders byte by byte, e.g. `INSERT INTO foo(a, b, c) VALUES(`, instead we can copy this whole block at once, 1 function call and maybe 1 buffer re-allocation per call. Also make use of `appendBinaryStringInfo` to avoid calculating string length as we have this info already. * Optmize query denormalization(2) Avoid allocating an array of strings for extracting query argument values, instead append the current parameter value directly in the buffer used to store the denormalized query. This avoids not only unnecessary memory allocations, but also copying data between temporary memory and the buffer. * Store denormalized query only under certain constraints This commit introduces a little optimization along with a feature, it stores the query in denormalized form only under the circumstances below: - The psgm_normalized_query GUC is disabled (off). - The query is seem for the first time, or the query total execution time exceeds the mean execution time calculated for the previous queries. Having the query which took most execution time along with it's arguments could help users in further investigating performance issues. * Fix regression tests When query normalization is disabled utility queries like SELECT 10+20 are now stored as is, instead of SELECT $1+$2. Also when functions or sub queries are created the arguments used internally by the function or subqueries will be replaced by NULL instead of $1..$N. The actual arguments will be displayed when the function or subquery is actually invoked. * Add query denormalization regression test for prepared statements Ensures that the denormalization of prepared statements is working, also ensure that a query which takes more time to execute replaces the previous denormalized query. * Updated pgsm_query_id regression tests With the query dernomalization feature, having integer literals used in sql like 1, or 2 could create some confusion on whether those are placeholders or constant values, thus this commit updates the pgsm_query_id regression test to use different integer literals to avoid confusion. * Improve query denormalization regression test Add a new test case: 1. Execute a prepared statement with larger execution time first. 2. Execute the same prepared statement with cheap execution time. 3. Ensures that the denormalized heavy query is not replaced by the cheaper. * Format source using pgindent * Fix top query regression tests on PG 12,13 On PG 12, 13, the internal return instruction in the following function: ``` CREATE OR REPLACE FUNCTION add(int, int) RETURNS INTEGER AS $$ BEGIN return (select $1 + $2); END; $$ language plpgsql; ``` Is stored as SELECT (select expr1 + expr2) On PG 14 onward it's stored just as SELECT (expr1 + expr2)
- Loading branch information
1 parent
467394f
commit c921d48
Showing
9 changed files
with
275 additions
and
22 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
@@ -0,0 +1,63 @@ | ||
CREATE EXTENSION pg_stat_monitor; | ||
Set pg_stat_monitor.pgsm_normalized_query='off'; | ||
CREATE TABLE t1 (a TEXT, b TEXT, c TEXT); | ||
SELECT pg_stat_monitor_reset(); | ||
pg_stat_monitor_reset | ||
----------------------- | ||
|
||
(1 row) | ||
|
||
-- First test, execute cheap query then heavy query. | ||
-- Ensure denormalized heavy query replaces the cheaper one. | ||
PREPARE prepstmt(TEXT, TEXT, TEXT) AS INSERT INTO t1(a, b, c) VALUES($1, $2, $3); | ||
EXECUTE prepstmt('A', 'B', 'C'); | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; | ||
substring | calls | ||
--------------------------------------------------------------------------------+------- | ||
PREPARE prepstmt(TEXT, TEXT, TEXT) AS INSERT INTO t1(a, b, c) VALUES(A, B, C); | 1 | ||
SELECT pg_stat_monitor_reset() | 1 | ||
(2 rows) | ||
|
||
EXECUTE prepstmt(REPEAT('XYZ', 8192), md5(random()::text), REPEAT('RANDOM', 4096)); | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; | ||
substring | calls | ||
---------------------------------------------------------------------------------------------------------------------------------+------- | ||
PREPARE prepstmt(TEXT, TEXT, TEXT) AS INSERT INTO t1(a, b, c) VALUES(XYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZX | 2 | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C" | 1 | ||
SELECT pg_stat_monitor_reset() | 1 | ||
(3 rows) | ||
|
||
TRUNCATE TABLE t1; | ||
SELECT pg_stat_monitor_reset(); | ||
pg_stat_monitor_reset | ||
----------------------- | ||
|
||
(1 row) | ||
|
||
-- Second test, execute heavy query then cheap query. | ||
-- Ensure denormalized heavy query is not replaced by the cheaper one. | ||
EXECUTE prepstmt(REPEAT('XYZ', 8192), md5(random()::text), REPEAT('RANDOM', 4096)); | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; | ||
substring | calls | ||
---------------------------------------------------------------------------------------------------------------------------------+------- | ||
PREPARE prepstmt(TEXT, TEXT, TEXT) AS INSERT INTO t1(a, b, c) VALUES(XYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZX | 1 | ||
SELECT pg_stat_monitor_reset() | 1 | ||
(2 rows) | ||
|
||
EXECUTE prepstmt('A', 'B', 'C'); | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C"; | ||
substring | calls | ||
---------------------------------------------------------------------------------------------------------------------------------+------- | ||
PREPARE prepstmt(TEXT, TEXT, TEXT) AS INSERT INTO t1(a, b, c) VALUES(XYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZXYZX | 2 | ||
SELECT SUBSTRING(query, 0, 128), calls FROM pg_stat_monitor ORDER BY query COLLATE "C" | 1 | ||
SELECT pg_stat_monitor_reset() | 1 | ||
(3 rows) | ||
|
||
DROP TABLE t1; | ||
SELECT pg_stat_monitor_reset(); | ||
pg_stat_monitor_reset | ||
----------------------- | ||
|
||
(1 row) | ||
|
||
DROP EXTENSION pg_stat_monitor; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Oops, something went wrong.