mirror of
https://github.com/postgres/postgres.git
synced 2025-04-22 23:02:54 +03:00
Make use of the statement boundary info added by commit ab1f0c822 to let pg_stat_statements behave more sanely when multiple SQL queries are jammed into one query string. It now records just the relevant part of the source string, not the whole thing, for each individual query. Even when no multi-statement strings are involved, users may notice small changes in the output: leading and trailing whitespace and semicolons will be stripped from statements, which did not happen before. Also, significantly expand pg_stat_statements' regression test script. Fabien Coelho, reviewed by Craig Ringer and Kyotaro Horiguchi, some mods by me Discussion: https://postgr.es/m/alpine.DEB.2.20.1612200926310.29821@lancre
185 lines
3.9 KiB
PL/PgSQL
185 lines
3.9 KiB
PL/PgSQL
CREATE EXTENSION pg_stat_statements;
|
|
|
|
--
|
|
-- simple and compound statements
|
|
--
|
|
SET pg_stat_statements.track_utility = FALSE;
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
SELECT 1 AS "int";
|
|
|
|
SELECT 'hello'
|
|
-- multiline
|
|
AS "text";
|
|
|
|
SELECT 'world' AS "text";
|
|
|
|
-- transaction
|
|
BEGIN;
|
|
SELECT 1 AS "int";
|
|
SELECT 'hello' AS "text";
|
|
COMMIT;
|
|
|
|
-- compound transaction
|
|
BEGIN \;
|
|
SELECT 2.0 AS "float" \;
|
|
SELECT 'world' AS "text" \;
|
|
COMMIT;
|
|
|
|
-- compound with empty statements and spurious leading spacing
|
|
\;\; SELECT 3 + 3 \;\;\; SELECT ' ' || ' !' \;\; SELECT 1 + 4 \;;
|
|
|
|
-- non ;-terminated statements
|
|
SELECT 1 + 1 + 1 AS "add" \gset
|
|
SELECT :add + 1 + 1 AS "add" \;
|
|
SELECT :add + 1 + 1 AS "add" \gset
|
|
|
|
-- set operator
|
|
SELECT 1 AS i UNION SELECT 2 ORDER BY i;
|
|
|
|
-- cte
|
|
WITH t(f) AS (
|
|
VALUES (1.0), (2.0)
|
|
)
|
|
SELECT f FROM t ORDER BY f;
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
--
|
|
-- CRUD: INSERT SELECT UPDATE DELETE on test table
|
|
--
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
-- utility "create table" should not be shown
|
|
CREATE TABLE test (a int, b char(20));
|
|
|
|
INSERT INTO test VALUES(generate_series(1, 10), 'aaa');
|
|
UPDATE test SET b = 'bbb' WHERE a > 7;
|
|
DELETE FROM test WHERE a > 9;
|
|
|
|
-- explicit transaction
|
|
BEGIN;
|
|
UPDATE test SET b = '111' WHERE a = 1 ;
|
|
COMMIT;
|
|
|
|
BEGIN \;
|
|
UPDATE test SET b = '222' WHERE a = 2 \;
|
|
COMMIT ;
|
|
|
|
UPDATE test SET b = '333' WHERE a = 3 \;
|
|
UPDATE test SET b = '444' WHERE a = 4 ;
|
|
|
|
BEGIN \;
|
|
UPDATE test SET b = '555' WHERE a = 5 \;
|
|
UPDATE test SET b = '666' WHERE a = 6 \;
|
|
COMMIT ;
|
|
|
|
-- SELECT with constants
|
|
SELECT * FROM test WHERE a > 5 ORDER BY a ;
|
|
|
|
SELECT *
|
|
FROM test
|
|
WHERE a > 9
|
|
ORDER BY a ;
|
|
|
|
-- SELECT without constants
|
|
SELECT * FROM test ORDER BY a;
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
--
|
|
-- pg_stat_statements.track = none
|
|
--
|
|
SET pg_stat_statements.track = 'none';
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
SELECT 1 AS "one";
|
|
SELECT 1 + 1 AS "two";
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
--
|
|
-- pg_stat_statements.track = top
|
|
--
|
|
SET pg_stat_statements.track = 'top';
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
DO LANGUAGE plpgsql $$
|
|
BEGIN
|
|
-- this is a SELECT
|
|
PERFORM 'hello world'::TEXT;
|
|
END;
|
|
$$;
|
|
|
|
-- PL/pgSQL function
|
|
CREATE FUNCTION PLUS_TWO(i INTEGER) RETURNS INTEGER AS $$
|
|
DECLARE
|
|
r INTEGER;
|
|
BEGIN
|
|
SELECT (i + 1 + 1.0)::INTEGER INTO r;
|
|
RETURN r;
|
|
END; $$ LANGUAGE plpgsql;
|
|
|
|
SELECT PLUS_TWO(3);
|
|
SELECT PLUS_TWO(7);
|
|
|
|
-- SQL function --- use LIMIT to keep it from being inlined
|
|
CREATE FUNCTION PLUS_ONE(i INTEGER) RETURNS INTEGER AS
|
|
$$ SELECT (i + 1.0)::INTEGER LIMIT 1 $$ LANGUAGE SQL;
|
|
|
|
SELECT PLUS_ONE(8);
|
|
SELECT PLUS_ONE(10);
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
--
|
|
-- pg_stat_statements.track = all
|
|
--
|
|
SET pg_stat_statements.track = 'all';
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
-- we drop and recreate the functions to avoid any caching funnies
|
|
DROP FUNCTION PLUS_ONE(INTEGER);
|
|
DROP FUNCTION PLUS_TWO(INTEGER);
|
|
|
|
-- PL/pgSQL function
|
|
CREATE FUNCTION PLUS_TWO(i INTEGER) RETURNS INTEGER AS $$
|
|
DECLARE
|
|
r INTEGER;
|
|
BEGIN
|
|
SELECT (i + 1 + 1.0)::INTEGER INTO r;
|
|
RETURN r;
|
|
END; $$ LANGUAGE plpgsql;
|
|
|
|
SELECT PLUS_TWO(-1);
|
|
SELECT PLUS_TWO(2);
|
|
|
|
-- SQL function --- use LIMIT to keep it from being inlined
|
|
CREATE FUNCTION PLUS_ONE(i INTEGER) RETURNS INTEGER AS
|
|
$$ SELECT (i + 1.0)::INTEGER LIMIT 1 $$ LANGUAGE SQL;
|
|
|
|
SELECT PLUS_ONE(3);
|
|
SELECT PLUS_ONE(1);
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
--
|
|
-- utility commands
|
|
--
|
|
SET pg_stat_statements.track_utility = TRUE;
|
|
SELECT pg_stat_statements_reset();
|
|
|
|
SELECT 1;
|
|
CREATE INDEX test_b ON test(b);
|
|
DROP TABLE test \;
|
|
DROP TABLE IF EXISTS test \;
|
|
DROP FUNCTION PLUS_ONE(INTEGER);
|
|
DROP TABLE IF EXISTS test \;
|
|
DROP TABLE IF EXISTS test \;
|
|
DROP FUNCTION IF EXISTS PLUS_ONE(INTEGER);
|
|
DROP FUNCTION PLUS_TWO(INTEGER);
|
|
|
|
SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
|
|
|
|
DROP EXTENSION pg_stat_statements;
|