feat(prebuilt/postgres): add postgres prebuilt tools (#1473)

## Description

- Adds a read-only PostgreSQL prebuilt tool
`list_autovacuum_configurations`, that returns the autovacuum
configurations name and corresponding settings from pg_settings view.
- Adds a read-only PostgreSQL prebuilt tool
`list_memory_configurations`, that returns the memory configurations
name and corresponding settings from `pg_settings` view.
- Adds a read-only PostgreSQL prebuilt tool `list_top_bloated_tables`,
that returns the top N tables based of dead tuple count. Each row
includes: `schema_name`, `relation_name`, `live_tuple`, `dead_tuple`,
`dead_tuple_percentage`, `last_vacuum`, `last_autovacuum`,
`last_analyze`, `last_autoanalyze`.
    - Parameters supported:
- `limit` (optional): Maximum numbers of results to return. Default: 50
- Adds a read-only PostgreSQL prebuilt tool `list_replication_slots`,
that returns the details of replication slots and WAL retained on it
Each row includes: `slot_name`, `slot_type`, `plugin`, `database`,
`temporary`, `active`, `restart_lsn`, `confirmed_flush_lsn`,
`catalog_min`, `retained_wal`.
- Adds a read-only PostgreSQL prebuilt tool `list_invalid_indexes`, that
returns the details of invalid indexes present in database. Each row
includes: `schema_name`, `index_name`, `table_name`, `index_size`,
`indisready`, `indisvalid`, `index_def`.
- Adds a read-only PostgreSQL prebuilt tool, `get_query_plan`, that
returns the optimizer’s estimated plan for a single SQL statement using
`EXPLAIN (FORMAT JSON)`—without executing the query. Output includes
node types, estimated rows, costs, width, and planner/JIT details when
available. Safe for production use in plan inspection, regression
checks, and query tuning workflows.

**Test Output**
- `list_autovacuum_configurations`

<img width="1442" height="734" alt="image"
src="https://github.com/user-attachments/assets/776b7c78-eefb-4e2a-b71b-5555cbbd7664"
/>

- `list_memory_configurations`
<img width="1423" height="728" alt="image"
src="https://github.com/user-attachments/assets/10167440-c36c-4ee8-83b9-a6ff017d7cb3"
/>

- `list_top_bloated_tables`
<img width="1424" height="733" alt="image"
src="https://github.com/user-attachments/assets/fca3f03c-e6ca-451a-849d-24f2eee058f5"
/>

- `list_replication_slots`
<img width="1411" height="727" alt="image"
src="https://github.com/user-attachments/assets/b0161bdd-ca84-4d4e-81bb-31181856c823"
/>

- `list_invalid_indexes`
<img width="1413" height="731" alt="image"
src="https://github.com/user-attachments/assets/26145cb7-2dfb-40dd-a519-138489e3f1a6"
/>

- `get_query_plan `
<img width="1437" height="727" alt="image"
src="https://github.com/user-attachments/assets/bf674ef6-86a2-4de5-b1d7-78b62cf4928c"
/>

---
> Should include a concise description of the changes (bug or feature),
it's
> impact, along with a summary of the solution

## PR Checklist

---
> Thank you for opening a Pull Request! Before submitting your PR, there
are a
> few things you can do to make sure it goes smoothly:

- [x] Make sure you reviewed

[CONTRIBUTING.md](https://github.com/googleapis/genai-toolbox/blob/main/CONTRIBUTING.md)
- [x] Make sure to open an issue as a

[bug/issue](https://github.com/googleapis/genai-toolbox/issues/new/choose)
before writing your code! That way we can discuss the change, evaluate
  designs, and agree on the general idea
- [x] Ensure the tests and linter pass
- [x] Code coverage does not decrease (if any source code was changed)
- [x] Appropriate docs were updated (if necessary)
- [x] Make sure to add `!` if this involve a breaking change

🛠️ Fixes #<issue_number_goes_here>

---------

Co-authored-by: Averi Kitsch <akitsch@google.com>
This commit is contained in:
isaurabhuttam
2025-09-17 01:45:44 +05:30
committed by GitHub
parent b2b06c72c2
commit edca9dc7d7
5 changed files with 357 additions and 3 deletions

View File

@@ -1385,7 +1385,7 @@ func TestPrebuiltTools(t *testing.T) {
wantToolset: server.ToolsetConfigs{
"alloydb_postgres_database_tools": tools.ToolsetConfig{
Name: "alloydb_postgres_database_tools",
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries"},
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan"},
},
},
},
@@ -1415,7 +1415,7 @@ func TestPrebuiltTools(t *testing.T) {
wantToolset: server.ToolsetConfigs{
"cloud_sql_postgres_database_tools": tools.ToolsetConfig{
Name: "cloud_sql_postgres_database_tools",
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries"},
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan"},
},
},
},
@@ -1495,7 +1495,7 @@ func TestPrebuiltTools(t *testing.T) {
wantToolset: server.ToolsetConfigs{
"postgres_database_tools": tools.ToolsetConfig{
Name: "postgres_database_tools",
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries"},
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan"},
},
},
},

View File

@@ -28,6 +28,12 @@ See guides, [Connect from your IDE](../how-to/connect-ide/_index.md), for detail
* **Tools:**
* `execute_sql`: Executes a SQL query.
* `list_tables`: Lists tables in the database.
* `list_autovacuum_configurations`: Lists autovacuum configurations in the database.
* `list_memory_configurations`: Lists memory-related configurations in the database.
* `list_top_bloated_tables`: List top bloated tables in the database.
* `list_replication_slots`: Lists replication slots in the database.
* `list_invalid_indexes`: Lists invalid indexes in the database.
* `get_query_plan`: Generate the execution plan of a statement.
## AlloyDB Postgres Admin
@@ -102,6 +108,12 @@ See guides, [Connect from your IDE](../how-to/connect-ide/_index.md), for detail
* **Tools:**
* `execute_sql`: Executes a SQL query.
* `list_tables`: Lists tables in the database.
* `list_autovacuum_configurations`: Lists autovacuum configurations in the database.
* `list_memory_configurations`: Lists memory-related configurations in the database.
* `list_top_bloated_tables`: List top bloated tables in the database.
* `list_replication_slots`: Lists replication slots in the database.
* `list_invalid_indexes`: Lists invalid indexes in the database.
* `get_query_plan`: Generate the execution plan of a statement.
## Cloud SQL for SQL Server
@@ -239,6 +251,12 @@ See guides, [Connect from your IDE](../how-to/connect-ide/_index.md), for detail
* **Tools:**
* `execute_sql`: Executes a SQL query.
* `list_tables`: Lists tables in the database.
* `list_autovacuum_configurations`: Lists autovacuum configurations in the database.
* `list_memory_configurations`: Lists memory-related configurations in the database.
* `list_top_bloated_tables`: List top bloated tables in the database.
* `list_replication_slots`: Lists replication slots in the database.
* `list_invalid_indexes`: Lists invalid indexes in the database.
* `get_query_plan`: Generate the execution plan of a statement.
## Spanner (GoogleSQL dialect)

View File

@@ -40,8 +40,120 @@ tools:
source: alloydb-pg-source
description: "List the top N (default 50) currently running queries (state='active') from pg_stat_activity, ordered by longest-running first. Returns pid, user, database, application_name, client_addr, state, wait_event_type/wait_event, backend/xact/query start times, computed query_duration, and the SQL text."
list_autovacuum_configurations:
kind: postgres-sql
source: alloydb-pg-source
description: "List PostgreSQL autovacuum-related configurations (name and current setting) from pg_settings."
statement: |
SELECT name,
setting
FROM pg_settings
WHERE category = 'Autovacuum';
list_memory_configurations:
kind: postgres-sql
source: alloydb-pg-source
description: "List PostgreSQL memory-related configurations (name and current setting) from pg_settings."
statement: |
(
SELECT
name,
pg_size_pretty((setting::bigint * 1024)::bigint) setting
FROM pg_settings
WHERE name IN ('work_mem', 'maintenance_work_mem')
)
UNION ALL
(
SELECT
name,
pg_size_pretty((((setting::bigint) * 8) * 1024)::bigint)
FROM pg_settings
WHERE name IN ('shared_buffers', 'wal_buffers', 'effective_cache_size', 'temp_buffers')
)
ORDER BY 1 DESC;
list_top_bloated_tables:
kind: postgres-sql
source: alloydb-pg-source
description: |
List the top tables by dead-tuple (approximate bloat signal), returning schema, table, live/dead tuples, percentage, and last vacuum/analyze times.
statement: |
SELECT
schemaname AS schema_name,
relname AS relation_name,
n_live_tup AS live_tuples,
n_dead_tup AS dead_tuples,
TRUNC((n_dead_tup::NUMERIC / NULLIF(n_live_tup + n_dead_tup, 0)) * 100, 2) AS dead_tuple_percentage,
last_vacuum,
last_autovacuum,
last_analyze,
last_autoanalyze
FROM pg_stat_user_tables
ORDER BY n_dead_tup DESC
LIMIT COALESCE($1::int, 50);
parameters:
- name: limit
description: "The maximum number of results to return."
type: integer
default: 50
list_replication_slots:
kind: postgres-sql
source: alloydb-pg-source
description: "List key details for all PostgreSQL replication slots (e.g., type, database, active status) and calculates the size of the outstanding WAL that is being prevented from removal by the slot."
statement: |
SELECT
slot_name,
slot_type,
plugin,
database,
temporary,
active,
restart_lsn,
confirmed_flush_lsn,
xmin,
catalog_xmin,
pg_size_pretty(pg_wal_lsn_diff(pg_current_wal_lsn(), restart_lsn)) AS retained_wal
FROM pg_replication_slots;
list_invalid_indexes:
kind: postgres-sql
source: alloydb-pg-source
description: "Lists all invalid PostgreSQL indexes which are taking up disk space but are unusable by the query planner. Typically created by failed CREATE INDEX CONCURRENTLY operations."
statement: |
SELECT
nspname AS schema_name,
indexrelid::regclass AS index_name,
indrelid::regclass AS table_name,
pg_size_pretty(pg_total_relation_size(indexrelid)) AS index_size,
indisready,
indisvalid,
pg_get_indexdef(pg_class.oid) AS index_def
FROM pg_index
JOIN pg_class ON pg_class.oid = pg_index.indexrelid
JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace
WHERE indisvalid = FALSE;
get_query_plan:
kind: postgres-sql
source: alloydb-pg-source
description: "Generate a PostgreSQL EXPLAIN plan in JSON format for a single SQL statement—without executing it. This returns the optimizer's estimated plan, costs, and rows (no ANALYZE, no extra options). Use in production safely for plan inspection, regression checks, and query tuning workflows."
statement: |
EXPLAIN (FORMAT JSON) {{.query}};
templateParameters:
- name: query
type: string
description: "The SQL statement for which you want to generate plan (omit the EXPLAIN keyword)."
required: true
toolsets:
alloydb_postgres_database_tools:
- execute_sql
- list_tables
- list_active_queries
- list_autovacuum_configurations
- list_memory_configurations
- list_top_bloated_tables
- list_replication_slots
- list_invalid_indexes
- get_query_plan

View File

@@ -39,8 +39,120 @@ tools:
source: cloudsql-pg-source
description: "List the top N (default 50) currently running queries (state='active') from pg_stat_activity, ordered by longest-running first. Returns pid, user, database, application_name, client_addr, state, wait_event_type/wait_event, backend/xact/query start times, computed query_duration, and the SQL text."
list_autovacuum_configurations:
kind: postgres-sql
source: cloudsql-pg-source
description: "List PostgreSQL autovacuum-related configurations (name and current setting) from pg_settings."
statement: |
SELECT name,
setting
FROM pg_settings
WHERE category = 'Autovacuum';
list_memory_configurations:
kind: postgres-sql
source: cloudsql-pg-source
description: "List PostgreSQL memory-related configurations (name and current setting) from pg_settings."
statement: |
(
SELECT
name,
pg_size_pretty((setting::bigint * 1024)::bigint) setting
FROM pg_settings
WHERE name IN ('work_mem', 'maintenance_work_mem')
)
UNION ALL
(
SELECT
name,
pg_size_pretty((((setting::bigint) * 8) * 1024)::bigint)
FROM pg_settings
WHERE name IN ('shared_buffers', 'wal_buffers', 'effective_cache_size', 'temp_buffers')
)
ORDER BY 1 DESC;
list_top_bloated_tables:
kind: postgres-sql
source: cloudsql-pg-source
description: |
List the top tables by dead-tuple (approximate bloat signal), returning schema, table, live/dead tuples, percentage, and last vacuum/analyze times.
statement: |
SELECT
schemaname AS schema_name,
relname AS relation_name,
n_live_tup AS live_tuples,
n_dead_tup AS dead_tuples,
TRUNC((n_dead_tup::NUMERIC / NULLIF(n_live_tup + n_dead_tup, 0)) * 100, 2) AS dead_tuple_percentage,
last_vacuum,
last_autovacuum,
last_analyze,
last_autoanalyze
FROM pg_stat_user_tables
ORDER BY n_dead_tup DESC
LIMIT COALESCE($1::int, 50);
parameters:
- name: limit
description: "The maximum number of results to return."
type: integer
default: 50
list_replication_slots:
kind: postgres-sql
source: cloudsql-pg-source
description: "List key details for all PostgreSQL replication slots (e.g., type, database, active status) and calculates the size of the outstanding WAL that is being prevented from removal by the slot."
statement: |
SELECT
slot_name,
slot_type,
plugin,
database,
temporary,
active,
restart_lsn,
confirmed_flush_lsn,
xmin,
catalog_xmin,
pg_size_pretty(pg_wal_lsn_diff(pg_current_wal_lsn(), restart_lsn)) AS retained_wal
FROM pg_replication_slots;
list_invalid_indexes:
kind: postgres-sql
source: cloudsql-pg-source
description: "Lists all invalid PostgreSQL indexes which are taking up disk space but are unusable by the query planner. Typically created by failed CREATE INDEX CONCURRENTLY operations."
statement: |
SELECT
nspname AS schema_name,
indexrelid::regclass AS index_name,
indrelid::regclass AS table_name,
pg_size_pretty(pg_total_relation_size(indexrelid)) AS index_size,
indisready,
indisvalid,
pg_get_indexdef(pg_class.oid) AS index_def
FROM pg_index
JOIN pg_class ON pg_class.oid = pg_index.indexrelid
JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace
WHERE indisvalid = FALSE;
get_query_plan:
kind: postgres-sql
source: cloudsql-pg-source
description: "Generate a PostgreSQL EXPLAIN plan in JSON format for a single SQL statement—without executing it. This returns the optimizer's estimated plan, costs, and rows (no ANALYZE, no extra options). Use in production safely for plan inspection, regression checks, and query tuning workflows."
statement: |
EXPLAIN (FORMAT JSON) {{.query}};
templateParameters:
- name: query
type: string
description: "The SQL statement for which you want to generate plan (omit the EXPLAIN keyword)."
required: true
toolsets:
cloud_sql_postgres_database_tools:
- execute_sql
- list_tables
- list_active_queries
- list_autovacuum_configurations
- list_memory_configurations
- list_top_bloated_tables
- list_replication_slots
- list_invalid_indexes
- get_query_plan

View File

@@ -38,8 +38,120 @@ tools:
source: postgresql-source
description: "List the top N (default 50) currently running queries (state='active') from pg_stat_activity, ordered by longest-running first. Returns pid, user, database, application_name, client_addr, state, wait_event_type/wait_event, backend/xact/query start times, computed query_duration, and the SQL text."
list_autovacuum_configurations:
kind: postgres-sql
source: postgresql-source
description: "List PostgreSQL autovacuum-related configurations (name and current setting) from pg_settings."
statement: |
SELECT name,
setting
FROM pg_settings
WHERE category = 'Autovacuum';
list_memory_configurations:
kind: postgres-sql
source: postgresql-source
description: "List PostgreSQL memory-related configurations (name and current setting) from pg_settings."
statement: |
(
SELECT
name,
pg_size_pretty((setting::bigint * 1024)::bigint) setting
FROM pg_settings
WHERE name IN ('work_mem', 'maintenance_work_mem')
)
UNION ALL
(
SELECT
name,
pg_size_pretty((((setting::bigint) * 8) * 1024)::bigint)
FROM pg_settings
WHERE name IN ('shared_buffers', 'wal_buffers', 'effective_cache_size', 'temp_buffers')
)
ORDER BY 1 DESC;
list_top_bloated_tables:
kind: postgres-sql
source: postgresql-source
description: |
List the top tables by dead-tuple (approximate bloat signal), returning schema, table, live/dead tuples, percentage, and last vacuum/analyze times.
statement: |
SELECT
schemaname AS schema_name,
relname AS relation_name,
n_live_tup AS live_tuples,
n_dead_tup AS dead_tuples,
TRUNC((n_dead_tup::NUMERIC / NULLIF(n_live_tup + n_dead_tup, 0)) * 100, 2) AS dead_tuple_percentage,
last_vacuum,
last_autovacuum,
last_analyze,
last_autoanalyze
FROM pg_stat_user_tables
ORDER BY n_dead_tup DESC
LIMIT COALESCE($1::int, 50);
parameters:
- name: limit
description: "The maximum number of results to return."
type: integer
default: 50
list_replication_slots:
kind: postgres-sql
source: postgresql-source
description: "List key details for all PostgreSQL replication slots (e.g., type, database, active status) and calculates the size of the outstanding WAL that is being prevented from removal by the slot."
statement: |
SELECT
slot_name,
slot_type,
plugin,
database,
temporary,
active,
restart_lsn,
confirmed_flush_lsn,
xmin,
catalog_xmin,
pg_size_pretty(pg_wal_lsn_diff(pg_current_wal_lsn(), restart_lsn)) AS retained_wal
FROM pg_replication_slots;
list_invalid_indexes:
kind: postgres-sql
source: postgresql-source
description: "Lists all invalid PostgreSQL indexes which are taking up disk space but are unusable by the query planner. Typically created by failed CREATE INDEX CONCURRENTLY operations."
statement: |
SELECT
nspname AS schema_name,
indexrelid::regclass AS index_name,
indrelid::regclass AS table_name,
pg_size_pretty(pg_total_relation_size(indexrelid)) AS index_size,
indisready,
indisvalid,
pg_get_indexdef(pg_class.oid) AS index_def
FROM pg_index
JOIN pg_class ON pg_class.oid = pg_index.indexrelid
JOIN pg_namespace ON pg_namespace.oid = pg_class.relnamespace
WHERE indisvalid = FALSE;
get_query_plan:
kind: postgres-sql
source: postgresql-source
description: "Generate a PostgreSQL EXPLAIN plan in JSON format for a single SQL statement—without executing it. This returns the optimizer's estimated plan, costs, and rows (no ANALYZE, no extra options). Use in production safely for plan inspection, regression checks, and query tuning workflows."
statement: |
EXPLAIN (FORMAT JSON) {{.query}};
templateParameters:
- name: query
type: string
description: "The SQL statement for which you want to generate plan (omit the EXPLAIN keyword)."
required: true
toolsets:
postgres_database_tools:
- execute_sql
- list_tables
- list_active_queries
- list_autovacuum_configurations
- list_memory_configurations
- list_top_bloated_tables
- list_replication_slots
- list_invalid_indexes
- get_query_plan