mirror of
https://github.com/googleapis/genai-toolbox.git
synced 2026-01-10 07:58:12 -05:00
feat: add list-table-stats-tool to list table statistics. (#2055)
Adds the following tools for Postgres: (1) list_table_stats: Lists table statistics in the database. . <img width="3446" height="1304" alt="image" src="https://github.com/user-attachments/assets/68951edc-8d99-460e-a1ac-2d3da9388baf" /> <img width="2870" height="1338" alt="image" src="https://github.com/user-attachments/assets/100a3b7d-202d-4dfd-b046-5dab4390ba41" /> > 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 #1738
This commit is contained in:
@@ -196,6 +196,7 @@ import (
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslistsequences"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslisttables"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslisttablespaces"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslisttablestats"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslisttriggers"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslistviews"
|
||||
_ "github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslongrunningtransactions"
|
||||
|
||||
@@ -1488,7 +1488,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", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles"},
|
||||
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles", "list_table_stats"},
|
||||
},
|
||||
},
|
||||
},
|
||||
@@ -1518,7 +1518,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", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles"},
|
||||
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles", "list_table_stats"},
|
||||
},
|
||||
},
|
||||
},
|
||||
@@ -1618,7 +1618,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", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles"},
|
||||
ToolNames: []string{"execute_sql", "list_tables", "list_active_queries", "list_available_extensions", "list_installed_extensions", "list_autovacuum_configurations", "list_memory_configurations", "list_top_bloated_tables", "list_replication_slots", "list_invalid_indexes", "get_query_plan", "list_views", "list_schemas", "database_overview", "list_triggers", "list_indexes", "list_sequences", "long_running_transactions", "list_locks", "replication_stats", "list_query_stats", "get_column_cardinality", "list_publication_tables", "list_tablespaces", "list_pg_settings", "list_database_stats", "list_roles", "list_table_stats"},
|
||||
},
|
||||
},
|
||||
},
|
||||
|
||||
@@ -77,6 +77,9 @@ cluster][alloydb-free-trial].
|
||||
- [`postgres-get-column-cardinality`](../tools/postgres/postgres-get-column-cardinality.md)
|
||||
List cardinality of columns in a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-table-stats`](../tools/postgres/postgres-list-table-stats.md)
|
||||
List statistics of a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-publication-tables`](../tools/postgres/postgres-list-publication-tables.md)
|
||||
List publication tables in a PostgreSQL database.
|
||||
|
||||
|
||||
@@ -58,6 +58,7 @@ to a database by following these instructions][csql-pg-quickstart].
|
||||
|
||||
- [`postgres-list-sequences`](../tools/postgres/postgres-list-sequences.md)
|
||||
List sequences in a PostgreSQL database.
|
||||
|
||||
- [`postgres-long-running-transactions`](../tools/postgres/postgres-long-running-transactions.md)
|
||||
List long running transactions in a PostgreSQL database.
|
||||
|
||||
@@ -73,6 +74,9 @@ to a database by following these instructions][csql-pg-quickstart].
|
||||
- [`postgres-get-column-cardinality`](../tools/postgres/postgres-get-column-cardinality.md)
|
||||
List cardinality of columns in a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-table-stats`](../tools/postgres/postgres-list-table-stats.md)
|
||||
List statistics of a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-publication-tables`](../tools/postgres/postgres-list-publication-tables.md)
|
||||
List publication tables in a PostgreSQL database.
|
||||
|
||||
|
||||
@@ -68,6 +68,9 @@ reputation for reliability, feature robustness, and performance.
|
||||
- [`postgres-get-column-cardinality`](../tools/postgres/postgres-get-column-cardinality.md)
|
||||
List cardinality of columns in a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-table-stats`](../tools/postgres/postgres-list-table-stats.md)
|
||||
List statistics of a table in a PostgreSQL database.
|
||||
|
||||
- [`postgres-list-publication-tables`](../tools/postgres/postgres-list-publication-tables.md)
|
||||
List publication tables in a PostgreSQL database.
|
||||
|
||||
|
||||
171
docs/en/resources/tools/postgres/postgres-list-table-stats.md
Normal file
171
docs/en/resources/tools/postgres/postgres-list-table-stats.md
Normal file
@@ -0,0 +1,171 @@
|
||||
---
|
||||
title: "postgres-list-table-stats"
|
||||
type: docs
|
||||
weight: 1
|
||||
description: >
|
||||
The "postgres-list-table-stats" tool reports table statistics including size, scan metrics, and bloat indicators for PostgreSQL tables.
|
||||
aliases:
|
||||
- /resources/tools/postgres-list-table-stats
|
||||
---
|
||||
|
||||
## About
|
||||
|
||||
The `postgres-list-table-stats` tool queries `pg_stat_all_tables` to provide comprehensive statistics about tables in the database. It calculates useful metrics like index scan ratio and dead row ratio to help identify performance issues and table bloat.
|
||||
|
||||
Compatible sources:
|
||||
|
||||
- [alloydb-postgres](../../sources/alloydb-pg.md)
|
||||
- [cloud-sql-postgres](../../sources/cloud-sql-pg.md)
|
||||
- [postgres](../../sources/postgres.md)
|
||||
|
||||
The tool returns a JSON array where each element represents statistics for a table, including scan metrics, row counts, and vacuum history. Results are sorted by sequential scans by default and limited to 50 rows.
|
||||
|
||||
## Example
|
||||
|
||||
```yaml
|
||||
tools:
|
||||
list_table_stats:
|
||||
kind: postgres-list-table-stats
|
||||
source: postgres-source
|
||||
description: "Lists table statistics including size, scans, and bloat metrics."
|
||||
```
|
||||
|
||||
### Example Requests
|
||||
|
||||
**List default tables in public schema:**
|
||||
```json
|
||||
{}
|
||||
```
|
||||
|
||||
**Filter by specific table name:**
|
||||
```json
|
||||
{
|
||||
"table_name": "users"
|
||||
}
|
||||
```
|
||||
|
||||
**Filter by owner and sort by size:**
|
||||
```json
|
||||
{
|
||||
"owner": "app_user",
|
||||
"sort_by": "size",
|
||||
"limit": 10
|
||||
}
|
||||
```
|
||||
|
||||
**Find tables with high dead row ratio:**
|
||||
```json
|
||||
{
|
||||
"sort_by": "dead_rows",
|
||||
"limit": 20
|
||||
}
|
||||
```
|
||||
|
||||
### Example Response
|
||||
|
||||
```json
|
||||
[
|
||||
{
|
||||
"schema_name": "public",
|
||||
"table_name": "users",
|
||||
"owner": "postgres",
|
||||
"total_size_bytes": 8388608,
|
||||
"seq_scan": 150,
|
||||
"idx_scan": 450,
|
||||
"idx_scan_ratio_percent": 75.0,
|
||||
"live_rows": 50000,
|
||||
"dead_rows": 1200,
|
||||
"dead_row_ratio_percent": 2.34,
|
||||
"n_tup_ins": 52000,
|
||||
"n_tup_upd": 12500,
|
||||
"n_tup_del": 800,
|
||||
"last_vacuum": "2025-11-27T10:30:00Z",
|
||||
"last_autovacuum": "2025-11-27T09:15:00Z",
|
||||
"last_autoanalyze": "2025-11-27T09:16:00Z"
|
||||
},
|
||||
{
|
||||
"schema_name": "public",
|
||||
"table_name": "orders",
|
||||
"owner": "postgres",
|
||||
"total_size_bytes": 16777216,
|
||||
"seq_scan": 50,
|
||||
"idx_scan": 1200,
|
||||
"idx_scan_ratio_percent": 96.0,
|
||||
"live_rows": 100000,
|
||||
"dead_rows": 5000,
|
||||
"dead_row_ratio_percent": 4.76,
|
||||
"n_tup_ins": 120000,
|
||||
"n_tup_upd": 45000,
|
||||
"n_tup_del": 15000,
|
||||
"last_vacuum": "2025-11-26T14:22:00Z",
|
||||
"last_autovacuum": "2025-11-27T02:30:00Z",
|
||||
"last_autoanalyze": "2025-11-27T02:31:00Z"
|
||||
}
|
||||
]
|
||||
```
|
||||
|
||||
## Parameters
|
||||
|
||||
| parameter | type | required | default | description |
|
||||
|-------------|---------|----------|---------|-------------|
|
||||
| schema_name | string | false | "public" | Optional: A specific schema name to filter by (supports partial matching) |
|
||||
| table_name | string | false | null | Optional: A specific table name to filter by (supports partial matching) |
|
||||
| owner | string | false | null | Optional: A specific owner to filter by (supports partial matching) |
|
||||
| sort_by | string | false | null | Optional: The column to sort by. Valid values: `size`, `dead_rows`, `seq_scan`, `idx_scan` (defaults to `seq_scan`) |
|
||||
| limit | integer | false | 50 | Optional: The maximum number of results to return |
|
||||
|
||||
## Output Fields Reference
|
||||
|
||||
| field | type | description |
|
||||
|------------------------|-----------|-------------|
|
||||
| schema_name | string | Name of the schema containing the table. |
|
||||
| table_name | string | Name of the table. |
|
||||
| owner | string | PostgreSQL user who owns the table. |
|
||||
| total_size_bytes | integer | Total size of the table including all indexes in bytes. |
|
||||
| seq_scan | integer | Number of sequential (full table) scans performed on this table. |
|
||||
| idx_scan | integer | Number of index scans performed on this table. |
|
||||
| idx_scan_ratio_percent | decimal | Percentage of total scans (seq_scan + idx_scan) that used an index. A low ratio may indicate missing or ineffective indexes. |
|
||||
| live_rows | integer | Number of live (non-deleted) rows in the table. |
|
||||
| dead_rows | integer | Number of dead (deleted but not yet vacuumed) rows in the table. |
|
||||
| dead_row_ratio_percent | decimal | Percentage of dead rows relative to total rows. High values indicate potential table bloat. |
|
||||
| n_tup_ins | integer | Total number of rows inserted into this table. |
|
||||
| n_tup_upd | integer | Total number of rows updated in this table. |
|
||||
| n_tup_del | integer | Total number of rows deleted from this table. |
|
||||
| last_vacuum | timestamp | Timestamp of the last manual VACUUM operation on this table (null if never manually vacuumed). |
|
||||
| last_autovacuum | timestamp | Timestamp of the last automatic vacuum operation on this table. |
|
||||
| last_autoanalyze | timestamp | Timestamp of the last automatic analyze operation on this table. |
|
||||
|
||||
## Interpretation Guide
|
||||
|
||||
### Index Scan Ratio (`idx_scan_ratio_percent`)
|
||||
|
||||
- **High ratio (> 80%)**: Table queries are efficiently using indexes. This is typically desirable.
|
||||
- **Low ratio (< 20%)**: Many sequential scans indicate missing indexes or queries that cannot use existing indexes effectively. Consider adding indexes to frequently searched columns.
|
||||
- **0%**: No index scans performed; all queries performed sequential scans. May warrant index investigation.
|
||||
|
||||
### Dead Row Ratio (`dead_row_ratio_percent`)
|
||||
|
||||
- **< 2%**: Healthy table with minimal bloat.
|
||||
- **2-5%**: Moderate bloat; consider running VACUUM if not recent.
|
||||
- **> 5%**: High bloat; may benefit from manual VACUUM or VACUUM FULL.
|
||||
|
||||
### Vacuum History
|
||||
|
||||
- **Null `last_vacuum`**: Table has never been manually vacuumed; relies on autovacuum.
|
||||
- **Recent `last_autovacuum`**: Autovacuum is actively managing the table.
|
||||
- **Stale timestamps**: Consider running manual VACUUM and ANALYZE if maintenance windows exist.
|
||||
|
||||
## Performance Considerations
|
||||
|
||||
- Statistics are collected from `pg_stat_all_tables`, which resets on PostgreSQL restart.
|
||||
- Run `ANALYZE` on tables to update statistics for accurate query planning.
|
||||
- The tool defaults to limiting results to 50 rows; adjust the `limit` parameter for larger result sets.
|
||||
- Filtering by schema, table name, or owner uses `LIKE` pattern matching (supports partial matches).
|
||||
|
||||
## Use Cases
|
||||
|
||||
- **Finding ineffective indexes**: Identify tables with low `idx_scan_ratio_percent` to evaluate index strategy.
|
||||
- **Detecting table bloat**: Sort by `dead_rows` to find tables needing VACUUM.
|
||||
- **Monitoring growth**: Track `total_size_bytes` over time for capacity planning.
|
||||
- **Audit maintenance**: Check `last_autovacuum` and `last_autoanalyze` timestamps to ensure maintenance tasks are running.
|
||||
- **Understanding workload**: Examine `seq_scan` vs `idx_scan` ratios to understand query patterns.
|
||||
@@ -200,6 +200,10 @@ tools:
|
||||
kind: postgres-get-column-cardinality
|
||||
source: alloydb-pg-source
|
||||
|
||||
list_table_stats:
|
||||
kind: postgres-list-table-stats
|
||||
source: alloydb-pg-source
|
||||
|
||||
list_publication_tables:
|
||||
kind: postgres-list-publication-tables
|
||||
source: alloydb-pg-source
|
||||
@@ -249,3 +253,4 @@ toolsets:
|
||||
- list_pg_settings
|
||||
- list_database_stats
|
||||
- list_roles
|
||||
- list_table_stats
|
||||
|
||||
@@ -201,6 +201,10 @@ tools:
|
||||
get_column_cardinality:
|
||||
kind: postgres-get-column-cardinality
|
||||
source: cloudsql-pg-source
|
||||
|
||||
list_table_stats:
|
||||
kind: postgres-list-table-stats
|
||||
source: cloudsql-pg-source
|
||||
|
||||
list_publication_tables:
|
||||
kind: postgres-list-publication-tables
|
||||
@@ -251,3 +255,4 @@ toolsets:
|
||||
- list_pg_settings
|
||||
- list_database_stats
|
||||
- list_roles
|
||||
- list_table_stats
|
||||
|
||||
@@ -201,6 +201,10 @@ tools:
|
||||
kind: postgres-get-column-cardinality
|
||||
source: postgresql-source
|
||||
|
||||
list_table_stats:
|
||||
kind: postgres-list-table-stats
|
||||
source: postgresql-source
|
||||
|
||||
list_publication_tables:
|
||||
kind: postgres-list-publication-tables
|
||||
source: postgresql-source
|
||||
@@ -250,3 +254,4 @@ toolsets:
|
||||
- list_pg_settings
|
||||
- list_database_stats
|
||||
- list_roles
|
||||
- list_table_stats
|
||||
|
||||
@@ -0,0 +1,245 @@
|
||||
// Copyright 2025 Google LLC
|
||||
//
|
||||
// Licensed under the Apache License, Version 2.0 (the "License");
|
||||
// you may not use this file except in compliance with the License.
|
||||
// You may obtain a copy of the License at
|
||||
//
|
||||
// http://www.apache.org/licenses/LICENSE-2.0
|
||||
//
|
||||
// Unless required by applicable law or agreed to in writing, software
|
||||
// distributed under the License is distributed on an "AS IS" BASIS,
|
||||
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||
// See the License for the specific language governing permissions and
|
||||
// limitations under the License.
|
||||
|
||||
package postgreslisttablestats
|
||||
|
||||
import (
|
||||
"context"
|
||||
"fmt"
|
||||
|
||||
yaml "github.com/goccy/go-yaml"
|
||||
"github.com/googleapis/genai-toolbox/internal/sources"
|
||||
"github.com/googleapis/genai-toolbox/internal/sources/alloydbpg"
|
||||
"github.com/googleapis/genai-toolbox/internal/sources/cloudsqlpg"
|
||||
"github.com/googleapis/genai-toolbox/internal/sources/postgres"
|
||||
"github.com/googleapis/genai-toolbox/internal/tools"
|
||||
"github.com/googleapis/genai-toolbox/internal/util/parameters"
|
||||
"github.com/jackc/pgx/v5/pgxpool"
|
||||
)
|
||||
|
||||
const kind string = "postgres-list-table-stats"
|
||||
|
||||
const listTableStats = `
|
||||
WITH table_stats AS (
|
||||
SELECT
|
||||
s.schemaname AS schema_name,
|
||||
s.relname AS table_name,
|
||||
pg_catalog.pg_get_userbyid(c.relowner) AS owner,
|
||||
pg_total_relation_size(s.relid) AS total_size_bytes,
|
||||
s.seq_scan,
|
||||
s.idx_scan,
|
||||
-- Ratio of index scans to total scans
|
||||
CASE
|
||||
WHEN (s.seq_scan + s.idx_scan) = 0 THEN 0
|
||||
ELSE round((s.idx_scan * 100.0) / (s.seq_scan + s.idx_scan), 2)
|
||||
END AS idx_scan_ratio_percent,
|
||||
s.n_live_tup AS live_rows,
|
||||
s.n_dead_tup AS dead_rows,
|
||||
-- Percentage of rows that are "dead" (bloat)
|
||||
CASE
|
||||
WHEN (s.n_live_tup + s.n_dead_tup) = 0 THEN 0
|
||||
ELSE round((s.n_dead_tup * 100.0) / (s.n_live_tup + s.n_dead_tup), 2)
|
||||
END AS dead_row_ratio_percent,
|
||||
s.n_tup_ins,
|
||||
s.n_tup_upd,
|
||||
s.n_tup_del,
|
||||
s.last_vacuum,
|
||||
s.last_autovacuum,
|
||||
s.last_autoanalyze
|
||||
FROM pg_stat_all_tables s
|
||||
JOIN pg_catalog.pg_class c ON s.relid = c.oid
|
||||
)
|
||||
SELECT *
|
||||
FROM table_stats
|
||||
WHERE
|
||||
($1::text IS NULL OR schema_name LIKE '%' || $1::text || '%')
|
||||
AND ($2::text IS NULL OR table_name LIKE '%' || $2::text || '%')
|
||||
AND ($3::text IS NULL OR owner LIKE '%' || $3::text || '%')
|
||||
ORDER BY
|
||||
CASE
|
||||
WHEN $4::text = 'size' THEN total_size_bytes
|
||||
WHEN $4::text = 'dead_rows' THEN dead_rows
|
||||
WHEN $4::text = 'seq_scan' THEN seq_scan
|
||||
WHEN $4::text = 'idx_scan' THEN idx_scan
|
||||
ELSE seq_scan
|
||||
END DESC
|
||||
LIMIT COALESCE($5::int, 50);
|
||||
`
|
||||
|
||||
func init() {
|
||||
if !tools.Register(kind, newConfig) {
|
||||
panic(fmt.Sprintf("tool kind %q already registered", kind))
|
||||
}
|
||||
}
|
||||
|
||||
func newConfig(ctx context.Context, name string, decoder *yaml.Decoder) (tools.ToolConfig, error) {
|
||||
actual := Config{Name: name}
|
||||
if err := decoder.DecodeContext(ctx, &actual); err != nil {
|
||||
return nil, err
|
||||
}
|
||||
return actual, nil
|
||||
}
|
||||
|
||||
type compatibleSource interface {
|
||||
PostgresPool() *pgxpool.Pool
|
||||
}
|
||||
|
||||
// validate compatible sources are still compatible
|
||||
var _ compatibleSource = &alloydbpg.Source{}
|
||||
var _ compatibleSource = &cloudsqlpg.Source{}
|
||||
var _ compatibleSource = &postgres.Source{}
|
||||
|
||||
var compatibleSources = [...]string{alloydbpg.SourceKind, cloudsqlpg.SourceKind, postgres.SourceKind}
|
||||
|
||||
type Config struct {
|
||||
Name string `yaml:"name" validate:"required"`
|
||||
Kind string `yaml:"kind" validate:"required"`
|
||||
Source string `yaml:"source" validate:"required"`
|
||||
Description string `yaml:"description"`
|
||||
AuthRequired []string `yaml:"authRequired"`
|
||||
}
|
||||
|
||||
// validate interface
|
||||
var _ tools.ToolConfig = Config{}
|
||||
|
||||
func (cfg Config) ToolConfigKind() string {
|
||||
return kind
|
||||
}
|
||||
|
||||
func (cfg Config) Initialize(srcs map[string]sources.Source) (tools.Tool, error) {
|
||||
// verify source exists
|
||||
rawS, ok := srcs[cfg.Source]
|
||||
if !ok {
|
||||
return nil, fmt.Errorf("no source named %q configured", cfg.Source)
|
||||
}
|
||||
|
||||
// verify the source is compatible
|
||||
s, ok := rawS.(compatibleSource)
|
||||
if !ok {
|
||||
return nil, fmt.Errorf("invalid source for %q tool: source kind must be one of %q", kind, compatibleSources)
|
||||
}
|
||||
|
||||
allParameters := parameters.Parameters{
|
||||
parameters.NewStringParameterWithDefault("schema_name", "public", "Optional: A specific schema name to filter by"),
|
||||
parameters.NewStringParameterWithRequired("table_name", "Optional: A specific table name to filter by", false),
|
||||
parameters.NewStringParameterWithRequired("owner", "Optional: A specific owner to filter by", false),
|
||||
parameters.NewStringParameterWithRequired("sort_by", "Optional: The column to sort by", false),
|
||||
parameters.NewIntParameterWithDefault("limit", 50, "Optional: The maximum number of results to return"),
|
||||
}
|
||||
paramManifest := allParameters.Manifest()
|
||||
|
||||
if cfg.Description == "" {
|
||||
cfg.Description = `Lists the user table statistics in the database ordered by number of
|
||||
sequential scans with a default limit of 50 rows. Returns the following
|
||||
columns: schema name, table name, table size in bytes, number of
|
||||
sequential scans, number of index scans, idx_scan_ratio_percent (showing
|
||||
the percentage of total scans that utilized an index, where a low ratio
|
||||
indicates missing or ineffective indexes), number of live rows, number
|
||||
of dead rows, dead_row_ratio_percent (indicating potential table bloat),
|
||||
total number of rows inserted, updated, and deleted, the timestamps
|
||||
for the last_vacuum, last_autovacuum, and last_autoanalyze operations.`
|
||||
}
|
||||
|
||||
mcpManifest := tools.GetMcpManifest(cfg.Name, cfg.Description, cfg.AuthRequired, allParameters, nil)
|
||||
|
||||
// finish tool setup
|
||||
return Tool{
|
||||
name: cfg.Name,
|
||||
kind: cfg.Kind,
|
||||
authRequired: cfg.AuthRequired,
|
||||
allParams: allParameters,
|
||||
pool: s.PostgresPool(),
|
||||
manifest: tools.Manifest{
|
||||
Description: cfg.Description,
|
||||
Parameters: paramManifest,
|
||||
AuthRequired: cfg.AuthRequired,
|
||||
},
|
||||
mcpManifest: mcpManifest,
|
||||
}, nil
|
||||
}
|
||||
|
||||
// validate interface
|
||||
var _ tools.Tool = Tool{}
|
||||
|
||||
type Tool struct {
|
||||
Config
|
||||
name string `yaml:"name"`
|
||||
kind string `yaml:"kind"`
|
||||
authRequired []string `yaml:"authRequired"`
|
||||
allParams parameters.Parameters `yaml:"allParams"`
|
||||
pool *pgxpool.Pool
|
||||
manifest tools.Manifest
|
||||
mcpManifest tools.McpManifest
|
||||
}
|
||||
|
||||
func (t Tool) ToConfig() tools.ToolConfig {
|
||||
return t.Config
|
||||
}
|
||||
|
||||
func (t Tool) Invoke(ctx context.Context, resourceMgr tools.SourceProvider, params parameters.ParamValues, accessToken tools.AccessToken) (any, error) {
|
||||
paramsMap := params.AsMap()
|
||||
|
||||
newParams, err := parameters.GetParams(t.allParams, paramsMap)
|
||||
if err != nil {
|
||||
return nil, fmt.Errorf("unable to extract standard params %w", err)
|
||||
}
|
||||
sliceParams := newParams.AsSlice()
|
||||
|
||||
results, err := t.pool.Query(ctx, listTableStats, sliceParams...)
|
||||
if err != nil {
|
||||
return nil, fmt.Errorf("unable to execute query: %w", err)
|
||||
}
|
||||
defer results.Close()
|
||||
|
||||
fields := results.FieldDescriptions()
|
||||
var out []map[string]any
|
||||
|
||||
for results.Next() {
|
||||
values, err := results.Values()
|
||||
if err != nil {
|
||||
return nil, fmt.Errorf("unable to parse row: %w", err)
|
||||
}
|
||||
rowMap := make(map[string]any)
|
||||
for i, field := range fields {
|
||||
rowMap[string(field.Name)] = values[i]
|
||||
}
|
||||
out = append(out, rowMap)
|
||||
}
|
||||
|
||||
return out, nil
|
||||
}
|
||||
|
||||
func (t Tool) ParseParams(data map[string]any, claims map[string]map[string]any) (parameters.ParamValues, error) {
|
||||
return parameters.ParseParams(t.allParams, data, claims)
|
||||
}
|
||||
|
||||
func (t Tool) Manifest() tools.Manifest {
|
||||
return t.manifest
|
||||
}
|
||||
|
||||
func (t Tool) McpManifest() tools.McpManifest {
|
||||
return t.mcpManifest
|
||||
}
|
||||
|
||||
func (t Tool) Authorized(verifiedAuthServices []string) bool {
|
||||
return tools.IsAuthorized(t.authRequired, verifiedAuthServices)
|
||||
}
|
||||
|
||||
func (t Tool) RequiresClientAuthorization(resourceMgr tools.SourceProvider) bool {
|
||||
return false
|
||||
}
|
||||
|
||||
func (t Tool) GetAuthTokenHeaderName() string {
|
||||
return "Authorization"
|
||||
}
|
||||
@@ -0,0 +1,95 @@
|
||||
// Copyright 2025 Google LLC
|
||||
//
|
||||
// Licensed under the Apache License, Version 2.0 (the "License");
|
||||
// you may not use this file except in compliance with the License.
|
||||
// You may obtain a copy of the License at
|
||||
//
|
||||
// http://www.apache.org/licenses/LICENSE-2.0
|
||||
//
|
||||
// Unless required by applicable law or agreed to in writing, software
|
||||
// distributed under the License is distributed on an "AS IS" BASIS,
|
||||
// WITHOUT WARRANTIES OR CONDITIONS OF ANY KIND, either express or implied.
|
||||
// See the License for the specific language governing permissions and
|
||||
// limitations under the License.
|
||||
|
||||
package postgreslisttablestats_test
|
||||
|
||||
import (
|
||||
"testing"
|
||||
|
||||
yaml "github.com/goccy/go-yaml"
|
||||
"github.com/google/go-cmp/cmp"
|
||||
"github.com/googleapis/genai-toolbox/internal/server"
|
||||
"github.com/googleapis/genai-toolbox/internal/testutils"
|
||||
"github.com/googleapis/genai-toolbox/internal/tools/postgres/postgreslisttablestats"
|
||||
)
|
||||
|
||||
func TestParseFromYamlPostgresListTableStats(t *testing.T) {
|
||||
ctx, err := testutils.ContextWithNewLogger()
|
||||
if err != nil {
|
||||
t.Fatalf("unexpected error: %s", err)
|
||||
}
|
||||
tcs := []struct {
|
||||
desc string
|
||||
in string
|
||||
want server.ToolConfigs
|
||||
}{
|
||||
{
|
||||
desc: "basic example",
|
||||
in: `
|
||||
tools:
|
||||
example_tool:
|
||||
kind: postgres-list-table-stats
|
||||
source: my-postgres-instance
|
||||
description: some description
|
||||
authRequired:
|
||||
- my-google-auth-service
|
||||
- other-auth-service
|
||||
`,
|
||||
want: server.ToolConfigs{
|
||||
"example_tool": postgreslisttablestats.Config{
|
||||
Name: "example_tool",
|
||||
Kind: "postgres-list-table-stats",
|
||||
Source: "my-postgres-instance",
|
||||
Description: "some description",
|
||||
AuthRequired: []string{"my-google-auth-service", "other-auth-service"},
|
||||
},
|
||||
},
|
||||
},
|
||||
{
|
||||
desc: "basic example",
|
||||
in: `
|
||||
tools:
|
||||
example_tool:
|
||||
kind: postgres-list-table-stats
|
||||
source: my-postgres-instance
|
||||
description: some description
|
||||
`,
|
||||
want: server.ToolConfigs{
|
||||
"example_tool": postgreslisttablestats.Config{
|
||||
Name: "example_tool",
|
||||
Kind: "postgres-list-table-stats",
|
||||
Source: "my-postgres-instance",
|
||||
Description: "some description",
|
||||
AuthRequired: []string{},
|
||||
},
|
||||
},
|
||||
},
|
||||
}
|
||||
for _, tc := range tcs {
|
||||
t.Run(tc.desc, func(t *testing.T) {
|
||||
got := struct {
|
||||
Tools server.ToolConfigs `yaml:"tools"`
|
||||
}{}
|
||||
// Parse contents
|
||||
err := yaml.UnmarshalContext(ctx, testutils.FormatYaml(tc.in), &got)
|
||||
if err != nil {
|
||||
t.Fatalf("unable to unmarshal: %s", err)
|
||||
}
|
||||
if diff := cmp.Diff(tc.want, got.Tools); diff != "" {
|
||||
t.Fatalf("incorrect parse: diff %v", diff)
|
||||
}
|
||||
})
|
||||
}
|
||||
|
||||
}
|
||||
@@ -195,6 +195,7 @@ func TestAlloyDBPgToolEndpoints(t *testing.T) {
|
||||
tests.RunPostgresLongRunningTransactionsTest(t, ctx, pool)
|
||||
tests.RunPostgresListQueryStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresGetColumnCardinalityTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresListPublicationTablesTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableSpacesTest(t)
|
||||
tests.RunPostgresListPgSettingsTest(t, ctx, pool)
|
||||
|
||||
@@ -179,6 +179,7 @@ func TestCloudSQLPgSimpleToolEndpoints(t *testing.T) {
|
||||
tests.RunPostgresLongRunningTransactionsTest(t, ctx, pool)
|
||||
tests.RunPostgresListQueryStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresGetColumnCardinalityTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresListPublicationTablesTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableSpacesTest(t)
|
||||
tests.RunPostgresListPgSettingsTest(t, ctx, pool)
|
||||
|
||||
@@ -207,6 +207,7 @@ func AddPostgresPrebuiltConfig(t *testing.T, config map[string]any) map[string]a
|
||||
PostgresReplicationStatsToolKind = "postgres-replication-stats"
|
||||
PostgresListQueryStatsToolKind = "postgres-list-query-stats"
|
||||
PostgresGetColumnCardinalityToolKind = "postgres-get-column-cardinality"
|
||||
PostgresListTableStats = "postgres-list-table-stats"
|
||||
PostgresListPublicationTablesToolKind = "postgres-list-publication-tables"
|
||||
PostgresListTablespacesToolKind = "postgres-list-tablespaces"
|
||||
PostgresListPGSettingsToolKind = "postgres-list-pg-settings"
|
||||
@@ -286,6 +287,12 @@ func AddPostgresPrebuiltConfig(t *testing.T, config map[string]any) map[string]a
|
||||
"kind": PostgresGetColumnCardinalityToolKind,
|
||||
"source": "my-instance",
|
||||
}
|
||||
|
||||
tools["list_table_stats"] = map[string]any{
|
||||
"kind": PostgresListTableStats,
|
||||
"source": "my-instance",
|
||||
}
|
||||
|
||||
tools["list_tablespaces"] = map[string]any{
|
||||
"kind": PostgresListTablespacesToolKind,
|
||||
"source": "my-instance",
|
||||
|
||||
@@ -158,6 +158,7 @@ func TestPostgres(t *testing.T) {
|
||||
tests.RunPostgresReplicationStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresListQueryStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresGetColumnCardinalityTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableStatsTest(t, ctx, pool)
|
||||
tests.RunPostgresListPublicationTablesTest(t, ctx, pool)
|
||||
tests.RunPostgresListTableSpacesTest(t)
|
||||
tests.RunPostgresListPgSettingsTest(t, ctx, pool)
|
||||
|
||||
244
tests/tool.go
244
tests/tool.go
@@ -4080,6 +4080,250 @@ func RunPostgresListQueryStatsTest(t *testing.T, ctx context.Context, pool *pgxp
|
||||
}
|
||||
}
|
||||
|
||||
// RunPostgresListTableStatsTest runs tests for the postgres list-table-stats tool
|
||||
func RunPostgresListTableStatsTest(t *testing.T, ctx context.Context, pool *pgxpool.Pool) {
|
||||
type tableStatsDetails struct {
|
||||
SchemaName string `json:"schema_name"`
|
||||
TableName string `json:"table_name"`
|
||||
Owner string `json:"owner"`
|
||||
TotalSizeBytes any `json:"total_size_bytes"`
|
||||
SeqScan any `json:"seq_scan"`
|
||||
IdxScan any `json:"idx_scan"`
|
||||
IdxScanRatioPercent float64 `json:"idx_scan_ratio_percent"`
|
||||
LiveRows any `json:"live_rows"`
|
||||
DeadRows any `json:"dead_rows"`
|
||||
DeadRowRatioPercent float64 `json:"dead_row_ratio_percent"`
|
||||
NTupIns any `json:"n_tup_ins"`
|
||||
NTupUpd any `json:"n_tup_upd"`
|
||||
NTupDel any `json:"n_tup_del"`
|
||||
LastVacuum any `json:"last_vacuum"`
|
||||
LastAutovacuum any `json:"last_autovacuum"`
|
||||
LastAutoanalyze any `json:"last_autoanalyze"`
|
||||
}
|
||||
|
||||
// Create a test table to generate statistics
|
||||
testTableName := "test_list_table_stats_" + strings.ReplaceAll(uuid.New().String(), "-", "")
|
||||
createTableStmt := fmt.Sprintf(`
|
||||
CREATE TABLE %s (
|
||||
id SERIAL PRIMARY KEY,
|
||||
name VARCHAR(100),
|
||||
email VARCHAR(100)
|
||||
)
|
||||
`, testTableName)
|
||||
|
||||
if _, err := pool.Exec(ctx, createTableStmt); err != nil {
|
||||
t.Fatalf("unable to create test table: %s", err)
|
||||
}
|
||||
defer func() {
|
||||
dropTableStmt := fmt.Sprintf("DROP TABLE IF EXISTS %s", testTableName)
|
||||
if _, err := pool.Exec(ctx, dropTableStmt); err != nil {
|
||||
t.Logf("warning: unable to drop test table: %v", err)
|
||||
}
|
||||
}()
|
||||
|
||||
// Insert some data to generate statistics
|
||||
insertStmt := fmt.Sprintf(`
|
||||
INSERT INTO %s (name, email) VALUES
|
||||
('Alice', 'alice@example.com'),
|
||||
('Bob', 'bob@example.com'),
|
||||
('Charlie', 'charlie@example.com'),
|
||||
('David', 'david@example.com'),
|
||||
('Eve', 'eve@example.com')
|
||||
`, testTableName)
|
||||
|
||||
if _, err := pool.Exec(ctx, insertStmt); err != nil {
|
||||
t.Fatalf("unable to insert test data: %s", err)
|
||||
}
|
||||
|
||||
// Run some sequential scans to generate statistics
|
||||
for i := 0; i < 3; i++ {
|
||||
selectStmt := fmt.Sprintf("SELECT * FROM %s WHERE name = 'Alice'", testTableName)
|
||||
if _, err := pool.Exec(ctx, selectStmt); err != nil {
|
||||
t.Logf("warning: unable to execute select: %v", err)
|
||||
}
|
||||
}
|
||||
|
||||
// Run ANALYZE to update statistics
|
||||
analyzeStmt := fmt.Sprintf("ANALYZE %s", testTableName)
|
||||
if _, err := pool.Exec(ctx, analyzeStmt); err != nil {
|
||||
t.Logf("warning: unable to run ANALYZE: %v", err)
|
||||
}
|
||||
|
||||
invokeTcs := []struct {
|
||||
name string
|
||||
requestBody io.Reader
|
||||
wantStatusCode int
|
||||
shouldHaveData bool
|
||||
filterTable bool
|
||||
}{
|
||||
{
|
||||
name: "list table stats with no arguments (default limit)",
|
||||
requestBody: bytes.NewBufferString(`{}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false, // may or may not have data depending on what's in the database
|
||||
},
|
||||
{
|
||||
name: "list table stats with default limit",
|
||||
requestBody: bytes.NewBufferString(`{"schema_name": "public"}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats filtering by specific table",
|
||||
requestBody: bytes.NewBufferString(fmt.Sprintf(`{"table_name": "%s"}`, testTableName)),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: true,
|
||||
filterTable: true,
|
||||
},
|
||||
{
|
||||
name: "list table stats with custom limit",
|
||||
requestBody: bytes.NewBufferString(`{"limit": 10}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats sorted by size",
|
||||
requestBody: bytes.NewBufferString(`{"sort_by": "size", "limit": 5}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats sorted by seq_scan",
|
||||
requestBody: bytes.NewBufferString(`{"sort_by": "seq_scan", "limit": 5}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats sorted by idx_scan",
|
||||
requestBody: bytes.NewBufferString(`{"sort_by": "idx_scan", "limit": 5}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats sorted by dead_rows",
|
||||
requestBody: bytes.NewBufferString(`{"sort_by": "dead_rows", "limit": 5}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats with non-existent table filter",
|
||||
requestBody: bytes.NewBufferString(`{"table_name": "non_existent_table_xyz"}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats with non-existent schema filter",
|
||||
requestBody: bytes.NewBufferString(`{"schema_name": "non_existent_schema_xyz"}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
{
|
||||
name: "list table stats with owner filter",
|
||||
requestBody: bytes.NewBufferString(`{"owner": "postgres"}`),
|
||||
wantStatusCode: http.StatusOK,
|
||||
shouldHaveData: false,
|
||||
},
|
||||
}
|
||||
|
||||
for _, tc := range invokeTcs {
|
||||
t.Run(tc.name, func(t *testing.T) {
|
||||
const api = "http://127.0.0.1:5000/api/tool/list_table_stats/invoke"
|
||||
resp, respBody := RunRequest(t, http.MethodPost, api, tc.requestBody, nil)
|
||||
if resp.StatusCode != tc.wantStatusCode {
|
||||
t.Fatalf("wrong status code: got %d, want %d, body: %s", resp.StatusCode, tc.wantStatusCode, string(respBody))
|
||||
}
|
||||
if tc.wantStatusCode != http.StatusOK {
|
||||
return
|
||||
}
|
||||
|
||||
var bodyWrapper struct {
|
||||
Result json.RawMessage `json:"result"`
|
||||
}
|
||||
if err := json.Unmarshal(respBody, &bodyWrapper); err != nil {
|
||||
t.Fatalf("error decoding response wrapper: %v", err)
|
||||
}
|
||||
|
||||
var resultString string
|
||||
if err := json.Unmarshal(bodyWrapper.Result, &resultString); err != nil {
|
||||
resultString = string(bodyWrapper.Result)
|
||||
}
|
||||
|
||||
var got []tableStatsDetails
|
||||
if resultString != "null" {
|
||||
if err := json.Unmarshal([]byte(resultString), &got); err != nil {
|
||||
t.Fatalf("failed to unmarshal result: %v, result string: %s", err, resultString)
|
||||
}
|
||||
}
|
||||
|
||||
// Verify expected data presence
|
||||
if tc.shouldHaveData {
|
||||
if len(got) == 0 {
|
||||
t.Fatalf("expected data but got empty result")
|
||||
}
|
||||
|
||||
// Verify the test table is in results
|
||||
found := false
|
||||
for _, row := range got {
|
||||
if row.TableName == testTableName {
|
||||
found = true
|
||||
// Verify expected fields are present
|
||||
if row.SchemaName == "" {
|
||||
t.Errorf("schema_name should not be empty")
|
||||
}
|
||||
if row.Owner == "" {
|
||||
t.Errorf("owner should not be empty")
|
||||
}
|
||||
if row.TotalSizeBytes == nil {
|
||||
t.Errorf("total_size_bytes should not be null")
|
||||
}
|
||||
if row.LiveRows == nil {
|
||||
t.Errorf("live_rows should not be null")
|
||||
}
|
||||
break
|
||||
}
|
||||
}
|
||||
|
||||
if !found {
|
||||
t.Errorf("test table %s not found in results", testTableName)
|
||||
}
|
||||
} else if tc.filterTable {
|
||||
// For filtered queries that shouldn't find anything
|
||||
if len(got) != 0 {
|
||||
t.Logf("warning: expected no data but got: %v", len(got))
|
||||
}
|
||||
}
|
||||
|
||||
// Verify result structure and data types
|
||||
for _, stat := range got {
|
||||
// Verify schema_name and table_name are strings
|
||||
if stat.SchemaName == "" && stat.TableName != "" {
|
||||
t.Errorf("schema_name is empty for table %s", stat.TableName)
|
||||
}
|
||||
|
||||
// Verify numeric fields are valid
|
||||
if stat.IdxScanRatioPercent < 0 || stat.IdxScanRatioPercent > 100 {
|
||||
t.Errorf("idx_scan_ratio_percent should be between 0 and 100, got %f", stat.IdxScanRatioPercent)
|
||||
}
|
||||
|
||||
if stat.DeadRowRatioPercent < 0 || stat.DeadRowRatioPercent > 100 {
|
||||
t.Errorf("dead_row_ratio_percent should be between 0 and 100, got %f", stat.DeadRowRatioPercent)
|
||||
}
|
||||
}
|
||||
|
||||
// Verify sorting for specific sort_by options
|
||||
if tc.name == "list table stats sorted by size" && len(got) > 1 {
|
||||
for i := 0; i < len(got)-1; i++ {
|
||||
current, ok1 := got[i].TotalSizeBytes.(float64)
|
||||
next, ok2 := got[i+1].TotalSizeBytes.(float64)
|
||||
if ok1 && ok2 && current < next {
|
||||
t.Logf("warning: results may not be sorted by total_size_bytes descending")
|
||||
}
|
||||
}
|
||||
}
|
||||
})
|
||||
}
|
||||
}
|
||||
|
||||
// RunRequest is a helper function to send HTTP requests and return the response
|
||||
func RunRequest(t *testing.T, method, url string, body io.Reader, headers map[string]string) (*http.Response, []byte) {
|
||||
// Send request
|
||||
|
||||
Reference in New Issue
Block a user