Add pg_buffercache_usage_counts() to contrib/pg_buffercache.
It was pointed out that pg_buffercache_summary()'s report of the overall average usage count isn't that useful, and what would be more helpful in many cases is to report totals for each possible usage count. Add a new function to do it like that. Since pg_buffercache 1.4 is already new for v16, we don't need to create a new extension version; we'll just define this as part of 1.4. Nathan Bossart Discussion: https://postgr.es/m/20230130233040.GA2800702@nathanxps13
This commit is contained in:
parent
e056c557ae
commit
f3fa31327e
@ -17,6 +17,12 @@ from pg_buffercache_summary();
|
|||||||
t | t | t
|
t | t | t
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
|
SELECT count(*) > 0 FROM pg_buffercache_usage_counts() WHERE buffers >= 0;
|
||||||
|
?column?
|
||||||
|
----------
|
||||||
|
t
|
||||||
|
(1 row)
|
||||||
|
|
||||||
-- Check that the functions / views can't be accessed by default. To avoid
|
-- 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.
|
-- having to create a dedicated user, use the pg_database_owner pseudo-role.
|
||||||
SET ROLE pg_database_owner;
|
SET ROLE pg_database_owner;
|
||||||
@ -26,6 +32,8 @@ SELECT * FROM pg_buffercache_pages() AS p (wrong int);
|
|||||||
ERROR: permission denied for function pg_buffercache_pages
|
ERROR: permission denied for function pg_buffercache_pages
|
||||||
SELECT * FROM pg_buffercache_summary();
|
SELECT * FROM pg_buffercache_summary();
|
||||||
ERROR: permission denied for function pg_buffercache_summary
|
ERROR: permission denied for function pg_buffercache_summary
|
||||||
|
SELECT * FROM pg_buffercache_usage_counts();
|
||||||
|
ERROR: permission denied for function pg_buffercache_usage_counts
|
||||||
RESET role;
|
RESET role;
|
||||||
-- Check that pg_monitor is allowed to query view / function
|
-- Check that pg_monitor is allowed to query view / function
|
||||||
SET ROLE pg_monitor;
|
SET ROLE pg_monitor;
|
||||||
@ -41,3 +49,9 @@ SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
|
|||||||
t
|
t
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
|
SELECT count(*) > 0 FROM pg_buffercache_usage_counts();
|
||||||
|
?column?
|
||||||
|
----------
|
||||||
|
t
|
||||||
|
(1 row)
|
||||||
|
|
||||||
|
@ -12,6 +12,17 @@ CREATE FUNCTION pg_buffercache_summary(
|
|||||||
AS 'MODULE_PATHNAME', 'pg_buffercache_summary'
|
AS 'MODULE_PATHNAME', 'pg_buffercache_summary'
|
||||||
LANGUAGE C PARALLEL SAFE;
|
LANGUAGE C PARALLEL SAFE;
|
||||||
|
|
||||||
|
CREATE FUNCTION pg_buffercache_usage_counts(
|
||||||
|
OUT usage_count int4,
|
||||||
|
OUT buffers int4,
|
||||||
|
OUT dirty int4,
|
||||||
|
OUT pinned int4)
|
||||||
|
RETURNS SETOF record
|
||||||
|
AS 'MODULE_PATHNAME', 'pg_buffercache_usage_counts'
|
||||||
|
LANGUAGE C PARALLEL SAFE;
|
||||||
|
|
||||||
-- Don't want these to be available to public.
|
-- Don't want these to be available to public.
|
||||||
REVOKE ALL ON FUNCTION pg_buffercache_summary() FROM PUBLIC;
|
REVOKE ALL ON FUNCTION pg_buffercache_summary() FROM PUBLIC;
|
||||||
GRANT EXECUTE ON FUNCTION pg_buffercache_summary() TO pg_monitor;
|
GRANT EXECUTE ON FUNCTION pg_buffercache_summary() TO pg_monitor;
|
||||||
|
REVOKE ALL ON FUNCTION pg_buffercache_usage_counts() FROM PUBLIC;
|
||||||
|
GRANT EXECUTE ON FUNCTION pg_buffercache_usage_counts() TO pg_monitor;
|
||||||
|
@ -18,6 +18,7 @@
|
|||||||
#define NUM_BUFFERCACHE_PAGES_MIN_ELEM 8
|
#define NUM_BUFFERCACHE_PAGES_MIN_ELEM 8
|
||||||
#define NUM_BUFFERCACHE_PAGES_ELEM 9
|
#define NUM_BUFFERCACHE_PAGES_ELEM 9
|
||||||
#define NUM_BUFFERCACHE_SUMMARY_ELEM 5
|
#define NUM_BUFFERCACHE_SUMMARY_ELEM 5
|
||||||
|
#define NUM_BUFFERCACHE_USAGE_COUNTS_ELEM 4
|
||||||
|
|
||||||
PG_MODULE_MAGIC;
|
PG_MODULE_MAGIC;
|
||||||
|
|
||||||
@ -61,6 +62,7 @@ typedef struct
|
|||||||
*/
|
*/
|
||||||
PG_FUNCTION_INFO_V1(pg_buffercache_pages);
|
PG_FUNCTION_INFO_V1(pg_buffercache_pages);
|
||||||
PG_FUNCTION_INFO_V1(pg_buffercache_summary);
|
PG_FUNCTION_INFO_V1(pg_buffercache_summary);
|
||||||
|
PG_FUNCTION_INFO_V1(pg_buffercache_usage_counts);
|
||||||
|
|
||||||
Datum
|
Datum
|
||||||
pg_buffercache_pages(PG_FUNCTION_ARGS)
|
pg_buffercache_pages(PG_FUNCTION_ARGS)
|
||||||
@ -304,3 +306,44 @@ pg_buffercache_summary(PG_FUNCTION_ARGS)
|
|||||||
|
|
||||||
PG_RETURN_DATUM(result);
|
PG_RETURN_DATUM(result);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
Datum
|
||||||
|
pg_buffercache_usage_counts(PG_FUNCTION_ARGS)
|
||||||
|
{
|
||||||
|
ReturnSetInfo *rsinfo = (ReturnSetInfo *) fcinfo->resultinfo;
|
||||||
|
int usage_counts[BM_MAX_USAGE_COUNT + 1] = {0};
|
||||||
|
int dirty[BM_MAX_USAGE_COUNT + 1] = {0};
|
||||||
|
int pinned[BM_MAX_USAGE_COUNT + 1] = {0};
|
||||||
|
Datum values[NUM_BUFFERCACHE_USAGE_COUNTS_ELEM];
|
||||||
|
bool nulls[NUM_BUFFERCACHE_USAGE_COUNTS_ELEM] = {0};
|
||||||
|
|
||||||
|
InitMaterializedSRF(fcinfo, 0);
|
||||||
|
|
||||||
|
for (int i = 0; i < NBuffers; i++)
|
||||||
|
{
|
||||||
|
BufferDesc *bufHdr = GetBufferDescriptor(i);
|
||||||
|
uint32 buf_state = pg_atomic_read_u32(&bufHdr->state);
|
||||||
|
int usage_count;
|
||||||
|
|
||||||
|
usage_count = BUF_STATE_GET_USAGECOUNT(buf_state);
|
||||||
|
usage_counts[usage_count]++;
|
||||||
|
|
||||||
|
if (buf_state & BM_DIRTY)
|
||||||
|
dirty[usage_count]++;
|
||||||
|
|
||||||
|
if (BUF_STATE_GET_REFCOUNT(buf_state) > 0)
|
||||||
|
pinned[usage_count]++;
|
||||||
|
}
|
||||||
|
|
||||||
|
for (int i = 0; i < BM_MAX_USAGE_COUNT + 1; i++)
|
||||||
|
{
|
||||||
|
values[0] = Int32GetDatum(i);
|
||||||
|
values[1] = Int32GetDatum(usage_counts[i]);
|
||||||
|
values[2] = Int32GetDatum(dirty[i]);
|
||||||
|
values[3] = Int32GetDatum(pinned[i]);
|
||||||
|
|
||||||
|
tuplestore_putvalues(rsinfo->setResult, rsinfo->setDesc, values, nulls);
|
||||||
|
}
|
||||||
|
|
||||||
|
return (Datum) 0;
|
||||||
|
}
|
||||||
|
@ -10,15 +10,19 @@ select buffers_used + buffers_unused > 0,
|
|||||||
buffers_pinned <= buffers_used
|
buffers_pinned <= buffers_used
|
||||||
from pg_buffercache_summary();
|
from pg_buffercache_summary();
|
||||||
|
|
||||||
|
SELECT count(*) > 0 FROM pg_buffercache_usage_counts() WHERE buffers >= 0;
|
||||||
|
|
||||||
-- Check that the functions / views can't be accessed by default. To avoid
|
-- 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.
|
-- having to create a dedicated user, use the pg_database_owner pseudo-role.
|
||||||
SET ROLE pg_database_owner;
|
SET ROLE pg_database_owner;
|
||||||
SELECT * FROM pg_buffercache;
|
SELECT * FROM pg_buffercache;
|
||||||
SELECT * FROM pg_buffercache_pages() AS p (wrong int);
|
SELECT * FROM pg_buffercache_pages() AS p (wrong int);
|
||||||
SELECT * FROM pg_buffercache_summary();
|
SELECT * FROM pg_buffercache_summary();
|
||||||
|
SELECT * FROM pg_buffercache_usage_counts();
|
||||||
RESET role;
|
RESET role;
|
||||||
|
|
||||||
-- Check that pg_monitor is allowed to query view / function
|
-- Check that pg_monitor is allowed to query view / function
|
||||||
SET ROLE pg_monitor;
|
SET ROLE pg_monitor;
|
||||||
SELECT count(*) > 0 FROM pg_buffercache;
|
SELECT count(*) > 0 FROM pg_buffercache;
|
||||||
SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
|
SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
|
||||||
|
SELECT count(*) > 0 FROM pg_buffercache_usage_counts();
|
||||||
|
@ -22,9 +22,10 @@
|
|||||||
</indexterm>
|
</indexterm>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
The module provides the <function>pg_buffercache_pages()</function>
|
This module provides the <function>pg_buffercache_pages()</function>
|
||||||
function, wrapped in the <structname>pg_buffercache</structname> view, and
|
function (wrapped in the <structname>pg_buffercache</structname> view),
|
||||||
the <function>pg_buffercache_summary()</function> function.
|
the <function>pg_buffercache_summary()</function> function, and the
|
||||||
|
<function>pg_buffercache_usage_counts()</function> function.
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
@ -39,6 +40,12 @@
|
|||||||
row summarizing the state of the shared buffer cache.
|
row summarizing the state of the shared buffer cache.
|
||||||
</para>
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The <function>pg_buffercache_usage_counts()</function> function returns a set
|
||||||
|
of records, each row describing the number of buffers with a given usage
|
||||||
|
count.
|
||||||
|
</para>
|
||||||
|
|
||||||
<para>
|
<para>
|
||||||
By default, use is restricted to superusers and roles with privileges of the
|
By default, use is restricted to superusers and roles with privileges of the
|
||||||
<literal>pg_monitor</literal> role. Access may be granted to others
|
<literal>pg_monitor</literal> role. Access may be granted to others
|
||||||
@ -243,7 +250,7 @@
|
|||||||
<structfield>usagecount_avg</structfield> <type>float8</type>
|
<structfield>usagecount_avg</structfield> <type>float8</type>
|
||||||
</para>
|
</para>
|
||||||
<para>
|
<para>
|
||||||
Average usagecount of used shared buffers
|
Average usage count of used shared buffers
|
||||||
</para></entry>
|
</para></entry>
|
||||||
</row>
|
</row>
|
||||||
</tbody>
|
</tbody>
|
||||||
@ -266,6 +273,84 @@
|
|||||||
</para>
|
</para>
|
||||||
</sect2>
|
</sect2>
|
||||||
|
|
||||||
|
<sect2>
|
||||||
|
<title>The <function>pg_buffercache_usage_counts()</function> Function</title>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The definitions of the columns exposed by the function are shown in
|
||||||
|
<xref linkend="pgbuffercache_usage_counts-columns"/>.
|
||||||
|
</para>
|
||||||
|
|
||||||
|
<table id="pgbuffercache_usage_counts-columns">
|
||||||
|
<title><function>pg_buffercache_usage_counts()</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>usage_count</structfield> <type>int4</type>
|
||||||
|
</para>
|
||||||
|
<para>
|
||||||
|
A possible buffer usage count
|
||||||
|
</para></entry>
|
||||||
|
</row>
|
||||||
|
|
||||||
|
<row>
|
||||||
|
<entry role="catalog_table_entry"><para role="column_definition">
|
||||||
|
<structfield>buffers</structfield> <type>int4</type>
|
||||||
|
</para>
|
||||||
|
<para>
|
||||||
|
Number of buffers with the usage count
|
||||||
|
</para></entry>
|
||||||
|
</row>
|
||||||
|
|
||||||
|
<row>
|
||||||
|
<entry role="catalog_table_entry"><para role="column_definition">
|
||||||
|
<structfield>dirty</structfield> <type>int4</type>
|
||||||
|
</para>
|
||||||
|
<para>
|
||||||
|
Number of dirty buffers with the usage count
|
||||||
|
</para></entry>
|
||||||
|
</row>
|
||||||
|
|
||||||
|
<row>
|
||||||
|
<entry role="catalog_table_entry"><para role="column_definition">
|
||||||
|
<structfield>pinned</structfield> <type>int4</type>
|
||||||
|
</para>
|
||||||
|
<para>
|
||||||
|
Number of pinned buffers with the usage count
|
||||||
|
</para></entry>
|
||||||
|
</row>
|
||||||
|
</tbody>
|
||||||
|
</tgroup>
|
||||||
|
</table>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
The <function>pg_buffercache_usage_counts()</function> function returns a
|
||||||
|
set of rows summarizing the states of all shared buffers, aggregated over
|
||||||
|
the possible usage count values. Similar and more detailed information is
|
||||||
|
provided by the <structname>pg_buffercache</structname> view, but
|
||||||
|
<function>pg_buffercache_usage_counts()</function> is significantly cheaper.
|
||||||
|
</para>
|
||||||
|
|
||||||
|
<para>
|
||||||
|
Like the <structname>pg_buffercache</structname> view,
|
||||||
|
<function>pg_buffercache_usage_counts()</function> does not acquire buffer
|
||||||
|
manager locks. Therefore concurrent activity can lead to minor inaccuracies
|
||||||
|
in the result.
|
||||||
|
</para>
|
||||||
|
</sect2>
|
||||||
|
|
||||||
<sect2 id="pgbuffercache-sample-output">
|
<sect2 id="pgbuffercache-sample-output">
|
||||||
<title>Sample Output</title>
|
<title>Sample Output</title>
|
||||||
|
|
||||||
@ -300,6 +385,18 @@ regression=# SELECT * FROM pg_buffercache_summary();
|
|||||||
--------------+----------------+---------------+----------------+----------------
|
--------------+----------------+---------------+----------------+----------------
|
||||||
248 | 2096904 | 39 | 0 | 3.141129
|
248 | 2096904 | 39 | 0 | 3.141129
|
||||||
(1 row)
|
(1 row)
|
||||||
|
|
||||||
|
|
||||||
|
regression=# SELECT * FROM pg_buffercache_usage_counts();
|
||||||
|
usage_count | buffers | dirty | pinned
|
||||||
|
-------------+---------+-------+--------
|
||||||
|
0 | 14650 | 0 | 0
|
||||||
|
1 | 1436 | 671 | 0
|
||||||
|
2 | 102 | 88 | 0
|
||||||
|
3 | 23 | 21 | 0
|
||||||
|
4 | 9 | 7 | 0
|
||||||
|
5 | 164 | 106 | 0
|
||||||
|
(6 rows)
|
||||||
</screen>
|
</screen>
|
||||||
</sect2>
|
</sect2>
|
||||||
|
|
||||||
|
Loading…
x
Reference in New Issue
Block a user