pax_global_header 0000666 0000000 0000000 00000000064 15007316545 0014520 g ustar 00root root 0000000 0000000 52 comment=b80c6920e01b2ff75788bddd2ff127bd79b57075
pg_show_plans-2.1.5/ 0000775 0000000 0000000 00000000000 15007316545 0014370 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/.editorconfig 0000664 0000000 0000000 00000000233 15007316545 0017043 0 ustar 00root root 0000000 0000000 root = true
[*]
end_of_line = lf
insert_final_newline = true
charset = utf-8
[*.{c,h}]
indent_style = tab
indent_size = 4
[Makefile]
indent_style = tab
pg_show_plans-2.1.5/.github/ 0000775 0000000 0000000 00000000000 15007316545 0015730 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/.github/ISSUE_TEMPLATE/ 0000775 0000000 0000000 00000000000 15007316545 0020113 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/.github/ISSUE_TEMPLATE/bug_report.md 0000664 0000000 0000000 00000001255 15007316545 0022610 0 ustar 00root root 0000000 0000000 ---
name: Bug report
about: Things to provide along with a report
title: ''
labels: ''
assignees: ''
---
# Things needed to file a bug report
Describe the issue and do not forget to attach the following info to get help quicker:
* PostgreSQL version
* Extension version
* Which way did you install PostgreSQL, sources or binaries?
* Operating system
* All the other extensions that you use.
* `shared_preload_libraries` value from `postgresql.conf`
* Can you reproduce your issue on a clean cluster? If yes, state exactly how.
* Does the server crash? Try to get a [stack trace](https://wiki.postgresql.org/wiki/Getting_a_stack_trace_of_a_running_PostgreSQL_backend_on_Linux/BSD).
pg_show_plans-2.1.5/.github/workflows/ 0000775 0000000 0000000 00000000000 15007316545 0017765 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/.github/workflows/installcheck.yml 0000664 0000000 0000000 00000001645 15007316545 0023162 0 ustar 00root root 0000000 0000000 name: Build
on:
pull_request:
branches:
- master
jobs:
build:
runs-on: ubuntu-latest
defaults:
run:
shell: sh
strategy:
matrix:
pgversion:
- 18
- 17
- 16
- 15
- 14
env:
PGVERSION: ${{ matrix.pgversion }}
steps:
- name: checkout
uses: actions/checkout@v4
- name: install pg
run: |
sudo /usr/share/postgresql-common/pgdg/apt.postgresql.org.sh -v $PGVERSION -p -i
sudo -u postgres createuser -s "$USER"
- name: build
run: |
make PROFILE="-Werror"
sudo -E make install
- name: test
run: |
sudo pg_conftool set shared_preload_libraries pg_show_plans
sudo pg_ctlcluster $PGVERSION main restart
make installcheck
- name: show regression diffs
if: ${{ failure() }}
run: |
cat regression.diffs
pg_show_plans-2.1.5/.gitignore 0000664 0000000 0000000 00000000205 15007316545 0016355 0 ustar 00root root 0000000 0000000 # Clangd
.cache/
.clangd
compile_commands.json
# Build Output
*.bc
*.o
*.so
.deps/
# Regression Tests Output
results/
regression.*
pg_show_plans-2.1.5/LICENSE 0000664 0000000 0000000 00000002077 15007316545 0015403 0 ustar 00root root 0000000 0000000 The PostgreSQL License
Copyright (c) 2019-2024, CYBERTEC PostgreSQL International GmbH
Permission to use, copy, modify, and distribute this software and its
documentation for any purpose, without fee, and without a written agreement is
hereby granted, provided that the above copyright notice and this paragraph and
the following two paragraphs appear in all copies.
IN NO EVENT SHALL CYBERTEC PostgreSQL International GmbH BE LIABLE TO ANY PARTY
FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING
LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION,
EVEN IF CYBERTEC PostgreSQL International GmbH HAS BEEN ADVISED OF THE
POSSIBILITY OF SUCH DAMAGE.
CYBERTEC PostgreSQL International GmbH SPECIFICALLY DISCLAIMS ANY WARRANTIES,
INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND
FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS
IS" BASIS, AND CYBERTEC PostgreSQL International GmbH HAS NO OBLIGATIONS TO
PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS.
pg_show_plans-2.1.5/Makefile 0000664 0000000 0000000 00000001261 15007316545 0016030 0 ustar 00root root 0000000 0000000 MODULE_big = pg_show_plans
OBJS = pg_show_plans.o
EXTENSION = pg_show_plans
DATA = pg_show_plans--1.0--1.1.sql \
pg_show_plans--1.1--2.0.sql \
pg_show_plans--2.0--2.1.sql \
pg_show_plans--2.1.sql
REGRESS = pg_show_plans formats
DOCS = pg_show_plans.md
# Fix GCC compilation warning against 16:
# cc1: warning: ‘-Wformat-security’ ignored without ‘-Wformat’ [-Wformat-security]
PG_CFLAGS = -Wformat
USE_PGXS = 1
ifdef USE_PGXS
PG_CONFIG = pg_config
PGXS := $(shell $(PG_CONFIG) --pgxs)
include $(PGXS)
else
subdir = contrib/pg_show_plans
top_builddir = ../..
include $(top_builddir)/src/Makefile.global
include $(top_srcdir)/contrib/contrib-global.mk
endif
pg_show_plans-2.1.5/README.md 0000664 0000000 0000000 00000011714 15007316545 0015653 0 ustar 00root root 0000000 0000000 # pg_show_plans
PostgreSQL extension that shows query plans of all the currently running SQL
statements. Query plans can be shown in several formats, like `JSON` or `YAML`.
*This extension creates a hash table within shared memory. The hash table is
not resizable, thus, no new plans can be added once it has been filled up.*
# INSTALL
PostgreSQL versions 14 and newer are supported.
Install PostgreSQL before proceeding. Make sure to have `pg_config` binary,
these are typically included in `-dev` and `-devel` packages.
```bash
git clone https://github.com/cybertec-postgresql/pg_show_plans.git
cd pg_show_plans
make
make install
```
## Configure
Add `pg_show_plans` to `shared_preload_libraries` within `postgresql.conf`:
```
shared_preload_libraries = 'pg_show_plans'
```
Restart the server, and invoke `CREATE EXTENSION pg_show_plans;`:
```
postgresql=# CREATE EXTENSION pg_show_plans;
CREATE EXTENSION
postgresql=#
```
# USAGE
To see the query plans:
```
testdb=# SELECT * FROM pg_show_plans;
pid | level | userid | dbid | plan
-------+-------+--------+-------+-----------------------------------------------------------------------
11473 | 0 | 10 | 16384 | Function Scan on pg_show_plans (cost=0.00..10.00 rows=1000 width=56)
11504 | 0 | 10 | 16384 | Function Scan on print_item (cost=0.25..10.25 rows=1000 width=524)
11504 | 1 | 10 | 16384 | Result (cost=0.00..0.01 rows=1 width=4)
(3 rows)
```
To get query plans and see the corresponding query expression:
```
testdb=# \x
Expanded display is on.
testdb=# SELECT * FROM pg_show_plans_q;
-[ RECORD 1 ]-----------------------------------------------------------------------------------------
pid | 11473
level | 0
plan | Sort (cost=72.08..74.58 rows=1000 width=80) +
| Sort Key: pg_show_plans.pid, pg_show_plans.level +
| -> Hash Left Join (cost=2.25..22.25 rows=1000 width=80) +
| Hash Cond: (pg_show_plans.pid = s.pid) +
| Join Filter: (pg_show_plans.level = 0) +
| -> Function Scan on pg_show_plans (cost=0.00..10.00 rows=1000 width=48) +
| -> Hash (cost=1.00..1.00 rows=100 width=44) +
| -> Function Scan on pg_stat_get_activity s (cost=0.00..1.00 rows=100 width=44)
query | SELECT p.pid, p.level, p.plan, a.query FROM pg_show_plans p +
| LEFT JOIN pg_stat_activity a +
| ON p.pid = a.pid AND p.level = 0 ORDER BY p.pid, p.level;
-[ RECORD 2 ]-----------------------------------------------------------------------------------------
pid | 11517
level | 0
plan | Function Scan on print_item (cost=0.25..10.25 rows=1000 width=524)
query | SELECT * FROM print_item(1,20);
-[ RECORD 3 ]-----------------------------------------------------------------------------------------
pid | 11517
level | 1
plan | Result (cost=0.00..0.01 rows=1 width=4)
query |
```
# BENCHMARKS
`pgbench -c 10 -j 3 -t 5000 -S` plain PostgreSQL `16.1`:
```
tps = 193655.084802 (without initial connection time)
tps = 200890.346014 (without initial connection time)
tps = 199931.223659 (without initial connection time)
```
`pgbench -c 10 -j 3 -t 5000 -S` PostgreSQL `16.1` with `pg_show_plans` version
`2.1.0`:
```
tps = 166564.507102 (without initial connection time)
tps = 172814.245424 (without initial connection time)
tps = 174658.455390 (without initial connection time)
```
In overall approximately 15% performance penalty.
# REFERENCE
## GUC Variables
* `pg_show_plans.plan_format = text`: query plans output format, either of
`text`, `json`, `yaml`, and `xml`.
* `pg_show_plans.max_plan_length = 16384`: query plan maximal length in bytes.
This value affects the amount of shared memory the extension asks for, the
server may not start if the value is too high.
* `pg_show_plans.is_enabled = true`: enable or disable the extension by
assigning to this variable.
*Default values are shown after '=' sign.*
## Views
* `pg_show_plans`: defined as `SELECT * FROM pg_show_plans();` for convenience.
* `pg_show_plans_q`: same as `pg_show_plans`, but it has one more column with
the corresponding query strings.
## Functions
* `pg_show_plans()`: show query plans:
- `pid`: server process ID that runs the query.
- `level`: query nest level. Top level is 0. For example, if you execute a
simple select query, the level of this query's plan is 0. If you execute a
function that invokes a select query, level 0 is the plan of the function
and level 1 is the plan of the select query invoked by the function.
- `userid`: user ID who runs the query.
- `dbid`: database ID the query runs in.
- `plan`: query plan.
pg_show_plans-2.1.5/expected/ 0000775 0000000 0000000 00000000000 15007316545 0016171 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/expected/formats.out 0000664 0000000 0000000 00000011633 15007316545 0020401 0 ustar 00root root 0000000 0000000 -- explain output on PG12/13 is missing "Async Capable"
select setting::int < 140000 as pg12_13 from pg_settings where name = 'server_version_num';
pg12_13
---------
f
(1 row)
-- json output
set pg_show_plans.plan_format = 'json';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
json
(1 row)
select * from nest();
level | plan
-------+---------------------------------------
0 | [ +
| "Plan": { +
| "Node Type": "Function Scan", +
| "Parallel Aware": false, +
| "Async Capable": false, +
| "Function Name": "nest", +
| "Alias": "nest", +
| "Startup Cost": 0.25, +
| "Total Cost": 10.25, +
| "Plan Rows": 1000, +
| "Plan Width": 36 +
| } +
| ]
1 | [ +
| "Plan": { +
| "Node Type": "Function Scan", +
| "Parallel Aware": false, +
| "Async Capable": false, +
| "Function Name": "pg_show_plans",+
| "Alias": "pg_show_plans", +
| "Startup Cost": 0.00, +
| "Total Cost": 12.50, +
| "Plan Rows": 333, +
| "Plan Width": 36, +
| "Filter": "(level >= 0)" +
| } +
| ]
(2 rows)
-- yaml output
set pg_show_plans.plan_format = 'yaml';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
yaml
(1 row)
select * from nest();
level | plan
-------+----------------------------------
0 | Plan: +
| Node Type: "Function Scan" +
| Parallel Aware: false +
| Async Capable: false +
| Function Name: "nest" +
| Alias: "nest" +
| Startup Cost: 0.25 +
| Total Cost: 10.25 +
| Plan Rows: 1000 +
| Plan Width: 36
1 | Plan: +
| Node Type: "Function Scan" +
| Parallel Aware: false +
| Async Capable: false +
| Function Name: "pg_show_plans"+
| Alias: "pg_show_plans" +
| Startup Cost: 0.00 +
| Total Cost: 12.50 +
| Plan Rows: 333 +
| Plan Width: 36 +
| Filter: "(level >= 0)"
(2 rows)
-- xml output
set pg_show_plans.plan_format = 'xml';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
xml
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------
0 | +
| +
| Function Scan +
| false +
| false +
| nest +
| nest +
| 0.25 +
| 10.25 +
| 1000 +
| 36 +
| +
|
1 | +
| +
| Function Scan +
| false +
| false +
| pg_show_plans +
| pg_show_plans +
| 0.00 +
| 12.50 +
| 333 +
| 36 +
| (level >= 0) +
| +
|
(2 rows)
-- check plan format after reconnect
\c
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
xml
(1 row)
pg_show_plans-2.1.5/expected/formats_1.out 0000664 0000000 0000000 00000012330 15007316545 0020614 0 ustar 00root root 0000000 0000000 -- explain output on PG12/13 is missing "Async Capable"
select setting::int < 140000 as pg12_13 from pg_settings where name = 'server_version_num';
pg12_13
---------
f
(1 row)
-- json output
set pg_show_plans.plan_format = 'json';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
json
(1 row)
select * from nest();
level | plan
-------+---------------------------------------
0 | [ +
| "Plan": { +
| "Node Type": "Function Scan", +
| "Parallel Aware": false, +
| "Async Capable": false, +
| "Function Name": "nest", +
| "Alias": "nest", +
| "Startup Cost": 0.25, +
| "Total Cost": 10.25, +
| "Plan Rows": 1000, +
| "Plan Width": 36, +
| "Disabled": false +
| } +
| ]
1 | [ +
| "Plan": { +
| "Node Type": "Function Scan", +
| "Parallel Aware": false, +
| "Async Capable": false, +
| "Function Name": "pg_show_plans",+
| "Alias": "pg_show_plans", +
| "Startup Cost": 0.00, +
| "Total Cost": 12.50, +
| "Plan Rows": 333, +
| "Plan Width": 36, +
| "Disabled": false, +
| "Filter": "(level >= 0)" +
| } +
| ]
(2 rows)
-- yaml output
set pg_show_plans.plan_format = 'yaml';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
yaml
(1 row)
select * from nest();
level | plan
-------+----------------------------------
0 | Plan: +
| Node Type: "Function Scan" +
| Parallel Aware: false +
| Async Capable: false +
| Function Name: "nest" +
| Alias: "nest" +
| Startup Cost: 0.25 +
| Total Cost: 10.25 +
| Plan Rows: 1000 +
| Plan Width: 36 +
| Disabled: false
1 | Plan: +
| Node Type: "Function Scan" +
| Parallel Aware: false +
| Async Capable: false +
| Function Name: "pg_show_plans"+
| Alias: "pg_show_plans" +
| Startup Cost: 0.00 +
| Total Cost: 12.50 +
| Plan Rows: 333 +
| Plan Width: 36 +
| Disabled: false +
| Filter: "(level >= 0)"
(2 rows)
-- xml output
set pg_show_plans.plan_format = 'xml';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
xml
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------
0 | +
| +
| Function Scan +
| false +
| false +
| nest +
| nest +
| 0.25 +
| 10.25 +
| 1000 +
| 36 +
| false +
| +
|
1 | +
| +
| Function Scan +
| false +
| false +
| pg_show_plans +
| pg_show_plans +
| 0.00 +
| 12.50 +
| 333 +
| 36 +
| false +
| (level >= 0) +
| +
|
(2 rows)
-- check plan format after reconnect
\c
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
xml
(1 row)
pg_show_plans-2.1.5/expected/formats_2.out 0000664 0000000 0000000 00000004216 15007316545 0020621 0 ustar 00root root 0000000 0000000 -- explain output on PG12/13 is missing "Async Capable"
select setting::int < 140000 as pg12_13 from pg_settings where name = 'server_version_num';
pg12_13
---------
f
(1 row)
-- json output
set pg_show_plans.plan_format = 'json';
ERROR: parameter "pg_show_plans.plan_format" cannot be changed without restarting the server
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------------------
0 | Function Scan on nest (cost=0.25..10.25 rows=1000 width=36)
1 | Function Scan on pg_show_plans (cost=0.00..12.50 rows=333 width=36)+
| Filter: (level >= 0)
(2 rows)
-- yaml output
set pg_show_plans.plan_format = 'yaml';
ERROR: parameter "pg_show_plans.plan_format" cannot be changed without restarting the server
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------------------
0 | Function Scan on nest (cost=0.25..10.25 rows=1000 width=36)
1 | Function Scan on pg_show_plans (cost=0.00..12.50 rows=333 width=36)+
| Filter: (level >= 0)
(2 rows)
-- xml output
set pg_show_plans.plan_format = 'xml';
ERROR: parameter "pg_show_plans.plan_format" cannot be changed without restarting the server
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------------------
0 | Function Scan on nest (cost=0.25..10.25 rows=1000 width=36)
1 | Function Scan on pg_show_plans (cost=0.00..12.50 rows=333 width=36)+
| Filter: (level >= 0)
(2 rows)
-- check plan format after reconnect
\c
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
pg_show_plans-2.1.5/expected/pg_show_plans.out 0000664 0000000 0000000 00000002421 15007316545 0021564 0 ustar 00root root 0000000 0000000 create extension pg_show_plans;
show pg_show_plans.is_enabled;
pg_show_plans.is_enabled
--------------------------
on
(1 row)
show pg_show_plans.max_plan_length;
pg_show_plans.max_plan_length
-------------------------------
16384
(1 row)
create function nest()
returns table (level int, plan text)
language plpgsql
as $$
begin
return query
select pg_show_plans.level, pg_show_plans.plan from pg_show_plans
where pg_show_plans.level >= 0;
end;
$$;
-- text output
set pg_show_plans.plan_format = 'text';
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
select level, plan from pg_show_plans;
level | plan
-------+-----------------------------------------------------------------------
0 | Function Scan on pg_show_plans (cost=0.00..10.00 rows=1000 width=36)
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------------------
0 | Function Scan on nest (cost=0.25..10.25 rows=1000 width=36)
1 | Function Scan on pg_show_plans (cost=0.00..12.50 rows=333 width=36)+
| Filter: (level >= 0)
(2 rows)
pg_show_plans-2.1.5/expected/pg_show_plans_1.out 0000664 0000000 0000000 00000002557 15007316545 0022016 0 ustar 00root root 0000000 0000000 create extension pg_show_plans;
show pg_show_plans.is_enabled;
pg_show_plans.is_enabled
--------------------------
on
(1 row)
show pg_show_plans.max_plan_length;
pg_show_plans.max_plan_length
-------------------------------
16384
(1 row)
create function nest()
returns table (level int, plan text)
language plpgsql
as $$
begin
return query
select pg_show_plans.level, pg_show_plans.plan from pg_show_plans
where pg_show_plans.level >= 0;
end;
$$;
-- text output
set pg_show_plans.plan_format = 'text';
ERROR: parameter "pg_show_plans.plan_format" cannot be changed without restarting the server
show pg_show_plans.plan_format;
pg_show_plans.plan_format
---------------------------
text
(1 row)
select level, plan from pg_show_plans;
level | plan
-------+-----------------------------------------------------------------------
0 | Function Scan on pg_show_plans (cost=0.00..10.00 rows=1000 width=36)
(1 row)
select * from nest();
level | plan
-------+----------------------------------------------------------------------
0 | Function Scan on nest (cost=0.25..10.25 rows=1000 width=36)
1 | Function Scan on pg_show_plans (cost=0.00..12.50 rows=333 width=36)+
| Filter: (level >= 0)
(2 rows)
pg_show_plans-2.1.5/pg_show_plans--1.0--1.1.sql 0000664 0000000 0000000 00000001413 15007316545 0020676 0 ustar 00root root 0000000 0000000 -- pid/level changed from int8 to int
DROP VIEW pg_show_plans;
DROP FUNCTION pg_show_plans;
CREATE FUNCTION pg_show_plans(
OUT pid int,
OUT level int,
OUT userid oid,
OUT dbid oid,
OUT plan text
)
RETURNS SETOF record
AS 'MODULE_PATHNAME'
LANGUAGE C;
-- Register a view on the function for ease of use.
CREATE VIEW pg_show_plans AS
SELECT * FROM pg_show_plans();
GRANT SELECT ON pg_show_plans TO PUBLIC;
-- Some 1.0 versions already contained yaml/xml, use "or replace" here
CREATE OR REPLACE FUNCTION pgsp_format_yaml()
RETURNS void
AS 'MODULE_PATHNAME'
LANGUAGE C;
CREATE OR REPLACE FUNCTION pgsp_format_xml()
RETURNS void
AS 'MODULE_PATHNAME'
LANGUAGE C;
REVOKE ALL ON FUNCTION pgsp_format_yaml() FROM PUBLIC;
REVOKE ALL ON FUNCTION pgsp_format_xml() FROM PUBLIC;
pg_show_plans-2.1.5/pg_show_plans--1.1--2.0.sql 0000664 0000000 0000000 00000000304 15007316545 0020675 0 ustar 00root root 0000000 0000000 DROP FUNCTION gsp_format_text;
DROP FUNCTION gsp_format_json;
DROP FUNCTION gsp_format_yaml;
DROP FUNCTION gsp_format_xml;
DROP FUNCTION pg_show_plans_enable;
DROP FUNCTION pg_show_plans_disable;
pg_show_plans-2.1.5/pg_show_plans--2.0--2.1.sql 0000664 0000000 0000000 00000000456 15007316545 0020706 0 ustar 00root root 0000000 0000000 -- Register a view to see query plans along with the corresponding queries.
CREATE VIEW pg_show_plans_q AS
SELECT p.pid, p.level, p.plan, a.query
FROM pg_show_plans p
LEFT JOIN pg_stat_activity a
ON p.pid = a.pid AND p.level = 0 ORDER BY p.pid, p.level;
GRANT SELECT ON pg_show_plans_q TO PUBLIC;
pg_show_plans-2.1.5/pg_show_plans--2.1.sql 0000664 0000000 0000000 00000001452 15007316545 0020331 0 ustar 00root root 0000000 0000000 /* pg_show_plans/pg_show_plans--2.1.sql */
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pg_show_plans" to load this file. \quit
CREATE FUNCTION pg_show_plans(
OUT pid int,
OUT level int,
OUT userid oid,
OUT dbid oid,
OUT plan text
)
RETURNS SETOF record
AS 'MODULE_PATHNAME'
LANGUAGE C;
-- Register a view on the function for ease of use.
CREATE VIEW pg_show_plans AS
SELECT * FROM pg_show_plans();
-- Register a view to see query plans along with the corresponding queries.
CREATE VIEW pg_show_plans_q AS
SELECT p.pid, p.level, p.plan, a.query
FROM pg_show_plans p
LEFT JOIN pg_stat_activity a
ON p.pid = a.pid AND p.level = 0 ORDER BY p.pid, p.level;
GRANT SELECT ON pg_show_plans TO PUBLIC;
GRANT SELECT ON pg_show_plans_q TO PUBLIC;
pg_show_plans-2.1.5/pg_show_plans.c 0000664 0000000 0000000 00000046341 15007316545 0017407 0 ustar 00root root 0000000 0000000 /*
* -------------------------------------------------------------------------
*
* pg_show_plans.c
* Show query plans of all currently running SQL statements
*
* Copyright (c) 2008-2022, PostgreSQL Global Development Group
* Copyright (c) 2019-2023, CYBERTEC PostgreSQL International GmbH
*
* -------------------------------------------------------------------------
*/
/* Includes */
#include "postgres.h"
#include "catalog/pg_authid.h"
#include "commands/explain.h"
#if PG_VERSION_NUM >= 180000
#include "commands/explain_state.h"
#include "commands/explain_format.h"
#endif
#include "fmgr.h"
#include "funcapi.h"
#include "lib/stringinfo.h"
#include "miscadmin.h"
#include "storage/ipc.h"
#include "storage/lwlock.h"
#include "storage/shmem.h"
#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/guc.h"
/* Constants and Macros */
PG_MODULE_MAGIC;
#if PG_VERSION_NUM < 120000
#error "Unsupported PostgreSQL Version"
#endif
#define MAX_NEST_LEVEL 10
/* Typedefs */
typedef struct pgspHashKey /* Hash entry key. */
{
pid_t pid;
} pgspHashKey;
typedef struct pgspEntry /* Hash table entry. */
{
pgspHashKey hash_key; /* Entry hash key, must be first. */
slock_t mutex; /* Protects the entry. */
Oid user_id; /* User OID. */
Oid db_id; /* Database OID. */
int plan_len[MAX_NEST_LEVEL]; /* Query plan length in bytes. */
int n_plans; /* Query plan count. */
char plan[]; /* Query plan string. */
} pgspEntry;
typedef struct pgspSharedState /* Shared state of the extension. */
{
LWLock *lock; /* Protects shared hash table. */
bool is_enabled; /* Enables or disables the extension. */
int plan_format;
} pgspSharedState;
typedef struct pgspCtx { /* Used as `funcctx->user_fctx` in pg_show_plans(). */
HASH_SEQ_STATUS *hash_seq;
pgspEntry *pgsp_tmp_entry; /* PGSP entry currently processing. */
int curr_nest; /* Current nest level porcessing. */
bool is_done; /* Done processing current PGSP entry? */
} pgspCtx;
/* Function Prototypes */
void _PG_init(void);
/* Returns shared hash entry size. */
static Size hash_entry_size(void);
/* Calculates shared memory size required for the extension. */
static Size shmem_required(void);
/* Generates a hash entry key. */
static uint32 gen_hash_key(const void *key, Size keysize);
/* Hash entry comparison function. */
static int compare_hash_key(const void *key1, const void *key2, Size keysize);
/* Caches the process' hash entry (if not already). Returns 1 on success. */
static int ensure_cached(void);
/* Grabs an exclusive lock, and creates a new hash table entry. */
static pgspEntry *create_hash_entry(const pgspHashKey *key);
/* Add a new query plan to the shared hash entry. */
static void append_query_plan(ExplainState *es);
/* on_shmem_exit() callback to delete hash entry on client disconnect. */
static void cleanup(int code, Datum arg);
/* Set extension state, either enable or disable. */
static void set_state(bool state, void *extra);
static const char *show_state(void);
/* Set query plan output format: text, json, ... */
static void set_format(const int format);
/* Propagate GUC variable value to shared memory (assign hook). */
static void prop_format_to_shmem(int newval, void *extra);
static const char *show_format(void);
/* Check the extension has been properly loaded. */
static inline void shmem_safety_check(void);
/* Check whether the user has required privileges. */
static bool is_allowed_role(void);
/* Hook functions. */
/* Ask for shared memory. */
#if PG_VERSION_NUM >= 150000
static void pgsp_shmem_request(void);
#endif
static void pgsp_shmem_startup(void);
/* Saves query plans to the shared hash table. */
static
#if PG_VERSION_NUM < 180000
void
#else
bool
#endif
pgsp_ExecutorStart(QueryDesc *queryDesc, int eflags);
/* Keeps track of the nest level. */
static void pgsp_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction,
uint64 count
#if PG_VERSION_NUM < 180000
, bool execute_once
#endif
);
/* Show query plans of all the currently running statements. */
Datum pg_show_plans(PG_FUNCTION_ARGS);
PG_FUNCTION_INFO_V1(pg_show_plans);
/* Global Variables */
/* Shared extension state. */
static pgspSharedState *pgsp = NULL;
/* Current process' hash entry. */
static pgspEntry *pgsp_cache = NULL;
/* Shared hash table with query plans. */
static HTAB *pgsp_hash = NULL;
/* Current query plan nested level. */
static unsigned int nest_level = 0;
/* To save old hook values. */
#if PG_VERSION_NUM >= 150000
static shmem_request_hook_type prev_shmem_request_hook = NULL;
#endif
static shmem_startup_hook_type prev_shmem_startup_hook = NULL;
static ExecutorStart_hook_type prev_ExecutorStart = NULL;
static ExecutorRun_hook_type prev_ExecutorRun = NULL;
/* GUC variables. */
/* Maximal query plan length. */
static int max_plan_length;
/* Start extension enabled or not?. */
static bool start_enabled;
/* pg_show_plans() query plan output format. */
static int plan_format;
/* Available query plan formats. */
static const struct config_enum_entry plan_formats[] =
{
{"text", EXPLAIN_FORMAT_TEXT, false},
{"json", EXPLAIN_FORMAT_JSON, false},
{"yaml", EXPLAIN_FORMAT_YAML, false},
{"xml", EXPLAIN_FORMAT_XML, false},
{NULL, 0, false}
};
void
_PG_init(void)
{
/* Must be in shared_preload_libraries="...". */
if (!process_shared_preload_libraries_in_progress)
return;
DefineCustomBoolVariable("pg_show_plans.is_enabled",
"Start with the extension enabled?",
NULL,
&start_enabled,
true,
#if PG_VERSION_NUM >= 150000
PGC_USERSET,
#else
PGC_POSTMASTER,
#endif
0,
NULL, set_state, show_state);
DefineCustomIntVariable("pg_show_plans.max_plan_length",
gettext_noop("Set the maximum plan length. "
"Note that this module allocates (max_plan_length*max_connections) "
"bytes on the shared memory."),
gettext_noop("A hash entry whose length is max_plan_length stores the plans of "
"all nested levels, so this value should be set enough size. "
"However, if it is too large, the server may not be able to start "
"because of the shortage of memory due to the huge shared memory size."),
&max_plan_length,
16 * 1024,
1024,
100 * 1024,
PGC_POSTMASTER,
0,
NULL, NULL, NULL);
DefineCustomEnumVariable("pg_show_plans.plan_format",
"Set the output format of query plans.",
NULL,
&plan_format,
EXPLAIN_FORMAT_TEXT,
plan_formats,
#if PG_VERSION_NUM >= 150000
PGC_USERSET,
#else
PGC_POSTMASTER,
#endif
0,
NULL, prop_format_to_shmem, show_format);
/* Save old hooks, and install new ones. */
#if PG_VERSION_NUM >= 150000
prev_shmem_request_hook = shmem_request_hook;
shmem_request_hook = pgsp_shmem_request;
#else
RequestAddinShmemSpace(shmem_required());
RequestNamedLWLockTranche("pg_show_plans", 1);
#endif
prev_shmem_startup_hook = shmem_startup_hook;
shmem_startup_hook = pgsp_shmem_startup;
prev_ExecutorStart = ExecutorStart_hook;
ExecutorStart_hook = pgsp_ExecutorStart; /* Store new plans. */
prev_ExecutorRun = ExecutorRun_hook;
ExecutorRun_hook = pgsp_ExecutorRun; /* Track nest level. */
}
static Size
hash_entry_size(void)
{ /* Structure size & variable array maximal length. */
return offsetof(pgspEntry, plan) + max_plan_length;
}
static Size
shmem_required(void)
{
Size s;
s = MAXALIGN(sizeof(pgspSharedState));
s = add_size(s,
hash_estimate_size(MaxConnections, hash_entry_size()) );
return s;
}
static uint32
gen_hash_key(const void *key, Size keysize)
{
const pgspHashKey *k = (const pgspHashKey *) key;
return (uint32) k->pid;
}
static int
compare_hash_key(const void *key1, const void *key2, Size keysize)
{
const pgspHashKey *k1 = (const pgspHashKey *) key1;
const pgspHashKey *k2 = (const pgspHashKey *) key2;
return (k1->pid == k2->pid) ? 0 : 1;
}
static int
ensure_cached(void)
{
pgspHashKey pgsp_hash_hey;
if (pgsp_cache)
return 1;
pgsp_hash_hey.pid = MyProcPid;
pgsp_cache = create_hash_entry(&pgsp_hash_hey);
if (!pgsp_cache)
return 0; /* Ran out of memory. */
pgsp_cache->user_id = GetUserId();
pgsp_cache->plan[0] = '\0';
pgsp_cache->n_plans = 0;
on_shmem_exit(cleanup, (Datum)NULL);
return 1;
}
/* Returns NULL if the hash table is full. */
static pgspEntry *
create_hash_entry(const pgspHashKey *key)
{
pgspEntry *entry;
LWLockAcquire(pgsp->lock, LW_EXCLUSIVE);
entry = (pgspEntry *)hash_search(pgsp_hash,
key,
HASH_ENTER_NULL,
NULL);
LWLockRelease(pgsp->lock);
return entry;
}
static void
append_query_plan(ExplainState *es)
{
const StringInfo new_plan = es->str;
int i;
int space_left; /* Space left within a shared hash map entry. */
int offset; /* Beginning of free space within an entry. */
offset = 0;
for (i = 0; i < nest_level; i++)
offset += pgsp_cache->plan_len[i] + 1; /* +1 for '\0'. */
space_left = max_plan_length - offset;
if (pgsp->plan_format == EXPLAIN_FORMAT_TEXT)
new_plan->len--; /* Discard '\n'. */
if (space_left < new_plan->len+1) {
ereport(WARNING,
errcode(ERRCODE_OUT_OF_MEMORY),
errmsg("not enough memory to append new query plans"),
errhint("Try increasing 'pg_show_plans.max_plan_length'."));
return;
}
memcpy(pgsp_cache->plan + offset,
new_plan->data, new_plan->len);
pgsp_cache->plan[offset + new_plan->len] = '\0';
pgsp_cache->plan_len[nest_level] = new_plan->len;
pgsp_cache->db_id = MyDatabaseId;
pgsp_cache->n_plans = nest_level+1;
}
static void
cleanup(int code, Datum arg)
{
pgspHashKey key;
key.pid = pgsp_cache->hash_key.pid;
LWLockAcquire(pgsp->lock, LW_EXCLUSIVE);
hash_search(pgsp_hash, &key, HASH_REMOVE, NULL);
LWLockRelease(pgsp->lock);
}
static void
set_state(bool state, void *extra)
{
/* Shared memory may not be fully available at server start, so we do not
* check for pgsp_hash availability here. That is why the following line is
* commented out. */
/* shmem_safety_check(); */
if (pgsp != NULL)
pgsp->is_enabled = state;
}
/* since we can't update start_enabled in running backends, provide a show hook
* that reads the value from shared memory */
static const char *
show_state()
{
if (pgsp->is_enabled)
return "on";
else
return "off";
}
static void
set_format(const int format)
{
/* Shared memory may not be fully available at server start, so we do not
* check for pgsp_hash availability here. That is why the following line is
* commented out. */
/* shmem_safety_check(); */
if (pgsp != NULL && is_allowed_role())
pgsp->plan_format = format;
}
static void
prop_format_to_shmem(int newval, void *extra)
{
set_format(newval);
}
static const char *
show_format()
{
if (pgsp->plan_format == EXPLAIN_FORMAT_TEXT)
return "text";
else if (pgsp->plan_format == EXPLAIN_FORMAT_JSON)
return "json";
else if (pgsp->plan_format == EXPLAIN_FORMAT_YAML)
return "yaml";
else if (pgsp->plan_format == EXPLAIN_FORMAT_XML)
return "xml";
else
ereport(ERROR,
errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
errmsg("unexpected plan_format value: %d", pgsp->plan_format),
errhint("Valid values are 'text', 'json', 'yaml', 'xml'."));
}
static inline void
shmem_safety_check(void)
{
if (pgsp && pgsp_hash)
return;
ereport(ERROR,
errcode(ERRCODE_OBJECT_NOT_IN_PREREQUISITE_STATE),
errmsg("shared library not found"),
errhint("Add 'pg_show_plans' to 'shared_preload_libraries', "
"and restart the server."));
}
static bool
is_allowed_role(void)
{
bool is_allowed_role = false;
#if PG_VERSION_NUM >= 140000
is_allowed_role = is_member_of_role(GetUserId(), ROLE_PG_READ_ALL_STATS);
#else
is_allowed_role = is_member_of_role(GetUserId(), DEFAULT_ROLE_READ_ALL_STATS);
#endif
return is_allowed_role;
}
#if PG_VERSION_NUM >= 150000
static void
pgsp_shmem_request(void)
{
if (prev_shmem_request_hook)
prev_shmem_request_hook();
RequestAddinShmemSpace(shmem_required());
RequestNamedLWLockTranche("pg_show_plans", 1);
}
#endif
static void
pgsp_shmem_startup(void)
{
bool found;
HASHCTL info;
if (prev_shmem_startup_hook)
prev_shmem_startup_hook();
/* Reset in case this is a restart within the postmaster. */
pgsp = NULL;
pgsp_hash = NULL;
/* Create or attach to the shared memory state, including hash table. */
LWLockAcquire(AddinShmemInitLock, LW_EXCLUSIVE);
pgsp = ShmemInitStruct("pg_show_plans",
sizeof(pgspSharedState), &found);
if (!found) /* First time. */
{
pgsp->lock = &(GetNamedLWLockTranche("pg_show_plans"))->lock;
pgsp->is_enabled = start_enabled;
pgsp->plan_format = plan_format;
}
memset(&info, 0, sizeof(info));
info.keysize = sizeof(pgspHashKey);
info.entrysize = hash_entry_size();
info.hash = gen_hash_key;
info.match = compare_hash_key;
pgsp_hash = ShmemInitHash("pg_show_plans hash",
MaxConnections,
MaxConnections,
&info,
HASH_ELEM|HASH_FUNCTION|HASH_COMPARE);
LWLockRelease(AddinShmemInitLock);
}
static
#if PG_VERSION_NUM < 180000
void
#else
bool
#endif
pgsp_ExecutorStart(QueryDesc *queryDesc, int eflags)
{
ExplainState *es;
#if PG_VERSION_NUM >= 180000
bool ret_val;
#endif
if (prev_ExecutorStart)
{
#if PG_VERSION_NUM >= 180000
ret_val =
#endif
prev_ExecutorStart(queryDesc, eflags);
}
else
{
#if PG_VERSION_NUM >= 180000
ret_val =
#endif
standard_ExecutorStart(queryDesc, eflags);
}
if (!ensure_cached()) {
ereport(WARNING,
errcode(ERRCODE_OUT_OF_MEMORY),
errmsg("not enough memory to append new query plans"),
errhint("Try increasing 'pg_show_plans.max_plan_length'."));
return
#if PG_VERSION_NUM >= 180000
ret_val
#endif
;
}
if (!pgsp->is_enabled)
{
return
#if PG_VERSION_NUM >= 180000
ret_val
#endif
;
}
es = NewExplainState();
es->format = pgsp->plan_format;
ExplainBeginOutput(es);
ExplainPrintPlan(es, queryDesc);
ExplainEndOutput(es);
append_query_plan(es);
pfree(es->str->data);
return
#if PG_VERSION_NUM >= 180000
ret_val
#endif
;
}
static void
pgsp_ExecutorRun(QueryDesc *queryDesc, ScanDirection direction,
uint64 count
#if PG_VERSION_NUM < 180000
, bool execute_once
#endif
)
{
nest_level++;
PG_TRY();
{
/* These functions return *after* the nested quries do. */
if (prev_ExecutorRun)
prev_ExecutorRun(queryDesc, direction, count
#if PG_VERSION_NUM < 180000
, execute_once);
#else
);
#endif
else
standard_ExecutorRun(queryDesc, direction, count
#if PG_VERSION_NUM < 180000
, execute_once
#endif
);
nest_level--;
/* Wait for reading to complete, then delete. */
if (nest_level < 1) { /* Mark hash entry as empty. */
SpinLockAcquire(&pgsp_cache->mutex);
pgsp_cache->n_plans = 0;
SpinLockRelease(&pgsp_cache->mutex);
}
}
PG_CATCH(); /* Since 13 PG_FINALLY() is available. */
{
nest_level--;
/* Wait for reading to complete, then delete. */
if (nest_level < 1) { /* Mark hash entry as empty. */
SpinLockAcquire(&pgsp_cache->mutex);
pgsp_cache->n_plans = 0;
SpinLockRelease(&pgsp_cache->mutex);
}
PG_RE_THROW();
}
PG_END_TRY();
}
Datum
pg_show_plans(PG_FUNCTION_ARGS)
{
FuncCallContext *funcctx;
TupleDesc tupdesc;
int call_cntr;
int max_calls;
int offset;
int i;
pgspCtx *pgsp_ctx;
HASH_SEQ_STATUS *hash_seq;
pgspEntry *pgsp_tmp_entry;
int curr_nest;
bool is_done;
shmem_safety_check();
if (SRF_IS_FIRSTCALL())
{
MemoryContext oldcontext;
funcctx = SRF_FIRSTCALL_INIT();
oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
LWLockAcquire(pgsp->lock, LW_SHARED);
pgsp_ctx = (pgspCtx *)palloc(sizeof(pgspCtx));
pgsp_ctx->is_done = true;
pgsp_ctx->curr_nest = 0;
pgsp_ctx->hash_seq = (HASH_SEQ_STATUS *)palloc(sizeof(HASH_SEQ_STATUS));
hash_seq_init(pgsp_ctx->hash_seq, pgsp_hash);
funcctx->user_fctx = (void *)pgsp_ctx;
funcctx->max_calls = hash_get_num_entries(pgsp_hash);
if (get_call_result_type(fcinfo, NULL, &tupdesc) != TYPEFUNC_COMPOSITE)
ereport(ERROR,
errcode(ERRCODE_FEATURE_NOT_SUPPORTED),
errmsg("function returning record called in context "
"that cannot accept type record"));
funcctx->tuple_desc = BlessTupleDesc(tupdesc);
MemoryContextSwitchTo(oldcontext);
}
funcctx = SRF_PERCALL_SETUP();
/* Restore context. */
pgsp_ctx = (pgspCtx *)funcctx->user_fctx;
hash_seq = pgsp_ctx->hash_seq;
is_done = pgsp_ctx->is_done;
pgsp_tmp_entry = pgsp_ctx->pgsp_tmp_entry;
curr_nest = pgsp_ctx->curr_nest;
/* Pull other stuff from `funcctx`. */
call_cntr = funcctx->call_cntr;
max_calls = funcctx->max_calls;
if (call_cntr < max_calls)
{
Datum values[5];
bool nulls[5];
HeapTuple htup;
if (is_done) /* Done processing a hash entry? */
{ /* Grab a new one. */
pgsp_tmp_entry = hash_seq_search(hash_seq);
/* Skip empty entries and the ones the user is not
* allowed to see. */
for (;;) {
if (pgsp_tmp_entry->n_plans >= 1) {
if (is_allowed_role())
break;
else if (pgsp_tmp_entry->user_id == GetUserId())
break;
}
if (call_cntr == max_calls-1) { /* No more entries. */
hash_seq_term(hash_seq);
LWLockRelease(pgsp->lock);
SRF_RETURN_DONE(funcctx);
}
pgsp_tmp_entry = hash_seq_search(hash_seq);
call_cntr++;
}
SpinLockAcquire(&pgsp_tmp_entry->mutex);
}
/* A single hash entry may store multiple (nested) plans, so
* count offset to get the desired plan. */
offset = 0;
for (i = 0; i < curr_nest; i++)
offset += pgsp_tmp_entry->plan_len[i] + 1;
MemSet(nulls, 0, sizeof(nulls));
values[0] = Int32GetDatum(pgsp_tmp_entry->hash_key.pid);
values[1] = Int32GetDatum(curr_nest);
values[2] = ObjectIdGetDatum(pgsp_tmp_entry->user_id);
values[3] = ObjectIdGetDatum(pgsp_tmp_entry->db_id);
values[4] = CStringGetTextDatum(pgsp_tmp_entry->plan + offset);
htup = heap_form_tuple(funcctx->tuple_desc, values, nulls);
if (curr_nest < pgsp_tmp_entry->n_plans-1)
{ /* Still have nested plans. */
curr_nest++;
call_cntr--; /* May not be legal, but it works. */
is_done = false;
} else { /* No more nested plans, get a new entry. */
curr_nest = 0;
is_done = true;
SpinLockRelease(&pgsp_tmp_entry->mutex);
}
/* Save values back to the context. */
pgsp_ctx->is_done = is_done;
pgsp_ctx->curr_nest = curr_nest;
pgsp_ctx->pgsp_tmp_entry = pgsp_tmp_entry;
funcctx->call_cntr = call_cntr;
SRF_RETURN_NEXT(funcctx, HeapTupleGetDatum(htup));
} else {
hash_seq_term(hash_seq);
LWLockRelease(pgsp->lock);
SRF_RETURN_DONE(funcctx);
}
}
pg_show_plans-2.1.5/pg_show_plans.control 0000664 0000000 0000000 00000000264 15007316545 0020637 0 ustar 00root root 0000000 0000000 # pg_show_plans extension
comment = 'show query plans of all currently running SQL statements'
default_version = '2.1'
module_pathname = '$libdir/pg_show_plans'
relocatable = true
pg_show_plans-2.1.5/pg_show_plans.md 0000777 0000000 0000000 00000000000 15007316545 0021027 2README.md ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/sql/ 0000775 0000000 0000000 00000000000 15007316545 0015167 5 ustar 00root root 0000000 0000000 pg_show_plans-2.1.5/sql/formats.sql 0000664 0000000 0000000 00000001045 15007316545 0017363 0 ustar 00root root 0000000 0000000 -- explain output on PG12/13 is missing "Async Capable"
select setting::int < 140000 as pg12_13 from pg_settings where name = 'server_version_num';
-- json output
set pg_show_plans.plan_format = 'json';
show pg_show_plans.plan_format;
select * from nest();
-- yaml output
set pg_show_plans.plan_format = 'yaml';
show pg_show_plans.plan_format;
select * from nest();
-- xml output
set pg_show_plans.plan_format = 'xml';
show pg_show_plans.plan_format;
select * from nest();
-- check plan format after reconnect
\c
show pg_show_plans.plan_format;
pg_show_plans-2.1.5/sql/pg_show_plans.sql 0000664 0000000 0000000 00000000745 15007316545 0020561 0 ustar 00root root 0000000 0000000 create extension pg_show_plans;
show pg_show_plans.is_enabled;
show pg_show_plans.max_plan_length;
create function nest()
returns table (level int, plan text)
language plpgsql
as $$
begin
return query
select pg_show_plans.level, pg_show_plans.plan from pg_show_plans
where pg_show_plans.level >= 0;
end;
$$;
-- text output
set pg_show_plans.plan_format = 'text';
show pg_show_plans.plan_format;
select level, plan from pg_show_plans;
select * from nest();