mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-04-06 20:31:03 +08:00
pg_buffercache: Add pg_buffercache_summary()
Using pg_buffercache_summary() is significantly cheaper than querying pg_buffercache and summarizing in SQL. Author: Melih Mutlu <m.melihmutlu@gmail.com> Reviewed-by: Andres Freund <andres@anarazel.de> Reviewed-by: Aleksander Alekseev <aleksander@timescale.com> Reviewed-by: Zhang Mingli <zmlpostgres@gmail.com> Discussion: https://postgr.es/m/CAGPVpCQAXYo54Q%3D8gqBsS%3Du0uk9qhnnq4%2B710BtUhUisX1XGEg%40mail.gmail.com
This commit is contained in:
parent
7f8d9cedb3
commit
2589434ae0
@ -7,7 +7,8 @@ OBJS = \
|
||||
|
||||
EXTENSION = pg_buffercache
|
||||
DATA = pg_buffercache--1.2.sql pg_buffercache--1.2--1.3.sql \
|
||||
pg_buffercache--1.1--1.2.sql pg_buffercache--1.0--1.1.sql
|
||||
pg_buffercache--1.1--1.2.sql pg_buffercache--1.0--1.1.sql \
|
||||
pg_buffercache--1.3--1.4.sql
|
||||
PGFILEDESC = "pg_buffercache - monitoring of shared buffer cache in real-time"
|
||||
|
||||
REGRESS = pg_buffercache
|
||||
|
@ -8,3 +8,36 @@ from pg_buffercache;
|
||||
t
|
||||
(1 row)
|
||||
|
||||
select buffers_used + buffers_unused > 0,
|
||||
buffers_dirty <= buffers_used,
|
||||
buffers_pinned <= buffers_used
|
||||
from pg_buffercache_summary();
|
||||
?column? | ?column? | ?column?
|
||||
----------+----------+----------
|
||||
t | t | t
|
||||
(1 row)
|
||||
|
||||
-- Check that the functions / views can't be accessed by default. To avoid
|
||||
-- having to create a dedicated user, use the pg_database_owner pseudo-role.
|
||||
SET ROLE pg_database_owner;
|
||||
SELECT * FROM pg_buffercache;
|
||||
ERROR: permission denied for view pg_buffercache
|
||||
SELECT * FROM pg_buffercache_pages() AS p (wrong int);
|
||||
ERROR: permission denied for function pg_buffercache_pages
|
||||
SELECT * FROM pg_buffercache_summary();
|
||||
ERROR: permission denied for function pg_buffercache_summary
|
||||
RESET role;
|
||||
-- Check that pg_monitor is allowed to query view / function
|
||||
SET ROLE pg_monitor;
|
||||
SELECT count(*) > 0 FROM pg_buffercache;
|
||||
?column?
|
||||
----------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
|
||||
?column?
|
||||
----------
|
||||
t
|
||||
(1 row)
|
||||
|
||||
|
@ -19,6 +19,7 @@ install_data(
|
||||
'pg_buffercache--1.1--1.2.sql',
|
||||
'pg_buffercache--1.2--1.3.sql',
|
||||
'pg_buffercache--1.2.sql',
|
||||
'pg_buffercache--1.3--1.4.sql',
|
||||
'pg_buffercache.control',
|
||||
kwargs: contrib_data_args,
|
||||
)
|
||||
|
17
contrib/pg_buffercache/pg_buffercache--1.3--1.4.sql
Normal file
17
contrib/pg_buffercache/pg_buffercache--1.3--1.4.sql
Normal file
@ -0,0 +1,17 @@
|
||||
/* contrib/pg_buffercache/pg_buffercache--1.3--1.4.sql */
|
||||
|
||||
-- complain if script is sourced in psql, rather than via ALTER EXTENSION
|
||||
\echo Use "ALTER EXTENSION pg_buffercache UPDATE TO '1.4'" to load this file. \quit
|
||||
|
||||
CREATE FUNCTION pg_buffercache_summary(
|
||||
OUT buffers_used int4,
|
||||
OUT buffers_unused int4,
|
||||
OUT buffers_dirty int4,
|
||||
OUT buffers_pinned int4,
|
||||
OUT usagecount_avg float8)
|
||||
AS 'MODULE_PATHNAME', 'pg_buffercache_summary'
|
||||
LANGUAGE C PARALLEL SAFE;
|
||||
|
||||
-- Don't want these to be available to public.
|
||||
REVOKE ALL ON FUNCTION pg_buffercache_summary() FROM PUBLIC;
|
||||
GRANT EXECUTE ON FUNCTION pg_buffercache_summary() TO pg_monitor;
|
@ -1,5 +1,5 @@
|
||||
# pg_buffercache extension
|
||||
comment = 'examine the shared buffer cache'
|
||||
default_version = '1.3'
|
||||
default_version = '1.4'
|
||||
module_pathname = '$libdir/pg_buffercache'
|
||||
relocatable = true
|
||||
|
@ -17,6 +17,7 @@
|
||||
|
||||
#define NUM_BUFFERCACHE_PAGES_MIN_ELEM 8
|
||||
#define NUM_BUFFERCACHE_PAGES_ELEM 9
|
||||
#define NUM_BUFFERCACHE_SUMMARY_ELEM 5
|
||||
|
||||
PG_MODULE_MAGIC;
|
||||
|
||||
@ -59,6 +60,7 @@ typedef struct
|
||||
* relation node/tablespace/database/blocknum and dirty indicator.
|
||||
*/
|
||||
PG_FUNCTION_INFO_V1(pg_buffercache_pages);
|
||||
PG_FUNCTION_INFO_V1(pg_buffercache_summary);
|
||||
|
||||
Datum
|
||||
pg_buffercache_pages(PG_FUNCTION_ARGS)
|
||||
@ -237,3 +239,68 @@ pg_buffercache_pages(PG_FUNCTION_ARGS)
|
||||
else
|
||||
SRF_RETURN_DONE(funcctx);
|
||||
}
|
||||
|
||||
Datum
|
||||
pg_buffercache_summary(PG_FUNCTION_ARGS)
|
||||
{
|
||||
Datum result;
|
||||
TupleDesc tupledesc;
|
||||
HeapTuple tuple;
|
||||
Datum values[NUM_BUFFERCACHE_SUMMARY_ELEM];
|
||||
bool nulls[NUM_BUFFERCACHE_SUMMARY_ELEM];
|
||||
|
||||
int32 buffers_used = 0;
|
||||
int32 buffers_unused = 0;
|
||||
int32 buffers_dirty = 0;
|
||||
int32 buffers_pinned = 0;
|
||||
int64 usagecount_total = 0;
|
||||
|
||||
if (get_call_result_type(fcinfo, NULL, &tupledesc) != TYPEFUNC_COMPOSITE)
|
||||
elog(ERROR, "return type must be a row type");
|
||||
|
||||
for (int i = 0; i < NBuffers; i++)
|
||||
{
|
||||
BufferDesc *bufHdr;
|
||||
uint32 buf_state;
|
||||
|
||||
/*
|
||||
* This function summarizes the state of all headers. Locking the
|
||||
* buffer headers wouldn't provide an improved result as the state of
|
||||
* the buffer can still change after we release the lock and it'd
|
||||
* noticeably increase the cost of the function.
|
||||
*/
|
||||
bufHdr = GetBufferDescriptor(i);
|
||||
buf_state = pg_atomic_read_u32(&bufHdr->state);
|
||||
|
||||
if (buf_state & BM_VALID)
|
||||
{
|
||||
buffers_used++;
|
||||
usagecount_total += BUF_STATE_GET_USAGECOUNT(buf_state);
|
||||
|
||||
if (buf_state & BM_DIRTY)
|
||||
buffers_dirty++;
|
||||
}
|
||||
else
|
||||
buffers_unused++;
|
||||
|
||||
if (BUF_STATE_GET_REFCOUNT(buf_state) > 0)
|
||||
buffers_pinned++;
|
||||
}
|
||||
|
||||
memset(nulls, 0, sizeof(nulls));
|
||||
values[0] = Int32GetDatum(buffers_used);
|
||||
values[1] = Int32GetDatum(buffers_unused);
|
||||
values[2] = Int32GetDatum(buffers_dirty);
|
||||
values[3] = Int32GetDatum(buffers_pinned);
|
||||
|
||||
if (buffers_used != 0)
|
||||
values[4] = Float8GetDatum((double) usagecount_total / buffers_used);
|
||||
else
|
||||
nulls[4] = true;
|
||||
|
||||
/* Build and return the tuple. */
|
||||
tuple = heap_form_tuple(tupledesc, values, nulls);
|
||||
result = HeapTupleGetDatum(tuple);
|
||||
|
||||
PG_RETURN_DATUM(result);
|
||||
}
|
||||
|
@ -4,3 +4,21 @@ select count(*) = (select setting::bigint
|
||||
from pg_settings
|
||||
where name = 'shared_buffers')
|
||||
from pg_buffercache;
|
||||
|
||||
select buffers_used + buffers_unused > 0,
|
||||
buffers_dirty <= buffers_used,
|
||||
buffers_pinned <= buffers_used
|
||||
from pg_buffercache_summary();
|
||||
|
||||
-- Check that the functions / views can't be accessed by default. To avoid
|
||||
-- having to create a dedicated user, use the pg_database_owner pseudo-role.
|
||||
SET ROLE pg_database_owner;
|
||||
SELECT * FROM pg_buffercache;
|
||||
SELECT * FROM pg_buffercache_pages() AS p (wrong int);
|
||||
SELECT * FROM pg_buffercache_summary();
|
||||
RESET role;
|
||||
|
||||
-- Check that pg_monitor is allowed to query view / function
|
||||
SET ROLE pg_monitor;
|
||||
SELECT count(*) > 0 FROM pg_buffercache;
|
||||
SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
|
||||
|
@ -16,13 +16,28 @@
|
||||
<primary>pg_buffercache_pages</primary>
|
||||
</indexterm>
|
||||
|
||||
<indexterm>
|
||||
<primary>pg_buffercache_summary</primary>
|
||||
</indexterm>
|
||||
|
||||
<para>
|
||||
The module provides a C function <function>pg_buffercache_pages</function>
|
||||
that returns a set of records, plus a view
|
||||
<structname>pg_buffercache</structname> that wraps the function for
|
||||
The module provides the <function>pg_buffercache_pages()</function>
|
||||
function, wrapped in the <structname>pg_buffercache</structname> view, and
|
||||
the <function>pg_buffercache_summary()</function> function.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <function>pg_buffercache_pages()</function> function returns a set of
|
||||
records, each row describing the state of one shared buffer entry. The
|
||||
<structname>pg_buffercache</structname> view wraps the function for
|
||||
convenient use.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
The <function>pg_buffercache_summary()</function> function returns a single
|
||||
row summarizing the state of the shared buffer cache.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
By default, use is restricted to superusers and roles with privileges of the
|
||||
<literal>pg_monitor</literal> role. Access may be granted to others
|
||||
@ -164,6 +179,92 @@
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2>
|
||||
<title>The <function>pg_buffercache_summary()</function> Function</title>
|
||||
|
||||
<para>
|
||||
The definitions of the columns exposed by the function are shown in <xref linkend="pgbuffercache_summary-columns"/>.
|
||||
</para>
|
||||
|
||||
<table id="pgbuffercache_summary-columns">
|
||||
<title><function>pg_buffercache_summary()</function> Output Columns</title>
|
||||
<tgroup cols="1">
|
||||
<thead>
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
Column Type
|
||||
</para>
|
||||
<para>
|
||||
Description
|
||||
</para></entry>
|
||||
</row>
|
||||
</thead>
|
||||
|
||||
<tbody>
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>buffers_used</structfield> <type>int4</type>
|
||||
</para>
|
||||
<para>
|
||||
Number of unused shared buffers
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>buffers_unused</structfield> <type>int4</type>
|
||||
</para>
|
||||
<para>
|
||||
Number of unused shared buffers
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>buffers_dirty</structfield> <type>int4</type>
|
||||
</para>
|
||||
<para>
|
||||
Number of dirty shared buffers
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>buffers_pinned</structfield> <type>int4</type>
|
||||
</para>
|
||||
<para>
|
||||
Number of pinned shared buffers
|
||||
</para></entry>
|
||||
</row>
|
||||
|
||||
<row>
|
||||
<entry role="catalog_table_entry"><para role="column_definition">
|
||||
<structfield>usagecount_avg</structfield> <type>float8</type>
|
||||
</para>
|
||||
<para>
|
||||
Average usagecount of used shared buffers
|
||||
</para></entry>
|
||||
</row>
|
||||
</tbody>
|
||||
</tgroup>
|
||||
</table>
|
||||
|
||||
<para>
|
||||
The <function>pg_buffercache_summary()</function> function returns a
|
||||
single row summarizing the state of all shared buffers. Similar and more
|
||||
detailed information is provided by the
|
||||
<structname>pg_buffercache</structname> view, but
|
||||
<function>pg_buffercache_summary()</function> is significantly cheaper.
|
||||
</para>
|
||||
|
||||
<para>
|
||||
Like the <structname>pg_buffercache</structname> view,
|
||||
<function>pg_buffercache_summary()</function> does not acquire buffer
|
||||
manager locks. Therefore concurrent activity can lead to minor inaccuracies
|
||||
in the result.
|
||||
</para>
|
||||
</sect2>
|
||||
|
||||
<sect2>
|
||||
<title>Sample Output</title>
|
||||
|
||||
@ -191,6 +292,13 @@ regression=# SELECT n.nspname, c.relname, count(*) AS buffers
|
||||
public | gin_test_tbl | 188
|
||||
public | spgist_text_tbl | 182
|
||||
(10 rows)
|
||||
|
||||
|
||||
regression=# SELECT * FROM pg_buffercache_summary();
|
||||
buffers_used | buffers_unused | buffers_dirty | buffers_pinned | usagecount_avg
|
||||
--------------+----------------+---------------+----------------+----------------
|
||||
248 | 2096904 | 39 | 0 | 3.141129
|
||||
(1 row)
|
||||
</screen>
|
||||
</sect2>
|
||||
|
||||
|
Loading…
x
Reference in New Issue
Block a user