CREATE EXTENSION pg_stat_statements;
-CREATE TABLE test (a int, b char(20));
--- test the basic functionality of pg_stat_statements
+--
+-- simple and compound statements
+--
+SET pg_stat_statements.track_utility = FALSE;
SELECT pg_stat_statements_reset();
pg_stat_statements_reset
--------------------------
(1 row)
+SELECT 1 AS "int";
+ int
+-----
+ 1
+(1 row)
+
+SELECT 'hello'
+ -- multiline
+ AS "text";
+ text
+-------
+ hello
+(1 row)
+
+SELECT 'world' AS "text";
+ text
+-------
+ world
+(1 row)
+
+-- transaction
+BEGIN;
+SELECT 1 AS "int";
+ int
+-----
+ 1
+(1 row)
+
+SELECT 'hello' AS "text";
+ text
+-------
+ hello
+(1 row)
+
+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 \;;
+ ?column?
+----------
+ 5
+(1 row)
+
+-- 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;
+ i
+---
+ 1
+ 2
+(2 rows)
+
+-- cte
+WITH t(f) AS (
+ VALUES (1.0), (2.0)
+)
+ SELECT f FROM t ORDER BY f;
+ f
+-----
+ 1.0
+ 2.0
+(2 rows)
+
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+-----------------------------------------+-------+------
+ SELECT ? +| 4 | 4
+ +| |
+ AS "text" | |
+ SELECT ? + ? | 2 | 2
+ SELECT ? + ? + ? AS "add" | 3 | 3
+ SELECT ? AS "float" | 1 | 1
+ SELECT ? AS "int" | 2 | 2
+ SELECT ? AS i UNION SELECT ? ORDER BY i | 1 | 2
+ SELECT ? || ? | 1 | 1
+ SELECT pg_stat_statements_reset() | 1 | 1
+ WITH t(f) AS ( +| 1 | 2
+ VALUES (?), (?) +| |
+ ) +| |
+ SELECT f FROM t ORDER BY f | |
+(9 rows)
+
+--
+-- CRUD: INSERT SELECT UPDATE DELETE on test table
+--
+SELECT pg_stat_statements_reset();
+ pg_stat_statements_reset
+--------------------------
+
+(1 row)
+
+-- 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 > 5;
-SELECT query, calls, rows from pg_stat_statements ORDER BY rows;
- query | calls | rows
-----------------------------------------------------+-------+------
- SELECT pg_stat_statements_reset(); | 1 | 1
- UPDATE test SET b = ? WHERE a > ?; | 1 | 5
- INSERT INTO test VALUES(generate_series(?, ?), ?); | 1 | 10
-(3 rows)
-
-DROP TABLE test;
+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 ;
+ a | b
+---+----------------------
+ 6 | 666
+ 7 | aaa
+ 8 | bbb
+ 9 | bbb
+(4 rows)
+
+SELECT *
+ FROM test
+ WHERE a > 9
+ ORDER BY a ;
+ a | b
+---+---
+(0 rows)
+
+-- SELECT without constants
+SELECT * FROM test ORDER BY a;
+ a | b
+---+----------------------
+ 1 | 111
+ 2 | 222
+ 3 | 333
+ 4 | 444
+ 5 | 555
+ 6 | 666
+ 7 | aaa
+ 8 | bbb
+ 9 | bbb
+(9 rows)
+
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+---------------------------------------------------+-------+------
+ DELETE FROM test WHERE a > ? | 1 | 1
+ INSERT INTO test VALUES(generate_series(?, ?), ?) | 1 | 10
+ SELECT * FROM test ORDER BY a | 1 | 9
+ SELECT * FROM test WHERE a > ? ORDER BY a | 2 | 4
+ SELECT pg_stat_statements_reset() | 1 | 1
+ UPDATE test SET b = ? WHERE a = ? | 6 | 6
+ UPDATE test SET b = ? WHERE a > ? | 1 | 3
+(7 rows)
+
+--
+-- pg_stat_statements.track = none
+--
+SET pg_stat_statements.track = 'none';
+SELECT pg_stat_statements_reset();
+ pg_stat_statements_reset
+--------------------------
+
+(1 row)
+
+SELECT 1 AS "one";
+ one
+-----
+ 1
+(1 row)
+
+SELECT 1 + 1 AS "two";
+ two
+-----
+ 2
+(1 row)
+
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+-------+-------+------
+(0 rows)
+
+--
+-- pg_stat_statements.track = top
+--
+SET pg_stat_statements.track = 'top';
+SELECT pg_stat_statements_reset();
+ pg_stat_statements_reset
+--------------------------
+
+(1 row)
+
+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);
+ plus_two
+----------
+ 5
+(1 row)
+
+SELECT PLUS_TWO(7);
+ plus_two
+----------
+ 9
+(1 row)
+
+-- 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);
+ plus_one
+----------
+ 9
+(1 row)
+
+SELECT PLUS_ONE(10);
+ plus_one
+----------
+ 11
+(1 row)
+
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+-----------------------------------+-------+------
+ SELECT ?::TEXT | 1 | 1
+ SELECT PLUS_ONE(?) | 2 | 2
+ SELECT PLUS_TWO(?) | 2 | 2
+ SELECT pg_stat_statements_reset() | 1 | 1
+(4 rows)
+
+--
+-- pg_stat_statements.track = all
+--
+SET pg_stat_statements.track = 'all';
+SELECT pg_stat_statements_reset();
+ pg_stat_statements_reset
+--------------------------
+
+(1 row)
+
+-- 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);
+ plus_two
+----------
+ 1
+(1 row)
+
+SELECT PLUS_TWO(2);
+ plus_two
+----------
+ 4
+(1 row)
+
+-- 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);
+ plus_one
+----------
+ 4
+(1 row)
+
+SELECT PLUS_ONE(1);
+ plus_one
+----------
+ 2
+(1 row)
+
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+-----------------------------------+-------+------
+ SELECT (i + ? + ?)::INTEGER | 2 | 2
+ SELECT (i + ?)::INTEGER LIMIT ? | 2 | 2
+ SELECT PLUS_ONE(?) | 2 | 2
+ SELECT PLUS_TWO(?) | 2 | 2
+ SELECT pg_stat_statements_reset() | 1 | 1
+(5 rows)
+
+--
+-- utility commands
+--
+SET pg_stat_statements.track_utility = TRUE;
+SELECT pg_stat_statements_reset();
+ pg_stat_statements_reset
+--------------------------
+
+(1 row)
+
+SELECT 1;
+ ?column?
+----------
+ 1
+(1 row)
+
+CREATE INDEX test_b ON test(b);
+DROP TABLE test \;
+DROP TABLE IF EXISTS test \;
+DROP FUNCTION PLUS_ONE(INTEGER);
+NOTICE: table "test" does not exist, skipping
+DROP TABLE IF EXISTS test \;
+DROP TABLE IF EXISTS test \;
+DROP FUNCTION IF EXISTS PLUS_ONE(INTEGER);
+NOTICE: table "test" does not exist, skipping
+NOTICE: table "test" does not exist, skipping
+NOTICE: function plus_one(pg_catalog.int4) does not exist, skipping
+DROP FUNCTION PLUS_TWO(INTEGER);
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
+ query | calls | rows
+-------------------------------------------+-------+------
+ CREATE INDEX test_b ON test(b) | 1 | 0
+ DROP FUNCTION IF EXISTS PLUS_ONE(INTEGER) | 1 | 0
+ DROP FUNCTION PLUS_ONE(INTEGER) | 1 | 0
+ DROP FUNCTION PLUS_TWO(INTEGER) | 1 | 0
+ DROP TABLE IF EXISTS test | 3 | 0
+ DROP TABLE test | 1 | 0
+ SELECT ? | 1 | 1
+ SELECT pg_stat_statements_reset() | 1 | 1
+(8 rows)
+
DROP EXTENSION pg_stat_statements;
#include "parser/analyze.h"
#include "parser/parsetree.h"
#include "parser/scanner.h"
+#include "parser/scansup.h"
#include "pgstat.h"
#include "storage/fd.h"
#include "storage/ipc.h"
DestReceiver *dest, char *completionTag);
static uint32 pgss_hash_fn(const void *key, Size keysize);
static int pgss_match_fn(const void *key1, const void *key2, Size keysize);
-static uint32 pgss_hash_string(const char *str);
+static uint32 pgss_hash_string(const char *str, int len);
static void pgss_store(const char *query, uint32 queryId,
+ int query_location, int query_len,
double total_time, uint64 rows,
const BufferUsage *bufusage,
pgssJumbleState *jstate);
static void JumbleExpr(pgssJumbleState *jstate, Node *node);
static void RecordConstLocation(pgssJumbleState *jstate, int location);
static char *generate_normalized_query(pgssJumbleState *jstate, const char *query,
- int *query_len_p, int encoding);
-static void fill_in_constant_lengths(pgssJumbleState *jstate, const char *query);
+ int query_loc, int *query_len_p, int encoding);
+static void fill_in_constant_lengths(pgssJumbleState *jstate, const char *query,
+ int query_loc);
static int comp_location(const void *a, const void *b);
if (jstate.clocations_count > 0)
pgss_store(pstate->p_sourcetext,
query->queryId,
+ query->stmt_location,
+ query->stmt_len,
0,
0,
NULL,
pgss_store(queryDesc->sourceText,
queryId,
+ queryDesc->plannedstmt->stmt_location,
+ queryDesc->plannedstmt->stmt_len,
queryDesc->totaltime->total * 1000.0, /* convert to msec */
queryDesc->estate->es_processed,
&queryDesc->totaltime->bufusage,
uint64 rows;
BufferUsage bufusage_start,
bufusage;
- uint32 queryId;
bufusage_start = pgBufferUsage;
INSTR_TIME_SET_CURRENT(start);
bufusage.blk_write_time = pgBufferUsage.blk_write_time;
INSTR_TIME_SUBTRACT(bufusage.blk_write_time, bufusage_start.blk_write_time);
- /* For utility statements, we just hash the query string directly */
- queryId = pgss_hash_string(queryString);
-
pgss_store(queryString,
- queryId,
+ 0, /* signal that it's a utility stmt */
+ pstmt->stmt_location,
+ pstmt->stmt_len,
INSTR_TIME_GET_MILLISEC(duration),
rows,
&bufusage,
* utility statements.
*/
static uint32
-pgss_hash_string(const char *str)
+pgss_hash_string(const char *str, int len)
{
- return hash_any((const unsigned char *) str, strlen(str));
+ return hash_any((const unsigned char *) str, len);
}
/*
* Store some statistics for a statement.
*
+ * If queryId is 0 then this is a utility statement and we should compute
+ * a suitable queryId internally.
+ *
* If jstate is not NULL then we're trying to create an entry for which
* we have no statistics as yet; we just want to record the normalized
* query string. total_time, rows, bufusage are ignored in this case.
*/
static void
pgss_store(const char *query, uint32 queryId,
+ int query_location, int query_len,
double total_time, uint64 rows,
const BufferUsage *bufusage,
pgssJumbleState *jstate)
pgssEntry *entry;
char *norm_query = NULL;
int encoding = GetDatabaseEncoding();
- int query_len;
Assert(query != NULL);
if (!pgss || !pgss_hash)
return;
- query_len = strlen(query);
+ /*
+ * Confine our attention to the relevant part of the string, if the query
+ * is a portion of a multi-statement source string.
+ *
+ * First apply starting offset, unless it's -1 (unknown).
+ */
+ if (query_location >= 0)
+ {
+ Assert(query_location <= strlen(query));
+ query += query_location;
+ /* Length of 0 (or -1) means "rest of string" */
+ if (query_len <= 0)
+ query_len = strlen(query);
+ else
+ Assert(query_len <= strlen(query));
+ }
+ else
+ {
+ /* If query location is unknown, distrust query_len as well */
+ query_location = 0;
+ query_len = strlen(query);
+ }
+
+ /*
+ * Discard leading and trailing whitespace, too. Use scanner_isspace()
+ * not libc's isspace(), because we want to match the lexer's behavior.
+ */
+ while (query_len > 0 && scanner_isspace(query[0]))
+ query++, query_location++, query_len--;
+ while (query_len > 0 && scanner_isspace(query[query_len - 1]))
+ query_len--;
+
+ /*
+ * For utility statements, we just hash the query string to get an ID.
+ */
+ if (queryId == 0)
+ queryId = pgss_hash_string(query, query_len);
/* Set up key for hashtable search */
key.userid = GetUserId();
{
LWLockRelease(pgss->lock);
norm_query = generate_normalized_query(jstate, query,
+ query_location,
&query_len,
encoding);
LWLockAcquire(pgss->lock, LW_SHARED);
}
/*
- * Given a null-terminated string, allocate a new entry in the external query
- * text file and store the string there.
- *
- * Although we could compute the string length via strlen(), callers already
- * have it handy, so we require them to pass it too.
+ * Given a query string (not necessarily null-terminated), allocate a new
+ * entry in the external query text file and store the string there.
*
* If successful, returns true, and stores the new entry's offset in the file
* into *query_offset. Also, if gc_count isn't NULL, *gc_count is set to the
if (lseek(fd, off, SEEK_SET) != off)
goto error;
- if (write(fd, query, query_len + 1) != query_len + 1)
+ if (write(fd, query, query_len) != query_len)
+ goto error;
+ if (write(fd, "\0", 1) != 1)
goto error;
CloseTransientFile(fd);
* just which "equivalent" query is used to create the hashtable entry.
* We assume this is OK.
*
+ * If query_loc > 0, then "query" has been advanced by that much compared to
+ * the original string start, so we need to translate the provided locations
+ * to compensate. (This lets us avoid re-scanning statements before the one
+ * of interest, so it's worth doing.)
+ *
* *query_len_p contains the input string length, and is updated with
* the result string length (which cannot be longer) on exit.
*
*/
static char *
generate_normalized_query(pgssJumbleState *jstate, const char *query,
- int *query_len_p, int encoding)
+ int query_loc, int *query_len_p, int encoding)
{
char *norm_query;
int query_len = *query_len_p;
* Get constants' lengths (core system only gives us locations). Note
* this also ensures the items are sorted by location.
*/
- fill_in_constant_lengths(jstate, query);
+ fill_in_constant_lengths(jstate, query, query_loc);
/* Allocate result buffer */
norm_query = palloc(query_len + 1);
tok_len; /* Length (in bytes) of that tok */
off = jstate->clocations[i].location;
+ /* Adjust recorded location if we're dealing with partial string */
+ off -= query_loc;
+
tok_len = jstate->clocations[i].length;
if (tok_len < 0)
* marked as '-1', so that they are later ignored. (Actually, we assume the
* lengths were initialized as -1 to start with, and don't change them here.)
*
+ * If query_loc > 0, then "query" has been advanced by that much compared to
+ * the original string start, so we need to translate the provided locations
+ * to compensate. (This lets us avoid re-scanning statements before the one
+ * of interest, so it's worth doing.)
+ *
* N.B. There is an assumption that a '-' character at a Const location begins
* a negative numeric constant. This precludes there ever being another
* reason for a constant to start with a '-'.
*/
static void
-fill_in_constant_lengths(pgssJumbleState *jstate, const char *query)
+fill_in_constant_lengths(pgssJumbleState *jstate, const char *query,
+ int query_loc)
{
pgssLocationLen *locs;
core_yyscan_t yyscanner;
int loc = locs[i].location;
int tok;
+ /* Adjust recorded location if we're dealing with partial string */
+ loc -= query_loc;
+
Assert(loc >= 0);
if (loc <= last_loc)
CREATE EXTENSION pg_stat_statements;
-CREATE TABLE test (a int, b char(20));
+--
+-- 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;
--- test the basic functionality of pg_stat_statements
+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 > 5;
+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 query, calls, rows from pg_stat_statements ORDER BY rows;
+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);
-DROP TABLE test;
+SELECT query, calls, rows FROM pg_stat_statements ORDER BY query COLLATE "C";
DROP EXTENSION pg_stat_statements;