From b9247d0080b6e93488578a732853b9fc00df11cf Mon Sep 17 00:00:00 2001
From: Bertrand Drouvot <bertranddrouvot.pg@gmail.com>
Date: Fri, 21 Nov 2025 05:17:20 +0000
Subject: [PATCH v8 4/4] Add pg_buffercache_os_pages function and view

ba2a3c2302f added a way to check if a buffer is spread across multiple pages.

Adding those new function and view so that one does not need NUMA support
enabled to get this information.

To do so this commit:

- renames pg_buffercache_numa_pages_internal() to pg_buffercache_os_pages()
- keep pg_buffercache_numa_pages() as a backward compatibility wrapper
- re-create the pg_buffercache_numa view on top of pg_buffercache_os_pages using
true as argument

That way we avoid code duplication and the pg_buffercache_os_pages view
does not get performance penalties when NUMA is available.
---
 contrib/pg_buffercache/Makefile               |   2 +-
 .../expected/pg_buffercache.out               |  18 +++
 contrib/pg_buffercache/meson.build            |   1 +
 .../pg_buffercache--1.6--1.7.sql              |  34 +++++
 contrib/pg_buffercache/pg_buffercache.control |   2 +-
 contrib/pg_buffercache/pg_buffercache_pages.c |  59 ++++++---
 contrib/pg_buffercache/sql/pg_buffercache.sql |   8 ++
 doc/src/sgml/pgbuffercache.sgml               | 120 ++++++++++++++++--
 src/tools/pgindent/typedefs.list              |   2 +
 9 files changed, 217 insertions(+), 29 deletions(-)
   4.4% contrib/pg_buffercache/expected/
   3.2% contrib/pg_buffercache/sql/
  38.7% contrib/pg_buffercache/
  53.0% doc/src/sgml/

diff --git a/contrib/pg_buffercache/Makefile b/contrib/pg_buffercache/Makefile
index 5f748543e2e..0e618f66aec 100644
--- a/contrib/pg_buffercache/Makefile
+++ b/contrib/pg_buffercache/Makefile
@@ -9,7 +9,7 @@ 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.3--1.4.sql pg_buffercache--1.4--1.5.sql \
-	pg_buffercache--1.5--1.6.sql
+	pg_buffercache--1.5--1.6.sql pg_buffercache--1.6--1.7.sql
 PGFILEDESC = "pg_buffercache - monitoring of shared buffer cache in real-time"
 
 REGRESS = pg_buffercache pg_buffercache_numa
diff --git a/contrib/pg_buffercache/expected/pg_buffercache.out b/contrib/pg_buffercache/expected/pg_buffercache.out
index 9a9216dc7b1..26c2d5f5710 100644
--- a/contrib/pg_buffercache/expected/pg_buffercache.out
+++ b/contrib/pg_buffercache/expected/pg_buffercache.out
@@ -8,6 +8,16 @@ from pg_buffercache;
  t
 (1 row)
 
+-- For pg_buffercache_os_pages, we expect at least one entry for each buffer
+select count(*) >= (select setting::bigint
+                    from pg_settings
+                    where name = 'shared_buffers')
+from pg_buffercache_os_pages;
+ ?column? 
+----------
+ t
+(1 row)
+
 select buffers_used + buffers_unused > 0,
         buffers_dirty <= buffers_used,
         buffers_pinned <= buffers_used
@@ -28,6 +38,8 @@ SELECT count(*) > 0 FROM pg_buffercache_usage_counts() WHERE buffers >= 0;
 SET ROLE pg_database_owner;
 SELECT * FROM pg_buffercache;
 ERROR:  permission denied for view pg_buffercache
+SELECT * FROM pg_buffercache_os_pages;
+ERROR:  permission denied for view pg_buffercache_os_pages
 SELECT * FROM pg_buffercache_pages() AS p (wrong int);
 ERROR:  permission denied for function pg_buffercache_pages
 SELECT * FROM pg_buffercache_summary();
@@ -43,6 +55,12 @@ SELECT count(*) > 0 FROM pg_buffercache;
  t
 (1 row)
 
+SELECT count(*) > 0 FROM pg_buffercache_os_pages;
+ ?column? 
+----------
+ t
+(1 row)
+
 SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
  ?column? 
 ----------
diff --git a/contrib/pg_buffercache/meson.build b/contrib/pg_buffercache/meson.build
index 7cd039a1df9..7c31141881f 100644
--- a/contrib/pg_buffercache/meson.build
+++ b/contrib/pg_buffercache/meson.build
@@ -24,6 +24,7 @@ install_data(
   'pg_buffercache--1.3--1.4.sql',
   'pg_buffercache--1.4--1.5.sql',
   'pg_buffercache--1.5--1.6.sql',
+  'pg_buffercache--1.6--1.7.sql',
   'pg_buffercache.control',
   kwargs: contrib_data_args,
 )
diff --git a/contrib/pg_buffercache/pg_buffercache--1.6--1.7.sql b/contrib/pg_buffercache/pg_buffercache--1.6--1.7.sql
new file mode 100644
index 00000000000..3cfe723c0c2
--- /dev/null
+++ b/contrib/pg_buffercache/pg_buffercache--1.6--1.7.sql
@@ -0,0 +1,34 @@
+/* contrib/pg_buffercache/pg_buffercache--1.6--1.7.sql */
+
+-- complain if script is sourced in psql, rather than via ALTER EXTENSION
+\echo Use "ALTER EXTENSION pg_buffercache UPDATE TO '1.7'" to load this file. \quit
+
+-- Register the new function with boolean parameter
+-- This function is the core implementation for both OS pages and NUMA queries
+CREATE FUNCTION pg_buffercache_os_pages(IN include_numa boolean,
+    OUT bufferid integer,
+    OUT os_page_num bigint,
+    OUT numa_node integer)
+RETURNS SETOF record
+AS 'MODULE_PATHNAME', 'pg_buffercache_os_pages'
+LANGUAGE C PARALLEL SAFE;
+
+-- Create a view for convenient access.
+CREATE VIEW pg_buffercache_os_pages AS
+    SELECT bufferid, os_page_num
+    FROM pg_buffercache_os_pages(false);
+
+DROP VIEW pg_buffercache_numa;
+
+-- Create a view for convenient access.
+CREATE VIEW pg_buffercache_numa AS
+    SELECT bufferid, os_page_num, numa_node
+    FROM pg_buffercache_os_pages(true);
+
+REVOKE ALL ON FUNCTION pg_buffercache_os_pages(boolean) FROM PUBLIC;
+REVOKE ALL ON pg_buffercache_os_pages FROM PUBLIC;
+REVOKE ALL ON pg_buffercache_numa FROM PUBLIC;
+
+GRANT EXECUTE ON FUNCTION pg_buffercache_os_pages(boolean) TO pg_monitor;
+GRANT SELECT ON pg_buffercache_os_pages TO pg_monitor;
+GRANT SELECT ON pg_buffercache_numa TO pg_monitor;
diff --git a/contrib/pg_buffercache/pg_buffercache.control b/contrib/pg_buffercache/pg_buffercache.control
index b030ba3a6fa..11499550945 100644
--- a/contrib/pg_buffercache/pg_buffercache.control
+++ b/contrib/pg_buffercache/pg_buffercache.control
@@ -1,5 +1,5 @@
 # pg_buffercache extension
 comment = 'examine the shared buffer cache'
-default_version = '1.6'
+default_version = '1.7'
 module_pathname = '$libdir/pg_buffercache'
 relocatable = true
diff --git a/contrib/pg_buffercache/pg_buffercache_pages.c b/contrib/pg_buffercache/pg_buffercache_pages.c
index cc02f7ea9f5..dbd4a601ccb 100644
--- a/contrib/pg_buffercache/pg_buffercache_pages.c
+++ b/contrib/pg_buffercache/pg_buffercache_pages.c
@@ -26,7 +26,7 @@
 #define NUM_BUFFERCACHE_EVICT_RELATION_ELEM 3
 #define NUM_BUFFERCACHE_EVICT_ALL_ELEM 3
 
-#define NUM_BUFFERCACHE_NUMA_ELEM	3
+#define NUM_BUFFERCACHE_OS_PAGES_ELEM	3
 
 /*
  * Get the maximum buffer cache entries needed.
@@ -73,14 +73,16 @@ typedef struct
 } BufferCachePagesContext;
 
 /*
- * Record structure holding the to be exposed cache data.
+ * Record structure holding the to be exposed cache data for OS pages.
+ * This structure is used by pg_buffercache_os_pages() which takes a
+ * boolean parameter to control whether NUMA information is included.
  */
 typedef struct
 {
 	uint32		bufferid;
 	int64		page_num;
 	int32		numa_node;
-} BufferCacheNumaRec;
+} BufferCacheOsPagesRec;
 
 /*
  * Function context for data persisting over repeated calls.
@@ -89,8 +91,8 @@ typedef struct
 {
 	TupleDesc	tupdesc;
 	bool		include_numa;
-	BufferCacheNumaRec *record;
-} BufferCacheNumaContext;
+	BufferCacheOsPagesRec *record;
+} BufferCacheOsPagesContext;
 
 
 /*
@@ -98,6 +100,7 @@ typedef struct
  * relation node/tablespace/database/blocknum and dirty indicator.
  */
 PG_FUNCTION_INFO_V1(pg_buffercache_pages);
+PG_FUNCTION_INFO_V1(pg_buffercache_os_pages);
 PG_FUNCTION_INFO_V1(pg_buffercache_numa_pages);
 PG_FUNCTION_INFO_V1(pg_buffercache_summary);
 PG_FUNCTION_INFO_V1(pg_buffercache_usage_counts);
@@ -319,8 +322,8 @@ pg_buffercache_pages(PG_FUNCTION_ARGS)
 }
 
 /*
- * Internal function to inquire about OS pages mappings for shared buffers,
- * with optional NUMA information.
+ * Inquire about OS pages mappings for shared buffers, with optional NUMA
+ * information.
  *
  * When 'include_numa' is:
  *  - false: Returns buffer to OS page mappings quickly, with numa_node as NULL.
@@ -337,12 +340,12 @@ pg_buffercache_pages(PG_FUNCTION_ARGS)
  * to touch memory pages, so that the inquiry about NUMA memory node doesn't
  * return -2 (which indicates unmapped/unallocated pages).
  */
-static Datum
-pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
+Datum
+pg_buffercache_os_pages(PG_FUNCTION_ARGS)
 {
 	FuncCallContext *funcctx;
 	MemoryContext oldcontext;
-	BufferCacheNumaContext *fctx;	/* User function context. */
+	BufferCacheOsPagesContext *fctx;	/* User function context. */
 	TupleDesc	tupledesc;
 	TupleDesc	expected_tupledesc;
 	HeapTuple	tuple;
@@ -350,6 +353,7 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 
 	if (SRF_IS_FIRSTCALL())
 	{
+		bool		include_numa;
 		int			i,
 					idx;
 		Size		os_page_size;
@@ -359,6 +363,9 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 		char	   *startptr,
 				   *endptr;
 
+		/* Get the boolean parameter that controls NUMA behavior */
+		include_numa = PG_GETARG_BOOL(0);
+
 		/* If NUMA information is requested, initialize NUMA support. */
 		if (include_numa && pg_numa_init() == -1)
 			elog(ERROR, "libnuma initialization failed or NUMA is not supported on this platform");
@@ -446,12 +453,12 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 		oldcontext = MemoryContextSwitchTo(funcctx->multi_call_memory_ctx);
 
 		/* Create a user function context for cross-call persistence */
-		fctx = (BufferCacheNumaContext *) palloc(sizeof(BufferCacheNumaContext));
+		fctx = (BufferCacheOsPagesContext *) palloc(sizeof(BufferCacheOsPagesContext));
 
 		if (get_call_result_type(fcinfo, NULL, &expected_tupledesc) != TYPEFUNC_COMPOSITE)
 			elog(ERROR, "return type must be a row type");
 
-		if (expected_tupledesc->natts != NUM_BUFFERCACHE_NUMA_ELEM)
+		if (expected_tupledesc->natts != NUM_BUFFERCACHE_OS_PAGES_ELEM)
 			elog(ERROR, "incorrect number of output arguments");
 
 		/* Construct a tuple descriptor for the result rows. */
@@ -475,10 +482,10 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 		 */
 		max_entries = GET_MAX_BUFFER_ENTRIES(NBuffers, os_page_size);
 
-		/* Allocate entries for BufferCachePagesRec records. */
-		fctx->record = (BufferCacheNumaRec *)
+		/* Allocate entries for BufferCacheOsPagesRec records. */
+		fctx->record = (BufferCacheOsPagesRec *)
 			MemoryContextAllocHuge(CurrentMemoryContext,
-								   sizeof(BufferCacheNumaRec) * max_entries);
+								   sizeof(BufferCacheOsPagesRec) * max_entries);
 
 		/* Return to original context when allocating transient memory */
 		MemoryContextSwitchTo(oldcontext);
@@ -553,8 +560,8 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 	if (funcctx->call_cntr < funcctx->max_calls)
 	{
 		uint32		i = funcctx->call_cntr;
-		Datum		values[NUM_BUFFERCACHE_NUMA_ELEM];
-		bool		nulls[NUM_BUFFERCACHE_NUMA_ELEM];
+		Datum		values[NUM_BUFFERCACHE_OS_PAGES_ELEM];
+		bool		nulls[NUM_BUFFERCACHE_OS_PAGES_ELEM];
 
 		values[0] = Int32GetDatum(fctx->record[i].bufferid);
 		nulls[0] = false;
@@ -583,11 +590,25 @@ pg_buffercache_numa_pages_internal(PG_FUNCTION_ARGS, bool include_numa)
 		SRF_RETURN_DONE(funcctx);
 }
 
-/* Entry point for extension. */
+/* Backward compatibility wrapper. */
 Datum
 pg_buffercache_numa_pages(PG_FUNCTION_ARGS)
 {
-	return pg_buffercache_numa_pages_internal(fcinfo, true);
+	LOCAL_FCINFO(newfcinfo, 1);
+	Datum		result;
+
+	/* Initialize the new fcinfo structure. */
+	InitFunctionCallInfoData(*newfcinfo, fcinfo->flinfo, 1, fcinfo->fncollation,
+							 NULL, NULL);
+
+	/* Set the include_numa parameter to true. */
+	newfcinfo->args[0].value = BoolGetDatum(true);
+	newfcinfo->args[0].isnull = false;
+
+	/* Call pg_buffercache_os_pages with include_numa=true */
+	result = pg_buffercache_os_pages(newfcinfo);
+
+	return result;
 }
 
 Datum
diff --git a/contrib/pg_buffercache/sql/pg_buffercache.sql b/contrib/pg_buffercache/sql/pg_buffercache.sql
index 47cca1907c7..3c70ee9ef4a 100644
--- a/contrib/pg_buffercache/sql/pg_buffercache.sql
+++ b/contrib/pg_buffercache/sql/pg_buffercache.sql
@@ -5,6 +5,12 @@ select count(*) = (select setting::bigint
                    where name = 'shared_buffers')
 from pg_buffercache;
 
+-- For pg_buffercache_os_pages, we expect at least one entry for each buffer
+select count(*) >= (select setting::bigint
+                    from pg_settings
+                    where name = 'shared_buffers')
+from pg_buffercache_os_pages;
+
 select buffers_used + buffers_unused > 0,
         buffers_dirty <= buffers_used,
         buffers_pinned <= buffers_used
@@ -16,6 +22,7 @@ SELECT count(*) > 0 FROM pg_buffercache_usage_counts() WHERE buffers >= 0;
 -- 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_os_pages;
 SELECT * FROM pg_buffercache_pages() AS p (wrong int);
 SELECT * FROM pg_buffercache_summary();
 SELECT * FROM pg_buffercache_usage_counts();
@@ -24,6 +31,7 @@ RESET role;
 -- Check that pg_monitor is allowed to query view / function
 SET ROLE pg_monitor;
 SELECT count(*) > 0 FROM pg_buffercache;
+SELECT count(*) > 0 FROM pg_buffercache_os_pages;
 SELECT buffers_used + buffers_unused > 0 FROM pg_buffercache_summary();
 SELECT count(*) > 0 FROM pg_buffercache_usage_counts();
 RESET role;
diff --git a/doc/src/sgml/pgbuffercache.sgml b/doc/src/sgml/pgbuffercache.sgml
index 99ad2e68785..67f96e289b2 100644
--- a/doc/src/sgml/pgbuffercache.sgml
+++ b/doc/src/sgml/pgbuffercache.sgml
@@ -46,8 +46,9 @@
  <para>
   This module provides the <function>pg_buffercache_pages()</function>
   function (wrapped in the <structname>pg_buffercache</structname> view), the
-  <function>pg_buffercache_numa_pages()</function> function (wrapped in the
-  <structname>pg_buffercache_numa</structname> view), the
+  <function>pg_buffercache_os_pages()</function> function (wrapped in the
+  <structname>pg_buffercache_os_pages</structname> and
+  <structname>pg_buffercache_numa</structname> views), the
   <function>pg_buffercache_summary()</function> function, the
   <function>pg_buffercache_usage_counts()</function> function, the
   <function>pg_buffercache_evict()</function> function, the
@@ -63,12 +64,14 @@
  </para>
 
  <para>
-  The <function>pg_buffercache_numa_pages()</function> function provides
-  <acronym>NUMA</acronym> node mappings for shared buffer entries. This
-  information is not part of <function>pg_buffercache_pages()</function>
-  itself, as it is much slower to retrieve.
-  The <structname>pg_buffercache_numa</structname> view wraps the function for
-  convenient use.
+  The <function>pg_buffercache_os_pages()</function> function provides OS
+  pages mappings for shared buffer entries. When its argument is <literal>true</literal>,
+  it also provides <acronym>NUMA</acronym> node mappings for shared buffer entries (
+  this information is not part of <function>pg_buffercache_pages()</function>
+  itself, as it is much slower to retrieve).
+  The <structname>pg_buffercache_os_pages</structname> and <structname>pg_buffercache_numa</structname>
+  views wrap the function for convenient use (with its argument set to <literal>false</literal>
+  and <literal>true</literal> respectively).
  </para>
 
  <para>
@@ -242,6 +245,52 @@
   </para>
  </sect2>
 
+ <sect2 id="pgbuffercache-pg-buffercache-os-pages">
+  <title>The <structname>pg_buffercache_os_pages</structname> View</title>
+
+  <para>
+   The definitions of the columns exposed by the view are shown in <xref linkend="pgbuffercache-os-pages-columns"/>.
+  </para>
+
+  <table id="pgbuffercache-os-pages-columns">
+   <title><structname>pg_buffercache_os_pages</structname> 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>bufferid</structfield> <type>integer</type>
+      </para>
+      <para>
+       ID, in the range 1..<varname>shared_buffers</varname>
+      </para></entry>
+     </row>
+
+     <row>
+      <entry role="catalog_table_entry"><para role="column_definition">
+       <structfield>os_page_num</structfield> <type>bigint</type>
+      </para>
+      <para>
+       Number of OS memory page for this buffer
+      </para></entry>
+     </row>
+
+    </tbody>
+   </tgroup>
+  </table>
+
+ </sect2>
+
  <sect2 id="pgbuffercache-pg-buffercache-numa">
   <title>The <structname>pg_buffercache_numa</structname> View</title>
 
@@ -558,6 +607,61 @@ regression=# SELECT n.nspname, c.relname, count(*) AS buffers
  public     | spgist_text_tbl        |     182
 (10 rows)
 
+regression=# SELECT pages_per_buffer, COUNT(*) as buffer_count
+             FROM (
+                   SELECT bufferid, COUNT(*) as pages_per_buffer
+                   FROM pg_buffercache_os_pages
+                   GROUP BY bufferid
+                  )
+             GROUP BY pages_per_buffer
+             ORDER BY pages_per_buffer;
+
+ pages_per_buffer | buffer_count
+------------------+--------------
+                1 |       261120
+                2 |         1024
+(2 rows)
+
+regression=# SELECT n.nspname, c.relname, count(*) AS buffers_on_multiple_pages
+             FROM pg_buffercache b JOIN pg_class c
+             ON b.relfilenode = pg_relation_filenode(c.oid) AND
+                b.reldatabase IN (0, (SELECT oid FROM pg_database
+                                      WHERE datname = current_database()))
+             JOIN pg_namespace n ON n.oid = c.relnamespace
+             JOIN (SELECT bufferid FROM pg_buffercache_os_pages
+                   GROUP BY bufferid HAVING count(*) > 1) m on m.bufferid = b.bufferid
+             GROUP BY n.nspname, c.relname
+             ORDER BY 3 DESC
+             LIMIT 10;
+
+  nspname   |           relname            | buffers_on_multiple_pages
+------------+------------------------------+---------------------------
+ public     | delete_test_table            |                         3
+ public     | gin_test_idx                 |                         2
+ pg_catalog | pg_depend                    |                         2
+ public     | quad_poly_tbl                |                         2
+ pg_catalog | pg_depend_reference_index    |                         1
+ pg_catalog | pg_index_indexrelid_index    |                         1
+ pg_catalog | pg_constraint_contypid_index |                         1
+ pg_catalog | pg_statistic                 |                         1
+ pg_catalog | pg_depend_depender_index     |                         1
+ pg_catalog | pg_operator                  |                         1
+(10 rows)
+
+
+  nspname   |             relname             | buffers_on_multiple_pages
+------------+---------------------------------+---------------------------
+ public     | gin_test_tbl                    |                         4
+ public     | delete_test_table               |                         4
+ public     | tenk1                           |                         4
+ pg_catalog | pg_attribute_relid_attnum_index |                         4
+ pg_catalog | pg_class                        |                         2
+ pg_catalog | pg_depend_depender_index        |                         2
+ pg_catalog | pg_attribute                    |                         2
+ pg_catalog | pg_opfamily                     |                         2
+ pg_catalog | pg_opclass_oid_index            |                         2
+ pg_catalog | pg_description                  |                         2
+(10 rows)
 
 regression=# SELECT * FROM pg_buffercache_summary();
  buffers_used | buffers_unused | buffers_dirty | buffers_pinned | usagecount_avg
diff --git a/src/tools/pgindent/typedefs.list b/src/tools/pgindent/typedefs.list
index c751c25a04d..f6a398881f6 100644
--- a/src/tools/pgindent/typedefs.list
+++ b/src/tools/pgindent/typedefs.list
@@ -340,6 +340,8 @@ BufferAccessStrategy
 BufferAccessStrategyType
 BufferCacheNumaContext
 BufferCacheNumaRec
+BufferCacheOsPagesContext
+BufferCacheOsPagesRec
 BufferCachePagesContext
 BufferCachePagesRec
 BufferDesc
-- 
2.34.1

