diff --git a/Makefile b/Makefile index 6318d2d88..3912f7766 100644 --- a/Makefile +++ b/Makefile @@ -28,7 +28,6 @@ db: db_sqlite usql pg://postgres:pgpass@localhost:55432/testdb?sslmode=disable -f testdata/ddl/postgres95.sql usql pg://postgres:pgpass@localhost:55413/testdb?sslmode=disable -f testdata/ddl/postgres.sql usql my://root:mypass@localhost:33306/testdb -f testdata/ddl/mysql56.sql - usql my://root:mypass@localhost:33308/testdb -f testdata/ddl/mysql.sql usql my://root:mypass@localhost:33308/testdb -c "CREATE DATABASE IF NOT EXISTS relations;" usql my://root:mypass@localhost:33308/relations -f testdata/ddl/detect_relations.sql usql my://root:mypass@localhost:33308/testdb -c "CREATE DATABASE IF NOT EXISTS relations_singular;" diff --git a/docker-compose.yml b/docker-compose.yml index ca8b36dc1..4a608e8e0 100644 --- a/docker-compose.yml +++ b/docker-compose.yml @@ -35,6 +35,9 @@ services: environment: - MYSQL_DATABASE=testdb - MYSQL_ROOT_PASSWORD=mypass + - LANG=C.UTF-8 + volumes: + - ./testdata/ddl/mysql:/docker-entrypoint-initdb.d mariadb: image: mariadb:10.5 restart: always diff --git a/drivers/mssql/mssql.go b/drivers/mssql/mssql.go index b1382de45..3de3b558f 100644 --- a/drivers/mssql/mssql.go +++ b/drivers/mssql/mssql.go @@ -8,6 +8,7 @@ import ( "strings" "github.com/k1LoW/tbls/ddl" + "github.com/k1LoW/tbls/dict" "github.com/k1LoW/tbls/schema" "github.com/pkg/errors" ) @@ -402,6 +403,12 @@ ORDER BY i.index_id tables = append(tables, table) } + functions, err := m.getFunctions() + if err != nil { + return err + } + s.Functions = functions + s.Tables = tables // relations @@ -459,6 +466,67 @@ ORDER BY i.index_id return nil } +const query = `SELECT SCHEMA_NAME(obj.schema_id) AS schema_name, + obj.name as name, + CASE type + WHEN 'FN' THEN 'SQL scalar function' + WHEN 'TF' THEN 'SQL table-valued-function' + WHEN 'IF' THEN 'SQL inline table-valued function' + WHEN 'P' THEN 'SQL Stored Procedure' + WHEN 'X' THEN 'Extended stored procedure' + END AS type, + TYPE_NAME(ret.user_type_id) AS return_type, + SUBSTRING(par.parameters, 0, LEN(par.parameters)) AS parameters +FROM sys.objects obj +JOIN sys.sql_modules mod +ON mod.object_id = obj.object_id +CROSS APPLY (SELECT p.name + ' ' + TYPE_NAME(p.user_type_id) + ', ' + FROM sys.parameters p + WHERE p.object_id = obj.object_id + AND p.parameter_id != 0 + FOR XML PATH ('') ) par (parameters) +LEFT JOIN sys.parameters ret + ON obj.object_id = ret.object_id + AND ret.parameter_id = 0 +WHERE obj.type IN ('FN', 'TF', 'IF', 'P', 'X') +ORDER BY schema_name, name;` + +func (m *Mssql) getFunctions() ([]*schema.Function, error) { + functions := []*schema.Function{} + functionsResult, err := m.db.Query(query) + if err != nil { + return nil, errors.WithStack(err) + } + defer functionsResult.Close() + + for functionsResult.Next() { + var ( + schemaName string + name string + typeValue string + returnType sql.NullString + arguments sql.NullString + ) + err := functionsResult.Scan(&schemaName, &name, &typeValue, &returnType, &arguments) + if err != nil { + return functions, errors.WithStack(err) + } + function := &schema.Function{ + Name: fullTableName(schemaName, name), + Type: typeValue, + ReturnType: returnType.String, + Arguments: arguments.String, + } + + functions = append(functions, function) + } + return functions, nil +} + +func fullTableName(owner string, tableName string) string { + return fmt.Sprintf("%s.%s", owner, tableName) +} + func (m *Mssql) Info() (*schema.Driver, error) { var v string row := m.db.QueryRow(`SELECT @@VERSION`) @@ -467,9 +535,17 @@ func (m *Mssql) Info() (*schema.Driver, error) { return nil, err } + dct := dict.New() + dct.Merge(map[string]string{ + "Functions": "Stored procedures and functions", + }) + d := &schema.Driver{ Name: "sqlserver", DatabaseVersion: v, + Meta: &schema.DriverMeta{ + Dict: &dct, + }, } return d, nil } diff --git a/drivers/mysql/mysql.go b/drivers/mysql/mysql.go index fffc335a5..434c379b3 100644 --- a/drivers/mysql/mysql.go +++ b/drivers/mysql/mysql.go @@ -8,6 +8,7 @@ import ( "github.com/aquasecurity/go-version/pkg/version" "github.com/k1LoW/tbls/ddl" + "github.com/k1LoW/tbls/dict" "github.com/k1LoW/tbls/drivers" "github.com/k1LoW/tbls/schema" "github.com/pkg/errors" @@ -418,6 +419,12 @@ WHERE table_schema = ? AND table_name = ? ORDER BY ordinal_position` tables = append(tables, table) } + functions, err := m.getFunctions() + if err != nil { + return err + } + s.Functions = functions + s.Tables = tables // Relations @@ -473,6 +480,50 @@ WHERE table_schema = ? AND table_name = ? ORDER BY ordinal_position` return nil } +const queryFunctions = `SELECT r.routine_schema as database_name, +r.routine_name, +r.routine_type AS type, +r.data_type AS return_type, +GROUP_CONCAT(CONCAT(p.parameter_name, ' ', p.data_type) SEPARATOR '; ') AS parameter +FROM information_schema.routines r +LEFT JOIN information_schema.parameters p + ON p.specific_schema = r.routine_schema + AND p.specific_name = r.specific_name +WHERE routine_schema NOT IN ('sys', 'information_schema', 'mysql', 'performance_schema') +GROUP BY r.routine_schema, r.routine_name, r.routine_type, r.data_type, r.routine_definition` + +func (m *Mysql) getFunctions() ([]*schema.Function, error) { + functions := []*schema.Function{} + functionsResult, err := m.db.Query(queryFunctions) + if err != nil { + return nil, errors.WithStack(err) + } + defer functionsResult.Close() + + for functionsResult.Next() { + var ( + databaseName string + name string + typeValue string + returnType string + arguments sql.NullString + ) + err := functionsResult.Scan(&databaseName, &name, &typeValue, &returnType, &arguments) + if err != nil { + return functions, errors.WithStack(err) + } + subroutine := &schema.Function{ + Name: name, + Type: typeValue, + ReturnType: returnType, + Arguments: arguments.String, + } + + functions = append(functions, subroutine) + } + return functions, nil +} + // Info return schema.Driver func (m *Mysql) Info() (*schema.Driver, error) { var v string @@ -487,9 +538,17 @@ func (m *Mysql) Info() (*schema.Driver, error) { name = "mariadb" } + dct := dict.New() + dct.Merge(map[string]string{ + "Functions": "Stored procedures and functions", + }) + d := &schema.Driver{ Name: name, DatabaseVersion: v, + Meta: &schema.DriverMeta{ + Dict: &dct, + }, } return d, nil } @@ -509,8 +568,5 @@ SELECT table_name, table_type, table_comment FROM information_schema.tables WHER } func convertColumnNullable(str string) bool { - if str == "NO" { - return false - } - return true + return str != "NO" } diff --git a/drivers/postgres/postgres.go b/drivers/postgres/postgres.go index fc492af32..2dc5c9ee3 100644 --- a/drivers/postgres/postgres.go +++ b/drivers/postgres/postgres.go @@ -8,6 +8,7 @@ import ( "github.com/aquasecurity/go-version/pkg/version" "github.com/k1LoW/tbls/ddl" + "github.com/k1LoW/tbls/dict" "github.com/k1LoW/tbls/schema" "github.com/lib/pq" "github.com/pkg/errors" @@ -296,6 +297,12 @@ ORDER BY tgrelid tables = append(tables, table) } + functions, err := p.getFunctions() + if err != nil { + return err + } + s.Functions = functions + s.Tables = tables // Relations @@ -364,6 +371,106 @@ ORDER BY tgrelid return nil } +const queryFunctions95 = `SELECT n.nspname AS schema_name, +p.proname AS specific_name, +TEXT 'FUNCTION', +t.typname AS return_type, +pg_get_function_arguments(p.oid) AS arguments +from pg_proc p +LEFT JOIN pg_namespace n ON p.pronamespace = n.oid +LEFT JOIN pg_type t ON t.oid = p.prorettype +WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')` + +const queryFunctions = `SELECT n.nspname AS schema_name, +p.proname AS specific_name, +CASE WHEN p.prokind = 'p' THEN TEXT 'PROCEDURE' ELSE CASE WHEN p.prokind = 'f' THEN TEXT 'FUNCTION' ELSE p.prokind END END, +t.typname AS return_type, +pg_get_function_arguments(p.oid) AS arguments +FROM pg_proc p +LEFT JOIN pg_namespace n ON p.pronamespace = n.oid +LEFT JOIN pg_type t ON t.oid = p.prorettype +WHERE n.nspname NOT IN ('pg_catalog', 'information_schema')` + +const queryStoredProcedureSupported = `SELECT column_name +FROM information_schema.columns +WHERE table_name='pg_proc' and column_name='prokind';` + +func (p *Postgres) isProceduresSupported() (bool, error) { + result, err := p.db.Query(queryStoredProcedureSupported) + if err != nil { + return false, errors.WithStack(err) + } + defer result.Close() + + if result.Next() { + var ( + name sql.NullString + ) + err := result.Scan(&name) + if err != nil { + return false, errors.WithStack(err) + } + return true, nil + } + return false, nil +} + +func (p *Postgres) getFunctions() ([]*schema.Function, error) { + var functions []*schema.Function + storedProcedureSupported, err := p.isProceduresSupported() + if err != nil { + return nil, errors.WithStack(err) + } + if storedProcedureSupported { + functions, err = p.getFunctionsByQuery(queryFunctions) + if err != nil { + return nil, errors.WithStack(err) + } + } else { + functions, err = p.getFunctionsByQuery(queryFunctions95) + if err != nil { + return nil, errors.WithStack(err) + } + } + return functions, nil +} + +func (p *Postgres) getFunctionsByQuery(query string) ([]*schema.Function, error) { + functions := []*schema.Function{} + functionsResult, err := p.db.Query(query) + if err != nil { + return nil, errors.WithStack(err) + } + defer functionsResult.Close() + + for functionsResult.Next() { + var ( + schemaName string + name string + typeValue string + returnType string + arguments sql.NullString + ) + err := functionsResult.Scan(&schemaName, &name, &typeValue, &returnType, &arguments) + if err != nil { + return functions, errors.WithStack(err) + } + function := &schema.Function{ + Name: fullTableName(schemaName, name), + Type: typeValue, + ReturnType: returnType, + Arguments: arguments.String, + } + + functions = append(functions, function) + } + return functions, nil +} + +func fullTableName(owner string, tableName string) string { + return fmt.Sprintf("%s.%s", owner, tableName) +} + // Info return schema.Driver func (p *Postgres) Info() (*schema.Driver, error) { var v string @@ -378,10 +485,17 @@ func (p *Postgres) Info() (*schema.Driver, error) { name = "redshift" } + dct := dict.New() + dct.Merge(map[string]string{ + "Functions": "Stored procedures and functions", + }) + d := &schema.Driver{ Name: name, DatabaseVersion: v, - Meta: &schema.DriverMeta{}, + Meta: &schema.DriverMeta{ + Dict: &dct, + }, } return d, nil } diff --git a/output/json/json_test.go b/output/json/json_test.go index ba116e1e0..851faba12 100644 --- a/output/json/json_test.go +++ b/output/json/json_test.go @@ -92,7 +92,7 @@ func newTestSchema() *schema.Schema { Comment: "table a", Columns: []*schema.Column{ ca, - &schema.Column{ + { Name: "a2", Type: "datetime", Comment: "column a2", @@ -110,7 +110,7 @@ func newTestSchema() *schema.Schema { Comment: "table b", Columns: []*schema.Column{ cb, - &schema.Column{ + { Name: "b2", Comment: "column b2", Type: "text", @@ -136,6 +136,7 @@ func newTestSchema() *schema.Schema { Relations: []*schema.Relation{ r, }, + Functions: []*schema.Function{}, Driver: &schema.Driver{ Name: "testdriver", DatabaseVersion: "1.0.0", diff --git a/output/md/md.go b/output/md/md.go index c65eee35f..fbca535f2 100644 --- a/output/md/md.go +++ b/output/md/md.go @@ -478,16 +478,41 @@ func (m *Md) makeSchemaTemplateData(s *schema.Schema) map[string]interface{} { tablesData = m.addNumberToTable(tablesData) } + tablesSubroutineData := [][]string{} + tablesSubroutineHeader := []string{ + m.config.MergedDict.Lookup("Name"), + m.config.MergedDict.Lookup("ReturnType"), + m.config.MergedDict.Lookup("Arguments"), + m.config.MergedDict.Lookup("Type"), + } + tablesSubroutineHeaderLine := []string{"----", "-------", "-------", "----"} + tablesSubroutineData = append(tablesSubroutineData, + tablesSubroutineHeader, + tablesSubroutineHeaderLine, + ) + + for _, t := range s.Functions { + data := []string{ + t.Name, + t.ReturnType, + t.Arguments, + t.Type, + } + tablesSubroutineData = append(tablesSubroutineData, data) + } + if adjust { return map[string]interface{}{ - "Schema": s, - "Tables": adjustTable(tablesData), + "Schema": s, + "Tables": adjustTable(tablesData), + "Functions": adjustTable(tablesSubroutineData), } } return map[string]interface{}{ - "Schema": s, - "Tables": tablesData, + "Schema": s, + "Tables": tablesData, + "Functions": tablesSubroutineData, } } diff --git a/output/md/templates/index.md.tmpl b/output/md/templates/index.md.tmpl index 777f07d2a..f26f97f09 100644 --- a/output/md/templates/index.md.tmpl +++ b/output/md/templates/index.md.tmpl @@ -17,6 +17,13 @@ {{ range $t := .Tables }} |{{ range $d := $t }} {{ $d | nl2br }} |{{ end }} {{- end -}} +{{- if .Schema.Functions }} + +## {{ "Functions" | lookup }} +{{ range $t := .Functions }} +|{{ range $d := $t }} {{ $d | nl2br }} |{{ end }} +{{- end -}} +{{- end -}} {{- if .er }} ## {{ "Relations" | lookup }} diff --git a/output/yaml/yaml_test.go b/output/yaml/yaml_test.go index d5bb09339..d72183c5a 100644 --- a/output/yaml/yaml_test.go +++ b/output/yaml/yaml_test.go @@ -92,7 +92,7 @@ func newTestSchema() *schema.Schema { Comment: "table a", Columns: []*schema.Column{ ca, - &schema.Column{ + { Name: "a2", Type: "datetime", Comment: "column a2", @@ -110,7 +110,7 @@ func newTestSchema() *schema.Schema { Comment: "table b", Columns: []*schema.Column{ cb, - &schema.Column{ + { Name: "b2", Comment: "column b2", Type: "text", @@ -136,6 +136,7 @@ func newTestSchema() *schema.Schema { Relations: []*schema.Relation{ r, }, + Functions: []*schema.Function{}, Driver: &schema.Driver{ Name: "testdriver", DatabaseVersion: "1.0.0", diff --git a/sample/adjust/README.md b/sample/adjust/README.md index 87eaeeffb..9b2e2ac39 100644 --- a/sample/adjust/README.md +++ b/sample/adjust/README.md @@ -25,6 +25,23 @@ Sample PostgreSQL database document. | [time.hyphenated-table](time.hyphenated-table.md) | 1 | | BASE TABLE | | [time.referencing](time.referencing.md) | 3 | | BASE TABLE | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ------------------------- | ---------- | ------------------------- | --------- | +| public.uuid_nil | uuid | | FUNCTION | +| public.uuid_ns_dns | uuid | | FUNCTION | +| public.uuid_ns_url | uuid | | FUNCTION | +| public.uuid_ns_oid | uuid | | FUNCTION | +| public.uuid_ns_x500 | uuid | | FUNCTION | +| public.uuid_generate_v1 | uuid | | FUNCTION | +| public.uuid_generate_v1mc | uuid | | FUNCTION | +| public.uuid_generate_v3 | uuid | namespace uuid, name text | FUNCTION | +| public.uuid_generate_v4 | uuid | | FUNCTION | +| public.uuid_generate_v5 | uuid | namespace uuid, name text | FUNCTION | +| public.update_updated | trigger | | FUNCTION | +| public.reset_comment | void | comment_id integer | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/detect_relations/README.md b/sample/detect_relations/README.md index 08da2f375..689a6a5d1 100644 --- a/sample/detect_relations/README.md +++ b/sample/detect_relations/README.md @@ -22,6 +22,13 @@ Sample database document. | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | | [users](users.md) | 6 | Users table | BASE TABLE | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/detect_relations_singular/README.md b/sample/detect_relations_singular/README.md index 85bdd8fdd..e0cf4061c 100644 --- a/sample/detect_relations_singular/README.md +++ b/sample/detect_relations_singular/README.md @@ -22,6 +22,13 @@ Sample database document. | [user](user.md) | 6 | User table | BASE TABLE | | | [user_option](user_option.md) | 4 | User option table | BASE TABLE | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/dict/README.md b/sample/dict/README.md index f4fb28499..a3d72c263 100644 --- a/sample/dict/README.md +++ b/sample/dict/README.md @@ -14,6 +14,13 @@ | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | [users](users.md) | 6 | Users table | BASE TABLE | +## Stored procedures and functions + +| 名前 | ReturnType | Arguments | タイプ | +| -------------- | ---------- | -------------- | --------- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## ER図 ![er](schema.svg) diff --git a/sample/exclude/README.md b/sample/exclude/README.md index 8cce79818..5df44b1c4 100644 --- a/sample/exclude/README.md +++ b/sample/exclude/README.md @@ -12,6 +12,13 @@ | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | [users](users.md) | 6 | Users table | BASE TABLE | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/font/README.md b/sample/font/README.md index 04e438389..b529dbb94 100644 --- a/sample/font/README.md +++ b/sample/font/README.md @@ -18,6 +18,13 @@ | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | [users](users.md) | 6 | Users table | BASE TABLE | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.png) diff --git a/sample/mssql/README.md b/sample/mssql/README.md index 1d3c16ea4..4731b74b9 100644 --- a/sample/mssql/README.md +++ b/sample/mssql/README.md @@ -24,6 +24,13 @@ Sample database document. | [administrator.blogs](administrator.blogs.md) | 6 | admin blogs | BASIC TABLE | | | [name with spaces](name%20with%20spaces.md) | 1 | | VIEW | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| dbo.get_user | | @userid int | SQL inline table-valued function | +| dbo.What_DB_is_that | | @ID int | SQL Stored Procedure | + ## Relations ![er](schema.svg) diff --git a/sample/mysql/README.md b/sample/mysql/README.md index cefe7375d..5694dd1d4 100644 --- a/sample/mysql/README.md +++ b/sample/mysql/README.md @@ -22,6 +22,13 @@ Sample database document. | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | | [users](users.md) | 6 | Users table | BASE TABLE | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/number/README.md b/sample/number/README.md index de03d1b18..28e67c6ef 100644 --- a/sample/number/README.md +++ b/sample/number/README.md @@ -22,6 +22,13 @@ Sample database document. | 8 | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | | 9 | [users](users.md) | 6 | Users table | BASE TABLE | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/png/README.md b/sample/png/README.md index 884c9591c..8529bf06d 100644 --- a/sample/png/README.md +++ b/sample/png/README.md @@ -22,6 +22,13 @@ Sample database document. | [user_options](user_options.md) | 4 | User options table | BASE TABLE | | | [users](users.md) | 6 | Users table | BASE TABLE | | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| CustomerLevel | varchar | credit decimal | FUNCTION | +| GetAllComments | | | PROCEDURE | + ## Relations ![er](schema.png) diff --git a/sample/postgres/README.md b/sample/postgres/README.md index 6371b8f7b..740854d6d 100644 --- a/sample/postgres/README.md +++ b/sample/postgres/README.md @@ -25,6 +25,23 @@ Sample PostgreSQL database document. | [time.hyphenated-table](time.hyphenated-table.md) | 1 | | BASE TABLE | | [time.referencing](time.referencing.md) | 3 | | BASE TABLE | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| public.uuid_nil | uuid | | FUNCTION | +| public.uuid_ns_dns | uuid | | FUNCTION | +| public.uuid_ns_url | uuid | | FUNCTION | +| public.uuid_ns_oid | uuid | | FUNCTION | +| public.uuid_ns_x500 | uuid | | FUNCTION | +| public.uuid_generate_v1 | uuid | | FUNCTION | +| public.uuid_generate_v1mc | uuid | | FUNCTION | +| public.uuid_generate_v3 | uuid | namespace uuid, name text | FUNCTION | +| public.uuid_generate_v4 | uuid | | FUNCTION | +| public.uuid_generate_v5 | uuid | namespace uuid, name text | FUNCTION | +| public.update_updated | trigger | | FUNCTION | +| public.reset_comment | void | comment_id integer | PROCEDURE | + ## Relations ![er](schema.svg) diff --git a/sample/postgres95/README.md b/sample/postgres95/README.md index 0252257db..35eec5feb 100644 --- a/sample/postgres95/README.md +++ b/sample/postgres95/README.md @@ -25,6 +25,22 @@ Sample PostgreSQL database document. | [time.hyphenated-table](time.hyphenated-table.md) | 1 | | BASE TABLE | | [time.referencing](time.referencing.md) | 3 | | BASE TABLE | +## Stored procedures and functions + +| Name | ReturnType | Arguments | Type | +| ---- | ------- | ------- | ---- | +| public.uuid_nil | uuid | | FUNCTION | +| public.uuid_ns_dns | uuid | | FUNCTION | +| public.uuid_ns_url | uuid | | FUNCTION | +| public.uuid_ns_oid | uuid | | FUNCTION | +| public.uuid_ns_x500 | uuid | | FUNCTION | +| public.uuid_generate_v1 | uuid | | FUNCTION | +| public.uuid_generate_v1mc | uuid | | FUNCTION | +| public.uuid_generate_v3 | uuid | namespace uuid, name text | FUNCTION | +| public.uuid_generate_v4 | uuid | | FUNCTION | +| public.uuid_generate_v5 | uuid | namespace uuid, name text | FUNCTION | +| public.update_updated | trigger | | FUNCTION | + ## Relations ![er](schema.svg) diff --git a/schema/json.go b/schema/json.go index 4aaad0261..3f8d54ea6 100644 --- a/schema/json.go +++ b/schema/json.go @@ -17,6 +17,7 @@ func (s Schema) MarshalJSON() ([]byte, error) { Desc string `json:"desc"` Tables []*Table `json:"tables"` Relations []*Relation `json:"relations"` + Functions []*Function `json:"functions"` Driver *Driver `json:"driver"` Labels Labels `json:"labels,omitempty"` }{ @@ -25,10 +26,26 @@ func (s Schema) MarshalJSON() ([]byte, error) { Tables: s.Tables, Relations: s.Relations, Driver: s.Driver, + Functions: s.Functions, Labels: s.Labels, }) } +// MarshalJSON return custom JSON byte +func (d Function) MarshalJSON() ([]byte, error) { + return json.Marshal(&struct { + Name string `json:"name"` + ReturnType string `json:"return_type"` + Arguments string `json:"arguments"` + Type string `json:"type"` + }{ + Name: d.Name, + ReturnType: d.ReturnType, + Arguments: d.Arguments, + Type: d.Type, + }) +} + // MarshalJSON return custom JSON byte func (d Driver) MarshalJSON() ([]byte, error) { if d.Meta == nil { diff --git a/schema/schema.go b/schema/schema.go index f10ecd5f8..076e4afa2 100644 --- a/schema/schema.go +++ b/schema/schema.go @@ -104,6 +104,14 @@ type DriverMeta struct { Dict *dict.Dict `json:"dict,omitempty"` } +// Function is the struct for tbls stored procedure/function information +type Function struct { + Name string `json:"name"` + ReturnType string `json:"return_type" yaml:"returnType"` + Arguments string `json:"arguments"` + Type string `json:"type"` +} + // Driver is the struct for tbls driver information type Driver struct { Name string `json:"name"` @@ -117,6 +125,7 @@ type Schema struct { Desc string `json:"desc"` Tables []*Table `json:"tables"` Relations []*Relation `json:"relations"` + Functions []*Function `json:"functions"` Driver *Driver `json:"driver"` Labels Labels `json:"labels,omitempty"` } diff --git a/testdata/ddl/mssql.sql b/testdata/ddl/mssql.sql index fbd1fb4f8..984c4d8d6 100644 --- a/testdata/ddl/mssql.sql +++ b/testdata/ddl/mssql.sql @@ -13,6 +13,8 @@ DROP TABLE IF EXISTS user_options; DROP TABLE IF EXISTS users; DROP SCHEMA IF EXISTS administrator; DROP VIEW IF EXISTS "name with spaces"; +DROP FUNCTION IF EXISTS get_user; +DROP PROC IF EXISTS What_DB_is_that; CREATE TABLE users ( id int NOT NULL IDENTITY(1,1) PRIMARY KEY, @@ -171,3 +173,17 @@ CREATE VIEW "name with spaces" AS ( SELECT TOP 1 p.title FROM posts AS p ); + +CREATE FUNCTION get_user (@userid int) +RETURNS TABLE +AS +RETURN +( + SELECT u.username, u.email + FROM users AS u + WHERE u.id = @userid +); + +CREATE PROC What_DB_is_that @ID INT +AS +SELECT DB_NAME(@ID) AS ThatDB; diff --git a/testdata/ddl/mysql.sql b/testdata/ddl/mysql/mysql.sql similarity index 84% rename from testdata/ddl/mysql.sql rename to testdata/ddl/mysql/mysql.sql index 42605b4fd..617273846 100644 --- a/testdata/ddl/mysql.sql +++ b/testdata/ddl/mysql/mysql.sql @@ -8,6 +8,8 @@ DROP TABLE IF EXISTS comments; DROP TABLE IF EXISTS posts; DROP TABLE IF EXISTS user_options; DROP TABLE IF EXISTS users; +DROP PROCEDURE IF EXISTS GetAllComments; +DROP FUNCTION IF EXISTS CustomerLevel; CREATE TABLE users ( id int PRIMARY KEY AUTO_INCREMENT, @@ -101,3 +103,32 @@ CREATE TABLE `hyphen-table` ( CREATE TRIGGER update_posts_updated BEFORE UPDATE ON posts FOR EACH ROW SET NEW.updated = CURRENT_TIMESTAMP(); + +DELIMITER // +CREATE PROCEDURE GetAllComments() +BEGIN + SELECT * FROM comments; +END// +DELIMITER ; + +DELIMITER $$ +CREATE FUNCTION CustomerLevel( + credit DECIMAL(10,2) +) +RETURNS VARCHAR(20) +DETERMINISTIC +BEGIN + DECLARE customerLevel VARCHAR(20); + + IF credit > 50000 THEN + SET customerLevel = 'PLATINUM'; + ELSEIF (credit >= 50000 AND + credit <= 10000) THEN + SET customerLevel = 'GOLD'; + ELSEIF credit < 10000 THEN + SET customerLevel = 'SILVER'; + END IF; + -- return the customer level + RETURN (customerLevel); +END$$ +DELIMITER ; diff --git a/testdata/ddl/postgres.sql b/testdata/ddl/postgres.sql index a2c853a83..05281e4e4 100644 --- a/testdata/ddl/postgres.sql +++ b/testdata/ddl/postgres.sql @@ -219,3 +219,13 @@ CREATE TABLE time.referencing ( CONSTRAINT referencing_bar_id FOREIGN KEY(bar_id) REFERENCES time.bar(id), CONSTRAINT referencing_ht_id FOREIGN KEY(ht_id) REFERENCES time."hyphenated-table"(id) ); + +CREATE OR REPLACE PROCEDURE reset_comment (comment_id int) AS ' + begin + update comments + set comment = "updated" + where id = comment_id; + + commit; + end; +' LANGUAGE plpgsql; diff --git a/testdata/json_test_schema.json.golden b/testdata/json_test_schema.json.golden index 0b52f4e52..ed7eda750 100644 --- a/testdata/json_test_schema.json.golden +++ b/testdata/json_test_schema.json.golden @@ -67,6 +67,7 @@ "virtual": false } ], + "functions": [], "driver": { "name": "testdriver", "database_version": "1.0.0", diff --git a/testdata/yaml_test_schema.yaml.golden b/testdata/yaml_test_schema.yaml.golden index 71031fe79..e10ce96e4 100644 --- a/testdata/yaml_test_schema.yaml.golden +++ b/testdata/yaml_test_schema.yaml.golden @@ -46,6 +46,7 @@ relations: - b def: "" virtual: false +functions: [] driver: name: testdriver databaseVersion: 1.0.0