mirror of
https://github.com/googleapis/genai-toolbox.git
synced 2026-02-05 12:45:11 -05:00
## Description Add additional filter parameters for existing PostgreSQL tools: 1. `list_views`: - Add a new optional `"schema_name"` filter parameter to return results based on a specific schema name pattern. - Add an additional column `"definition"` to return the view definition. 2. `list_schemas`: - Add a new optional `"owner"` filter parameter to return results based on a specific owner name pattern. - Add a new optional `"limit"` parameter to return a specific number of rows. 3. `list_indexes`: - Add a new optional `"only_unused"` filter parameter to return only unused indexes. > Should include a concise description of the changes (bug or feature), it's > impact, along with a summary of the solution list_views <img width="1531" height="763" alt="Screenshot 2025-11-25 at 1 36 39 PM" src="https://github.com/user-attachments/assets/bd6805b3-43d2-46c7-adc8-62d3a4521d36" /> list_schemas <img width="1519" height="755" alt="Screenshot 2025-11-25 at 1 35 54 PM" src="https://github.com/user-attachments/assets/62d3e987-b64e-442b-ba1a-84def1df7a58" /> list_indexes <img width="1523" height="774" alt="Screenshot 2025-11-25 at 1 35 32 PM" src="https://github.com/user-attachments/assets/c6f73b3f-f8a2-4b76-9218-64d7011a2241" /> ## 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> Co-authored-by: Averi Kitsch <akitsch@google.com>
241 lines
7.3 KiB
Go
241 lines
7.3 KiB
Go
// 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 postgreslistschemas
|
|
|
|
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-schemas"
|
|
|
|
const listSchemasStatement = `
|
|
WITH
|
|
schema_grants AS (
|
|
SELECT schema_oid, jsonb_object_agg(grantee, privileges) AS grants
|
|
FROM
|
|
(
|
|
SELECT
|
|
n.oid AS schema_oid,
|
|
CASE
|
|
WHEN p.grantee = 0 THEN 'PUBLIC'
|
|
ELSE pg_catalog.pg_get_userbyid(p.grantee)
|
|
END
|
|
AS grantee,
|
|
jsonb_agg(p.privilege_type ORDER BY p.privilege_type) AS privileges
|
|
FROM pg_catalog.pg_namespace n, aclexplode(n.nspacl) p
|
|
WHERE n.nspacl IS NOT NULL
|
|
GROUP BY n.oid, grantee
|
|
) permissions_by_grantee
|
|
GROUP BY schema_oid
|
|
),
|
|
all_schemas AS (
|
|
SELECT
|
|
n.nspname AS schema_name,
|
|
pg_catalog.pg_get_userbyid(n.nspowner) AS owner,
|
|
COALESCE(sg.grants, '{}'::jsonb) AS grants,
|
|
(
|
|
SELECT COUNT(*)
|
|
FROM pg_catalog.pg_class c
|
|
WHERE c.relnamespace = n.oid AND c.relkind = 'r'
|
|
) AS tables,
|
|
(
|
|
SELECT COUNT(*)
|
|
FROM pg_catalog.pg_class c
|
|
WHERE c.relnamespace = n.oid AND c.relkind = 'v'
|
|
) AS views,
|
|
(SELECT COUNT(*) FROM pg_catalog.pg_proc p WHERE p.pronamespace = n.oid)
|
|
AS functions
|
|
FROM pg_catalog.pg_namespace n
|
|
LEFT JOIN schema_grants sg
|
|
ON n.oid = sg.schema_oid
|
|
)
|
|
SELECT *
|
|
FROM all_schemas
|
|
-- Exclude system schemas and temporary schemas created per session.
|
|
WHERE
|
|
schema_name NOT IN ('pg_catalog', 'information_schema', 'pg_toast')
|
|
AND schema_name NOT LIKE 'pg_temp_%'
|
|
AND schema_name NOT LIKE 'pg_toast_temp_%'
|
|
AND ($1::text IS NULL OR schema_name ILIKE '%' || $1::text || '%')
|
|
AND ($2::text IS NULL OR owner ILIKE '%' || $2::text || '%')
|
|
ORDER BY schema_name
|
|
LIMIT COALESCE($3::int, NULL);
|
|
`
|
|
|
|
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", "", "Optional: A specific schema name pattern to search for."),
|
|
parameters.NewStringParameterWithDefault("owner", "", "Optional: A specific schema owner name pattern to search for."),
|
|
parameters.NewIntParameterWithDefault("limit", 10, "Optional: The maximum number of schemas to return."),
|
|
}
|
|
|
|
if cfg.Description == "" {
|
|
cfg.Description = "Lists all schemas in the database ordered by schema name and excluding system and temporary schemas. It returns the schema name, schema owner, grants, number of functions, number of tables and number of views within each schema."
|
|
}
|
|
mcpManifest := tools.GetMcpManifest(cfg.Name, cfg.Description, cfg.AuthRequired, allParameters, nil)
|
|
|
|
// finish tool setup
|
|
return Tool{
|
|
Config: cfg,
|
|
allParams: allParameters,
|
|
pool: s.PostgresPool(),
|
|
manifest: tools.Manifest{
|
|
Description: cfg.Description,
|
|
Parameters: allParameters.Manifest(),
|
|
AuthRequired: cfg.AuthRequired,
|
|
},
|
|
mcpManifest: mcpManifest,
|
|
}, nil
|
|
}
|
|
|
|
// validate interface
|
|
var _ tools.Tool = Tool{}
|
|
|
|
type Tool struct {
|
|
Config
|
|
allParams parameters.Parameters `yaml:"allParams"`
|
|
pool *pgxpool.Pool
|
|
manifest tools.Manifest
|
|
mcpManifest tools.McpManifest
|
|
}
|
|
|
|
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, listSchemasStatement, 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)
|
|
}
|
|
|
|
// this will catch actual query execution errors
|
|
if err := results.Err(); err != nil {
|
|
return nil, fmt.Errorf("unable to execute query: %w", err)
|
|
}
|
|
|
|
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) ToConfig() tools.ToolConfig {
|
|
return t.Config
|
|
}
|
|
|
|
func (t Tool) GetAuthTokenHeaderName() string {
|
|
return "Authorization"
|
|
}
|