feat(tools/mysql-list-tables): Add new tool for mysql (#1287)

## Description
---
This pull request introduces a new custom tool kind `mysql-list-tables`
that allows users to list tables within a MySQL database.

### Example Configuration

```yaml
tools:
  mysql_list_tables:
    kind: mysql-list-tables
    source: mysql-source
    description: Use this tool to retrieve schema information for all or specified tables. Output format can be simple (only table names) or detailed.
```

### Example Request
``` 
curl -X POST http://127.0.0.1:5000/api/tool/mysql_list_tables/invoke \
-H "Content-Type: application/json" \
-d '{
    "table_names": "users",
    "output_format": "simple"
}'
```

## 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)
- [ ] Make sure to open an issue as a

[bug/issue](https://github.com/googleapis/langchain-google-alloydb-pg-python/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

---------

Co-authored-by: Averi Kitsch <akitsch@google.com>
This commit is contained in:
Sri Varshitha
2025-09-11 15:42:56 +05:30
committed by GitHub
parent 71f360d315
commit 6c8460b0e5
9 changed files with 689 additions and 321 deletions

View File

@@ -99,6 +99,7 @@ import (
_ "github.com/googleapis/genai-toolbox/internal/tools/mssql/mssqlexecutesql"
_ "github.com/googleapis/genai-toolbox/internal/tools/mssql/mssqlsql"
_ "github.com/googleapis/genai-toolbox/internal/tools/mysql/mysqlexecutesql"
_ "github.com/googleapis/genai-toolbox/internal/tools/mysql/mysqllisttables"
_ "github.com/googleapis/genai-toolbox/internal/tools/mysql/mysqlsql"
_ "github.com/googleapis/genai-toolbox/internal/tools/neo4j/neo4jcypher"
_ "github.com/googleapis/genai-toolbox/internal/tools/neo4j/neo4jexecutecypher"

View File

@@ -28,6 +28,9 @@ to a database by following these instructions][csql-mysql-quickstart].
- [`mysql-execute-sql`](../tools/mysql/mysql-execute-sql.md)
Run parameterized SQL queries in Cloud SQL for MySQL.
- [`mysql-list-tables`](../tools/mysql/mysql-list-tables.md)
List tables in a Cloud SQL for MySQL database.
### Pre-built Configurations
- [Cloud SQL for MySQL using MCP](https://googleapis.github.io/genai-toolbox/how-to/connect-ide/cloud_sql_mysql_mcp/)

View File

@@ -22,6 +22,9 @@ reliability, performance, and ease of use.
- [`mysql-execute-sql`](../tools/mysql/mysql-execute-sql.md)
Run parameterized SQL queries in MySQL.
- [`mysql-list-tables`](../tools/mysql/mysql-list-tables.md)
List tables in a MySQL database.
## Requirements
### Database User

View File

@@ -0,0 +1,43 @@
---
title: "mysql-list-tables"
type: docs
weight: 1
description: >
The "mysql-list-tables" tool lists schema information for all or specified tables in a MySQL database.
aliases:
- /resources/tools/mysql-list-tables
---
## About
The `mysql-list-tables` tool retrieves schema information for all or specified tables in a MySQL database. It is compatible with any of the following sources:
- [cloud-sql-mysql](../../sources/cloud-sql-mysql.md)
- [mysql](../../sources/mysql.md)
`mysql-list-tables` lists detailed schema information (object type, columns, constraints, indexes, triggers, owner, comment) as JSON for user-created tables (ordinary or partitioned). Filters by a comma-separated list of names. If names are omitted, it lists all tables in user schemas. The output format can be set to `simple` which will return only the table names or `detailed` which is the default.
The tool takes the following input parameters:
| Parameter | Type | Description | Required |
| :--------- | :----- | :--------------------------------------------------------------------------------------- | :------- |
| `table_names` | string | Filters by a comma-separated list of names. By default, it lists all tables in user schemas. Default: `""` | No |
| `output_format` | string | Indicate the output format of table schema. `simple` will return only the table names, `detailed` will return the full table information. Default: `detailed`. | No |
## Example
```yaml
tools:
mysql_list_tables:
kind: mysql-list-tables
source: mysql-source
description: Use this tool to retrieve schema information for all or specified tables. Output format can be simple (only table names) or detailed.
```
## Reference
| **field** | **type** | **required** | **description** |
|-------------|:------------------------------------------:|:------------:|--------------------------------------------------------------------------------------------------|
| kind | string | true | Must be "mysql-list-tables". |
| source | string | true | Name of the source the SQL should execute on. |
| description | string | true | Description of the tool that is passed to the agent. |

View File

@@ -4,7 +4,7 @@
# 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
# 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,
@@ -28,168 +28,9 @@ tools:
source: cloud-sql-mysql-source
description: Use this tool to execute SQL.
list_tables:
kind: mysql-sql
kind: mysql-list-tables
source: cloud-sql-mysql-source
description: "Lists detailed schema information (object type, columns, constraints, indexes, triggers, comment) as JSON for user-created tables (ordinary or partitioned). Filters by a comma-separated list of names. If names are omitted, lists all tables in user schemas."
statement: |
SELECT
T.TABLE_SCHEMA AS schema_name,
T.TABLE_NAME AS object_name,
CASE
WHEN @output_format = 'simple' THEN
JSON_OBJECT('name', T.TABLE_NAME)
ELSE
CONVERT( JSON_OBJECT(
'schema_name', T.TABLE_SCHEMA,
'object_name', T.TABLE_NAME,
'object_type', 'TABLE',
'owner', (
SELECT
IFNULL(U.GRANTEE, 'N/A')
FROM
INFORMATION_SCHEMA.SCHEMA_PRIVILEGES U
WHERE
U.TABLE_SCHEMA = T.TABLE_SCHEMA
LIMIT 1
),
'comment', IFNULL(T.TABLE_COMMENT, ''),
'columns', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'column_name', C.COLUMN_NAME,
'data_type', C.COLUMN_TYPE,
'ordinal_position', C.ORDINAL_POSITION,
'is_not_nullable', IF(C.IS_NULLABLE = 'NO', TRUE, FALSE),
'column_default', C.COLUMN_DEFAULT,
'column_comment', IFNULL(C.COLUMN_COMMENT, '')
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.COLUMNS C
WHERE
C.TABLE_SCHEMA = T.TABLE_SCHEMA AND C.TABLE_NAME = T.TABLE_NAME
ORDER BY C.ORDINAL_POSITION
),
'constraints', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'constraint_name', TC.CONSTRAINT_NAME,
'constraint_type',
CASE TC.CONSTRAINT_TYPE
WHEN 'PRIMARY KEY' THEN 'PRIMARY KEY'
WHEN 'FOREIGN KEY' THEN 'FOREIGN KEY'
WHEN 'UNIQUE' THEN 'UNIQUE'
ELSE TC.CONSTRAINT_TYPE
END,
'constraint_definition', '',
'constraint_columns', (
SELECT
IFNULL(JSON_ARRAYAGG(KCU.COLUMN_NAME), JSON_ARRAY())
FROM
INFORMATION_SCHEMA.KEY_COLUMN_USAGE KCU
WHERE
KCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND KCU.TABLE_NAME = TC.TABLE_NAME
ORDER BY KCU.ORDINAL_POSITION
),
'foreign_key_referenced_table', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY', RC.REFERENCED_TABLE_NAME, NULL),
'foreign_key_referenced_columns', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY',
(SELECT IFNULL(JSON_ARRAYAGG(FKCU.REFERENCED_COLUMN_NAME), JSON_ARRAY())
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE FKCU
WHERE FKCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND FKCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND FKCU.TABLE_NAME = TC.TABLE_NAME
AND FKCU.REFERENCED_TABLE_NAME IS NOT NULL
ORDER BY FKCU.ORDINAL_POSITION),
NULL
)
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC
LEFT JOIN
INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS RC
ON TC.CONSTRAINT_SCHEMA = RC.CONSTRAINT_SCHEMA
AND TC.CONSTRAINT_NAME = RC.CONSTRAINT_NAME
AND TC.TABLE_NAME = RC.TABLE_NAME
WHERE
TC.TABLE_SCHEMA = T.TABLE_SCHEMA AND TC.TABLE_NAME = T.TABLE_NAME
),
'indexes', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'index_name', IndexData.INDEX_NAME,
'is_unique', IF(IndexData.NON_UNIQUE = 0, TRUE, FALSE),
'is_primary', IF(IndexData.INDEX_NAME = 'PRIMARY', TRUE, FALSE),
'index_columns', IFNULL(IndexData.INDEX_COLUMNS_ARRAY, JSON_ARRAY())
)
),
JSON_ARRAY()
)
FROM (
SELECT
S.TABLE_SCHEMA,
S.TABLE_NAME,
S.INDEX_NAME,
MIN(S.NON_UNIQUE) AS NON_UNIQUE, -- Aggregate NON_UNIQUE here to get unique status for the index
JSON_ARRAYAGG(S.COLUMN_NAME) AS INDEX_COLUMNS_ARRAY -- Aggregate columns into an array for this index
FROM
INFORMATION_SCHEMA.STATISTICS S
WHERE
S.TABLE_SCHEMA = T.TABLE_SCHEMA AND S.TABLE_NAME = T.TABLE_NAME
GROUP BY
S.TABLE_SCHEMA, S.TABLE_NAME, S.INDEX_NAME
) AS IndexData
ORDER BY IndexData.INDEX_NAME
),
'triggers', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'trigger_name', TR.TRIGGER_NAME,
'trigger_definition', TR.ACTION_STATEMENT
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TRIGGERS TR
WHERE
TR.EVENT_OBJECT_SCHEMA = T.TABLE_SCHEMA AND TR.EVENT_OBJECT_TABLE = T.TABLE_NAME
ORDER BY TR.TRIGGER_NAME
)
) USING utf8mb4)
END AS object_details
FROM
INFORMATION_SCHEMA.TABLES T
CROSS JOIN (SELECT @table_names := ?, @output_format := ?) AS variables
WHERE
T.TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')
AND (NULLIF(TRIM(@table_names), '') IS NULL OR FIND_IN_SET(T.TABLE_NAME, @table_names))
AND T.TABLE_TYPE = 'BASE TABLE'
ORDER BY
T.TABLE_SCHEMA, T.TABLE_NAME;
parameters:
- name: table_names
type: string
description: "Optional: A comma-separated list of table names. If empty, details for all tables in user-accessible schemas will be listed."
default: ""
- name: output_format
type: string
description: "Optional: Use 'simple' to return table names only or use 'detailed' to return the full information schema."
default: "detailed"
toolsets:
cloud-sql-mysql-database-tools:

View File

@@ -32,168 +32,9 @@ tools:
source: mysql-source
description: Use this tool to execute SQL.
list_tables:
kind: mysql-sql
kind: mysql-list-tables
source: mysql-source
description: "Lists detailed schema information (object type, columns, constraints, indexes, triggers, comment) as JSON for user-created tables (ordinary or partitioned). Filters by a comma-separated list of names. If names are omitted, lists all tables in user schemas."
statement: |
SELECT
T.TABLE_SCHEMA AS schema_name,
T.TABLE_NAME AS object_name,
CASE
WHEN @output_format = 'simple' THEN
JSON_OBJECT('name', T.TABLE_NAME)
ELSE
CONVERT( JSON_OBJECT(
'schema_name', T.TABLE_SCHEMA,
'object_name', T.TABLE_NAME,
'object_type', 'TABLE',
'owner', (
SELECT
IFNULL(U.GRANTEE, 'N/A')
FROM
INFORMATION_SCHEMA.SCHEMA_PRIVILEGES U
WHERE
U.TABLE_SCHEMA = T.TABLE_SCHEMA
LIMIT 1
),
'comment', IFNULL(T.TABLE_COMMENT, ''),
'columns', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'column_name', C.COLUMN_NAME,
'data_type', C.COLUMN_TYPE,
'ordinal_position', C.ORDINAL_POSITION,
'is_not_nullable', IF(C.IS_NULLABLE = 'NO', TRUE, FALSE),
'column_default', C.COLUMN_DEFAULT,
'column_comment', IFNULL(C.COLUMN_COMMENT, '')
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.COLUMNS C
WHERE
C.TABLE_SCHEMA = T.TABLE_SCHEMA AND C.TABLE_NAME = T.TABLE_NAME
ORDER BY C.ORDINAL_POSITION
),
'constraints', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'constraint_name', TC.CONSTRAINT_NAME,
'constraint_type',
CASE TC.CONSTRAINT_TYPE
WHEN 'PRIMARY KEY' THEN 'PRIMARY KEY'
WHEN 'FOREIGN KEY' THEN 'FOREIGN KEY'
WHEN 'UNIQUE' THEN 'UNIQUE'
ELSE TC.CONSTRAINT_TYPE
END,
'constraint_definition', '',
'constraint_columns', (
SELECT
IFNULL(JSON_ARRAYAGG(KCU.COLUMN_NAME), JSON_ARRAY())
FROM
INFORMATION_SCHEMA.KEY_COLUMN_USAGE KCU
WHERE
KCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND KCU.TABLE_NAME = TC.TABLE_NAME
ORDER BY KCU.ORDINAL_POSITION
),
'foreign_key_referenced_table', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY', RC.REFERENCED_TABLE_NAME, NULL),
'foreign_key_referenced_columns', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY',
(SELECT IFNULL(JSON_ARRAYAGG(FKCU.REFERENCED_COLUMN_NAME), JSON_ARRAY())
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE FKCU
WHERE FKCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND FKCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND FKCU.TABLE_NAME = TC.TABLE_NAME
AND FKCU.REFERENCED_TABLE_NAME IS NOT NULL
ORDER BY FKCU.ORDINAL_POSITION),
NULL
)
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC
LEFT JOIN
INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS RC
ON TC.CONSTRAINT_SCHEMA = RC.CONSTRAINT_SCHEMA
AND TC.CONSTRAINT_NAME = RC.CONSTRAINT_NAME
AND TC.TABLE_NAME = RC.TABLE_NAME
WHERE
TC.TABLE_SCHEMA = T.TABLE_SCHEMA AND TC.TABLE_NAME = T.TABLE_NAME
),
'indexes', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'index_name', IndexData.INDEX_NAME,
'is_unique', IF(IndexData.NON_UNIQUE = 0, TRUE, FALSE),
'is_primary', IF(IndexData.INDEX_NAME = 'PRIMARY', TRUE, FALSE),
'index_columns', IFNULL(IndexData.INDEX_COLUMNS_ARRAY, JSON_ARRAY())
)
),
JSON_ARRAY()
)
FROM (
SELECT
S.TABLE_SCHEMA,
S.TABLE_NAME,
S.INDEX_NAME,
MIN(S.NON_UNIQUE) AS NON_UNIQUE, -- Aggregate NON_UNIQUE here to get unique status for the index
JSON_ARRAYAGG(S.COLUMN_NAME) AS INDEX_COLUMNS_ARRAY -- Aggregate columns into an array for this index
FROM
INFORMATION_SCHEMA.STATISTICS S
WHERE
S.TABLE_SCHEMA = T.TABLE_SCHEMA AND S.TABLE_NAME = T.TABLE_NAME
GROUP BY
S.TABLE_SCHEMA, S.TABLE_NAME, S.INDEX_NAME
) AS IndexData
ORDER BY IndexData.INDEX_NAME
),
'triggers', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'trigger_name', TR.TRIGGER_NAME,
'trigger_definition', TR.ACTION_STATEMENT
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TRIGGERS TR
WHERE
TR.EVENT_OBJECT_SCHEMA = T.TABLE_SCHEMA AND TR.EVENT_OBJECT_TABLE = T.TABLE_NAME
ORDER BY TR.TRIGGER_NAME
)
) USING utf8mb4)
END AS object_details
FROM
INFORMATION_SCHEMA.TABLES T
CROSS JOIN (SELECT @table_names := ?, @output_format := ?) AS variables
WHERE
T.TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')
AND (NULLIF(TRIM(@table_names), '') IS NULL OR FIND_IN_SET(T.TABLE_NAME, @table_names))
AND T.TABLE_TYPE = 'BASE TABLE'
ORDER BY
T.TABLE_SCHEMA, T.TABLE_NAME;
parameters:
- name: table_names
type: string
description: "Optional: A comma-separated list of table names. If empty, details for all tables in user-accessible schemas will be listed."
default: ""
- name: output_format
type: string
description: "Optional: Use 'simple' to return table names only or use 'detailed' to return the full information schema."
default: "detailed"
toolsets:
mysql-database-tools:

View File

@@ -0,0 +1,360 @@
// 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 mysqllisttables
import (
"context"
"database/sql"
"fmt"
yaml "github.com/goccy/go-yaml"
"github.com/googleapis/genai-toolbox/internal/sources"
"github.com/googleapis/genai-toolbox/internal/sources/cloudsqlmysql"
"github.com/googleapis/genai-toolbox/internal/sources/mysql"
"github.com/googleapis/genai-toolbox/internal/tools"
"github.com/googleapis/genai-toolbox/internal/tools/mysql/mysqlcommon"
)
const kind string = "mysql-list-tables"
const listTablesStatement = `
SELECT
T.TABLE_SCHEMA AS schema_name,
T.TABLE_NAME AS object_name,
CASE
WHEN @output_format = 'simple' THEN
JSON_OBJECT('name', T.TABLE_NAME)
ELSE
CONVERT(
JSON_OBJECT(
'schema_name', T.TABLE_SCHEMA,
'object_name', T.TABLE_NAME,
'object_type', 'TABLE',
'owner', (
SELECT
IFNULL(U.GRANTEE, 'N/A')
FROM
INFORMATION_SCHEMA.SCHEMA_PRIVILEGES U
WHERE
U.TABLE_SCHEMA = T.TABLE_SCHEMA
LIMIT 1
),
'comment', IFNULL(T.TABLE_COMMENT, ''),
'columns', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'column_name', C.COLUMN_NAME,
'data_type', C.COLUMN_TYPE,
'ordinal_position', C.ORDINAL_POSITION,
'is_not_nullable', IF(C.IS_NULLABLE = 'NO', TRUE, FALSE),
'column_default', C.COLUMN_DEFAULT,
'column_comment', IFNULL(C.COLUMN_COMMENT, '')
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.COLUMNS C
WHERE
C.TABLE_SCHEMA = T.TABLE_SCHEMA AND C.TABLE_NAME = T.TABLE_NAME
ORDER BY C.ORDINAL_POSITION
),
'constraints', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'constraint_name', TC.CONSTRAINT_NAME,
'constraint_type',
CASE TC.CONSTRAINT_TYPE
WHEN 'PRIMARY KEY' THEN 'PRIMARY KEY'
WHEN 'FOREIGN KEY' THEN 'FOREIGN KEY'
WHEN 'UNIQUE' THEN 'UNIQUE'
ELSE TC.CONSTRAINT_TYPE
END,
'constraint_definition', '',
'constraint_columns', (
SELECT
IFNULL(JSON_ARRAYAGG(KCU.COLUMN_NAME), JSON_ARRAY())
FROM
INFORMATION_SCHEMA.KEY_COLUMN_USAGE KCU
WHERE
KCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND KCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND KCU.TABLE_NAME = TC.TABLE_NAME
ORDER BY KCU.ORDINAL_POSITION
),
'foreign_key_referenced_table', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY', RC.REFERENCED_TABLE_NAME, NULL),
'foreign_key_referenced_columns', IF(TC.CONSTRAINT_TYPE = 'FOREIGN KEY',
(SELECT IFNULL(JSON_ARRAYAGG(FKCU.REFERENCED_COLUMN_NAME), JSON_ARRAY())
FROM INFORMATION_SCHEMA.KEY_COLUMN_USAGE FKCU
WHERE FKCU.CONSTRAINT_SCHEMA = TC.CONSTRAINT_SCHEMA
AND FKCU.CONSTRAINT_NAME = TC.CONSTRAINT_NAME
AND FKCU.TABLE_NAME = TC.TABLE_NAME
AND FKCU.REFERENCED_TABLE_NAME IS NOT NULL
ORDER BY FKCU.ORDINAL_POSITION),
NULL
)
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TABLE_CONSTRAINTS TC
LEFT JOIN
INFORMATION_SCHEMA.REFERENTIAL_CONSTRAINTS RC
ON TC.CONSTRAINT_SCHEMA = RC.CONSTRAINT_SCHEMA
AND TC.CONSTRAINT_NAME = RC.CONSTRAINT_NAME
AND TC.TABLE_NAME = RC.TABLE_NAME
WHERE
TC.TABLE_SCHEMA = T.TABLE_SCHEMA AND TC.TABLE_NAME = T.TABLE_NAME
),
'indexes', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'index_name', IndexData.INDEX_NAME,
'is_unique', IF(IndexData.NON_UNIQUE = 0, TRUE, FALSE),
'is_primary', IF(IndexData.INDEX_NAME = 'PRIMARY', TRUE, FALSE),
'index_columns', IFNULL(IndexData.INDEX_COLUMNS_ARRAY, JSON_ARRAY())
)
),
JSON_ARRAY()
)
FROM (
SELECT
S.TABLE_SCHEMA,
S.TABLE_NAME,
S.INDEX_NAME,
MIN(S.NON_UNIQUE) AS NON_UNIQUE,
JSON_ARRAYAGG(S.COLUMN_NAME) AS INDEX_COLUMNS_ARRAY
FROM
INFORMATION_SCHEMA.STATISTICS S
WHERE
S.TABLE_SCHEMA = T.TABLE_SCHEMA AND S.TABLE_NAME = T.TABLE_NAME
GROUP BY
S.TABLE_SCHEMA, S.TABLE_NAME, S.INDEX_NAME
) AS IndexData
ORDER BY IndexData.INDEX_NAME
),
'triggers', (
SELECT
IFNULL(
JSON_ARRAYAGG(
JSON_OBJECT(
'trigger_name', TR.TRIGGER_NAME,
'trigger_definition', TR.ACTION_STATEMENT
)
),
JSON_ARRAY()
)
FROM
INFORMATION_SCHEMA.TRIGGERS TR
WHERE
TR.EVENT_OBJECT_SCHEMA = T.TABLE_SCHEMA AND TR.EVENT_OBJECT_TABLE = T.TABLE_NAME
ORDER BY TR.TRIGGER_NAME
)
)
USING utf8mb4)
END AS object_details
FROM
INFORMATION_SCHEMA.TABLES T
CROSS JOIN (SELECT @table_names := ?, @output_format := ?) AS variables
WHERE
T.TABLE_SCHEMA NOT IN ('mysql', 'information_schema', 'performance_schema', 'sys')
AND (NULLIF(TRIM(@table_names), '') IS NULL OR FIND_IN_SET(T.TABLE_NAME, @table_names))
AND T.TABLE_TYPE = 'BASE TABLE'
ORDER BY
T.TABLE_SCHEMA, T.TABLE_NAME;
`
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 {
MySQLPool() *sql.DB
}
// validate compatible sources are still compatible
var _ compatibleSource = &cloudsqlmysql.Source{}
var _ compatibleSource = &mysql.Source{}
var compatibleSources = [...]string{cloudsqlmysql.SourceKind, mysql.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" validate:"required"`
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 := tools.Parameters{
tools.NewStringParameter("table_names", "Optional: A comma-separated list of table names. If empty, details for all tables will be listed."),
tools.NewStringParameterWithDefault("output_format", "detailed", "Optional: Use 'simple' for names only or 'detailed' for full info."),
}
paramManifest := allParameters.Manifest()
inputSchema := allParameters.McpManifest()
mcpManifest := tools.McpManifest{
Name: cfg.Name,
Description: cfg.Description,
InputSchema: inputSchema,
}
// finish tool setup
t := Tool{
Name: cfg.Name,
Kind: kind,
AllParams: allParameters,
AuthRequired: cfg.AuthRequired,
Pool: s.MySQLPool(),
manifest: tools.Manifest{Description: cfg.Description, Parameters: paramManifest, AuthRequired: cfg.AuthRequired},
mcpManifest: mcpManifest,
}
return t, nil
}
// validate interface
var _ tools.Tool = Tool{}
type Tool struct {
Name string `yaml:"name"`
Kind string `yaml:"kind"`
AuthRequired []string `yaml:"authRequired"`
AllParams tools.Parameters `yaml:"allParams"`
Pool *sql.DB
manifest tools.Manifest
mcpManifest tools.McpManifest
}
func (t Tool) Invoke(ctx context.Context, params tools.ParamValues, accessToken tools.AccessToken) (any, error) {
paramsMap := params.AsMap()
tableNames, ok := paramsMap["table_names"].(string)
if !ok {
return nil, fmt.Errorf("invalid or missing '%s' parameter; expected a string", tableNames)
}
outputFormat, _ := paramsMap["output_format"].(string)
if outputFormat != "simple" && outputFormat != "detailed" {
return nil, fmt.Errorf("invalid value for output_format: must be 'simple' or 'detailed', but got %q", outputFormat)
}
results, err := t.Pool.QueryContext(ctx, listTablesStatement, tableNames, outputFormat)
if err != nil {
return nil, fmt.Errorf("unable to execute query: %w", err)
}
cols, err := results.Columns()
if err != nil {
return nil, fmt.Errorf("unable to retrieve rows column name: %w", err)
}
// create an array of values for each column, which can be re-used to scan each row
rawValues := make([]any, len(cols))
values := make([]any, len(cols))
for i := range rawValues {
values[i] = &rawValues[i]
}
defer results.Close()
colTypes, err := results.ColumnTypes()
if err != nil {
return nil, fmt.Errorf("unable to get column types: %w", err)
}
var out []any
for results.Next() {
err := results.Scan(values...)
if err != nil {
return nil, fmt.Errorf("unable to parse row: %w", err)
}
vMap := make(map[string]any)
for i, name := range cols {
val := rawValues[i]
if val == nil {
vMap[name] = nil
continue
}
vMap[name], err = mysqlcommon.ConvertToType(colTypes[i], val)
if err != nil {
return nil, fmt.Errorf("errors encountered when converting values: %w", err)
}
}
out = append(out, vMap)
}
if err := results.Err(); err != nil {
return nil, fmt.Errorf("errors encountered during row iteration: %w", err)
}
return out, nil
}
func (t Tool) ParseParams(data map[string]any, claims map[string]map[string]any) (tools.ParamValues, error) {
return tools.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() bool {
return false
}

View File

@@ -0,0 +1,75 @@
// 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 mysqllisttables_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"
mysqllisttables "github.com/googleapis/genai-toolbox/internal/tools/mysql/mysqllisttables"
)
func TestParseFromYamlMySQLListTables(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: mysql-list-tables
source: my-mysql-instance
description: some description
authRequired:
- my-google-auth-service
- other-auth-service
`,
want: server.ToolConfigs{
"example_tool": mysqllisttables.Config{
Name: "example_tool",
Kind: "mysql-list-tables",
Source: "my-mysql-instance",
Description: "some description",
AuthRequired: []string{"my-google-auth-service", "other-auth-service"},
},
},
},
}
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)
}
})
}
}

View File

@@ -15,15 +15,21 @@
package mysql
import (
"bytes"
"context"
"database/sql"
"encoding/json"
"fmt"
"io"
"net/http"
"os"
"regexp"
"strings"
"testing"
"time"
"github.com/google/go-cmp/cmp"
"github.com/google/go-cmp/cmp/cmpopts"
"github.com/google/uuid"
"github.com/googleapis/genai-toolbox/internal/testutils"
"github.com/googleapis/genai-toolbox/tests"
@@ -32,6 +38,7 @@ import (
var (
MySQLSourceKind = "mysql"
MySQLToolKind = "mysql-sql"
MySQLListTablesToolKind = "mysql-list-tables"
MySQLDatabase = os.Getenv("MYSQL_DATABASE")
MySQLHost = os.Getenv("MYSQL_HOST")
MySQLPort = os.Getenv("MYSQL_PORT")
@@ -63,6 +70,20 @@ func getMySQLVars(t *testing.T) map[string]any {
}
}
func addPrebuiltToolConfig(t *testing.T, config map[string]any) map[string]any {
tools, ok := config["tools"].(map[string]any)
if !ok {
t.Fatalf("unable to get tools from config")
}
tools["list_tables"] = map[string]any{
"kind": MySQLListTablesToolKind,
"source": "my-instance",
"description": "Lists tables in the database.",
}
config["tools"] = tools
return config
}
// Copied over from mysql.go
func initMySQLConnectionPool(host, port, user, pass, dbname string) (*sql.DB, error) {
dsn := fmt.Sprintf("%s:%s@tcp(%s:%s)/%s?parseTime=true", user, pass, host, port, dbname)
@@ -108,6 +129,8 @@ func TestMySQLToolEndpoints(t *testing.T) {
tmplSelectCombined, tmplSelectFilterCombined := tests.GetMySQLTmplToolStatement()
toolsFile = tests.AddTemplateParamConfig(t, toolsFile, MySQLToolKind, tmplSelectCombined, tmplSelectFilterCombined, "")
toolsFile = addPrebuiltToolConfig(t, toolsFile)
cmd, cleanup, err := tests.StartCmd(ctx, toolsFile, args...)
if err != nil {
t.Fatalf("command initialization returned an error: %s", err)
@@ -131,4 +154,182 @@ func TestMySQLToolEndpoints(t *testing.T) {
tests.RunMCPToolCallMethod(t, mcpMyFailToolWant, mcpSelect1Want)
tests.RunExecuteSqlToolInvokeTest(t, createTableStatement, select1Want)
tests.RunToolInvokeWithTemplateParameters(t, tableNameTemplateParam)
// Run specific MySQL tool tests
runMySQLListTablesTest(t, tableNameParam, tableNameAuth)
}
func runMySQLListTablesTest(t *testing.T, tableNameParam, tableNameAuth string) {
type tableInfo struct {
ObjectName string `json:"object_name"`
SchemaName string `json:"schema_name"`
ObjectDetails string `json:"object_details"`
}
type column struct {
DataType string `json:"data_type"`
ColumnName string `json:"column_name"`
ColumnComment string `json:"column_comment"`
ColumnDefault any `json:"column_default"`
IsNotNullable int `json:"is_not_nullable"`
OrdinalPosition int `json:"ordinal_position"`
}
type objectDetails struct {
Owner any `json:"owner"`
Columns []column `json:"columns"`
Comment string `json:"comment"`
Indexes []any `json:"indexes"`
Triggers []any `json:"triggers"`
Constraints []any `json:"constraints"`
ObjectName string `json:"object_name"`
ObjectType string `json:"object_type"`
SchemaName string `json:"schema_name"`
}
paramTableWant := objectDetails{
ObjectName: tableNameParam,
SchemaName: MySQLDatabase,
ObjectType: "TABLE",
Columns: []column{
{DataType: "int", ColumnName: "id", IsNotNullable: 1, OrdinalPosition: 1},
{DataType: "varchar(255)", ColumnName: "name", OrdinalPosition: 2},
},
Indexes: []any{map[string]any{"index_columns": []any{"id"}, "index_name": "PRIMARY", "is_primary": float64(1), "is_unique": float64(1)}},
Triggers: []any{},
Constraints: []any{map[string]any{"constraint_columns": []any{"id"}, "constraint_name": "PRIMARY", "constraint_type": "PRIMARY KEY", "foreign_key_referenced_columns": any(nil), "foreign_key_referenced_table": any(nil), "constraint_definition": ""}},
}
authTableWant := objectDetails{
ObjectName: tableNameAuth,
SchemaName: MySQLDatabase,
ObjectType: "TABLE",
Columns: []column{
{DataType: "int", ColumnName: "id", IsNotNullable: 1, OrdinalPosition: 1},
{DataType: "varchar(255)", ColumnName: "name", OrdinalPosition: 2},
{DataType: "varchar(255)", ColumnName: "email", OrdinalPosition: 3},
},
Indexes: []any{map[string]any{"index_columns": []any{"id"}, "index_name": "PRIMARY", "is_primary": float64(1), "is_unique": float64(1)}},
Triggers: []any{},
Constraints: []any{map[string]any{"constraint_columns": []any{"id"}, "constraint_name": "PRIMARY", "constraint_type": "PRIMARY KEY", "foreign_key_referenced_columns": any(nil), "foreign_key_referenced_table": any(nil), "constraint_definition": ""}},
}
invokeTcs := []struct {
name string
requestBody io.Reader
wantStatusCode int
want any
isSimple bool
}{
{
name: "invoke list_tables detailed output",
requestBody: bytes.NewBufferString(fmt.Sprintf(`{"table_names": "%s"}`, tableNameAuth)),
wantStatusCode: http.StatusOK,
want: []objectDetails{authTableWant},
},
{
name: "invoke list_tables simple output",
requestBody: bytes.NewBufferString(fmt.Sprintf(`{"table_names": "%s", "output_format": "simple"}`, tableNameAuth)),
wantStatusCode: http.StatusOK,
want: []map[string]any{{"name": tableNameAuth}},
isSimple: true,
},
{
name: "invoke list_tables with multiple table names",
requestBody: bytes.NewBufferString(fmt.Sprintf(`{"table_names": "%s,%s"}`, tableNameParam, tableNameAuth)),
wantStatusCode: http.StatusOK,
want: []objectDetails{authTableWant, paramTableWant},
},
{
name: "invoke list_tables with one existing and one non-existent table",
requestBody: bytes.NewBufferString(fmt.Sprintf(`{"table_names": "%s,non_existent_table"}`, tableNameAuth)),
wantStatusCode: http.StatusOK,
want: []objectDetails{authTableWant},
},
{
name: "invoke list_tables with non-existent table",
requestBody: bytes.NewBufferString(`{"table_names": "non_existent_table"}`),
wantStatusCode: http.StatusOK,
want: nil,
},
}
for _, tc := range invokeTcs {
t.Run(tc.name, func(t *testing.T) {
const api = "http://127.0.0.1:5000/api/tool/list_tables/invoke"
req, err := http.NewRequest(http.MethodPost, api, tc.requestBody)
if err != nil {
t.Fatalf("unable to create request: %v", err)
}
req.Header.Add("Content-type", "application/json")
resp, err := http.DefaultClient.Do(req)
if err != nil {
t.Fatalf("unable to send request: %v", err)
}
defer resp.Body.Close()
if resp.StatusCode != tc.wantStatusCode {
body, _ := io.ReadAll(resp.Body)
t.Fatalf("wrong status code: got %d, want %d, body: %s", resp.StatusCode, tc.wantStatusCode, string(body))
}
if tc.wantStatusCode != http.StatusOK {
return
}
var bodyWrapper struct{ Result json.RawMessage `json:"result"` }
if err := json.NewDecoder(resp.Body).Decode(&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 any
if tc.isSimple {
var tables []tableInfo
if err := json.Unmarshal([]byte(resultString), &tables); err != nil {
t.Fatalf("failed to unmarshal outer JSON array into []tableInfo: %v", err)
}
var details []map[string]any
for _, table := range tables {
var d map[string]any
if err := json.Unmarshal([]byte(table.ObjectDetails), &d); err != nil {
t.Fatalf("failed to unmarshal nested ObjectDetails string: %v", err)
}
details = append(details, d)
}
got = details
} else {
if resultString == "null" {
got = nil
} else {
var tables []tableInfo
if err := json.Unmarshal([]byte(resultString), &tables); err != nil {
t.Fatalf("failed to unmarshal outer JSON array into []tableInfo: %v", err)
}
var details []objectDetails
for _, table := range tables {
var d objectDetails
if err := json.Unmarshal([]byte(table.ObjectDetails), &d); err != nil {
t.Fatalf("failed to unmarshal nested ObjectDetails string: %v", err)
}
details = append(details, d)
}
got = details
}
}
opts := []cmp.Option{
cmpopts.SortSlices(func(a, b objectDetails) bool { return a.ObjectName < b.ObjectName }),
cmpopts.SortSlices(func(a, b column) bool { return a.ColumnName < b.ColumnName }),
cmpopts.SortSlices(func(a, b map[string]any) bool { return a["name"].(string) < b["name"].(string) }),
}
if diff := cmp.Diff(tc.want, got, opts...); diff != "" {
t.Errorf("Unexpected result: got %#v, want: %#v", got, tc.want)
}
})
}
}