Skip to content

Commit

Permalink
Merge pull request #101 from RJSonnenberg/main
Browse files Browse the repository at this point in the history
Add MySql support to SqlHydra.Cli
  • Loading branch information
JordanMarr authored Jul 10, 2024
2 parents 910da6b + 09a007f commit a6e9cd7
Show file tree
Hide file tree
Showing 6 changed files with 270 additions and 15 deletions.
41 changes: 38 additions & 3 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -451,6 +451,9 @@ let getProductsWithCategory () =
}
```

> [!WARNING]
> You need to write the join `on` equality condition using the known (left) table variable on the left and the new (right) one on the right; otherwise, the F# compiler will complain that `p` and `c` are not defined. (This order condition is due to the way F# [Query Expressions](https://learn.microsoft.com/en-us/dotnet/fsharp/language-reference/query-expressions) are defined.)
Select `Customer` with left joined `Address` where `CustomerID` is in a list of values:
(Note that left joined tables will be of type `'T option`, so you will need to use the `.Value` property to access join columns.)

Expand Down Expand Up @@ -490,7 +493,8 @@ select {
}
```

💥 The `join` `on` clause only supports simple column = column comparisons. Constant value parameters are not supported.
> [!WARNING]
> The `join` `on` clause only supports simple column = column comparisons. Constant value parameters are not supported.
Any custom filters that you might normally put in the `on` clause, especially those involving input parameters, will need to be moved to the `where` clause.
This is because the F# `join` `on` syntax does not support complex filter clauses.

Expand Down Expand Up @@ -587,8 +591,8 @@ let! customersWithNoSalesPersonCount =
count
}
```

💥 In some cases when selecting an aggregate of a non-NULL column, the database will still return NULL if the query result set is empty, for example if selecting the MAX of an INT column in an empty table. This is not supported and will throw an exception. If your query might return NULL for the aggregate of a non-NULL column, you may include `Some` in the aggregate to support parsing the NULL as an `Option` value:
> [!WARNING]
> In some cases when selecting an aggregate of a non-NULL column, the database will still return NULL if the query result set is empty, for example if selecting the MAX of an INT column in an empty table. This is not supported and will throw an exception. If your query might return NULL for the aggregate of a non-NULL column, you may include `Some` in the aggregate to support parsing the NULL as an `Option` value:
❌ INCORRECT:
```F#
Expand Down Expand Up @@ -964,6 +968,8 @@ let getCustomers filters =
Sometimes it is easier to just write a custom SQL query. This can be helpful when you have a very custom query, or are using SQL constructs that do not yet exist in `SqlHydra.Query`.
You can do this while still maintaining the benefits of the strongly typed generated `HydraReader`.

This example uses the generated `HydraReader` to hydrate the generated `dbo.Product` table record.

```F#
let getTop10Products(conn: SqlConnection) = task {
let sql = $"SELECT TOP 10 * FROM {nameof dbo.Product} p"
Expand All @@ -978,6 +984,35 @@ let getTop10Products(conn: SqlConnection) = task {
}
```

The next example uses a query expression that modifies the underlying `SqlKata` query (using the the `kata` custom operation) to override the `SELECT` clause, and then manually reads the results into a custom record type.
This technique can be useful if you want to select custom columns that use functions with a custom result type, but you still want to use a strongly typed query expression.

```F#
/// A custom result type to be used for this query.
type CityRow = { City3: string; Number: int }
let getCities() = task {
use ctx = openContext()
let! reader =
select {
for a in Person.Address do
where (a.City |=| [ "Seattle"; "Denver" ])
kata (fun query -> query.SelectRaw("SUBSTRING(City, 1, 3) AS City3, 123 AS Number"))
}
|> ctx.GetReaderAsync
return
[
while reader.Read() do
{
City3 = reader.Get "City3"
Number = reader.Get "Number"
}
]
}
```

See more examples of using the generated `HydraReader`:
https://github.com/JordanMarr/SqlHydra/wiki/DataReaders

10 changes: 10 additions & 0 deletions src/SqlHydra.Cli/MySql/AppInfo.fs
Original file line number Diff line number Diff line change
@@ -0,0 +1,10 @@
module SqlHydra.MySql.AppInfo

open SqlHydra.Domain

let info =
{
AppInfo.Name = "SqlHydra.MySql"
AppInfo.DefaultReaderType = "System.Data.Common.DbDataReader" // "System.Data.IDataReader"
AppInfo.DefaultProvider = "MySql.Data"
}
80 changes: 80 additions & 0 deletions src/SqlHydra.Cli/MySql/MySqlDataTypes.fs
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
module SqlHydra.MySql.MySqlDataTypes

open System.Data
open MySql.Data.MySqlClient
open SqlHydra.Domain

let private r : System.Data.Common.DbDataReader = null

/// A list of supported column type mappings
let supportedTypeMappings = // https://dev.mysql.com/doc/refman/9.0/en/data-types.html
[// ColumnTypeAlias ClrType DbType ProviderDbType
"bit", "int16", DbType.Int16, Some (nameof MySqlDbType.Bit), nameof r.GetInt16
"tinyint", "int16", DbType.Int16, Some (nameof MySqlDbType.Int16), nameof r.GetInt16
"bool", "int16", DbType.Boolean, Some (nameof MySqlDbType.Int16), nameof r.GetBoolean
"boolean", "int16", DbType.Boolean, Some (nameof MySqlDbType.Int16), nameof r.GetBoolean
"smallint", "int16", DbType.Int16, Some (nameof MySqlDbType.Int16), nameof r.GetInt16
"mediumint", "int", DbType.Int32, Some (nameof MySqlDbType.Int24), nameof r.GetInt32
"int", "int", DbType.Int32, Some (nameof MySqlDbType.Int32), nameof r.GetInt32
"integer", "int", DbType.Int32, Some (nameof MySqlDbType.Int32), nameof r.GetInt32
"bigint", "int64", DbType.Int64, Some (nameof MySqlDbType.Int64), nameof r.GetInt64
"decimal", "decimal", DbType.Decimal, Some (nameof MySqlDbType.Decimal), nameof r.GetDecimal
"dec", "decimal", DbType.Decimal, Some (nameof MySqlDbType.Decimal), nameof r.GetDecimal
"float", "float", DbType.Single, Some (nameof MySqlDbType.Float), nameof r.GetFloat
"double", "double", DbType.Double, Some (nameof MySqlDbType.Double), nameof r.GetDouble
"double precision", "double", DbType.Double, Some (nameof MySqlDbType.Double), nameof r.GetDouble
"char", "string", DbType.String, Some (nameof MySqlDbType.String), nameof r.GetString
"varchar", "string", DbType.String, Some (nameof MySqlDbType.VarChar), nameof r.GetString
"nvarchar", "string", DbType.String, Some (nameof MySqlDbType.VarChar), nameof r.GetString
"binary", "byte[]", DbType.Binary, Some (nameof MySqlDbType.Binary), nameof r.GetFieldValue
"char BYTE", "byte[]", DbType.Binary, Some (nameof MySqlDbType.Binary), nameof r.GetFieldValue
"varbinary", "byte[]", DbType.Binary, Some (nameof MySqlDbType.VarBinary), nameof r.GetFieldValue
"tinyblob", "byte[]", DbType.Binary, Some (nameof MySqlDbType.TinyBlob), nameof r.GetFieldValue
"blob", "byte[]", DbType.Binary, Some (nameof MySqlDbType.Blob), nameof r.GetFieldValue
"mediumblob", "byte[]", DbType.Binary, Some (nameof MySqlDbType.MediumBlob), nameof r.GetFieldValue
"longblob", "byte[]", DbType.Binary, Some (nameof MySqlDbType.LongBlob), nameof r.GetFieldValue
"tinytext", "string", DbType.String, Some (nameof MySqlDbType.TinyText), nameof r.GetString
"text", "string", DbType.String, Some (nameof MySqlDbType.Text), nameof r.GetString
"mediumtext", "string", DbType.String, Some (nameof MySqlDbType.MediumText), nameof r.GetString
"longtext", "string", DbType.String, Some (nameof MySqlDbType.LongText), nameof r.GetString
"enum", "string", DbType.String, Some (nameof MySqlDbType.Enum), nameof r.GetString
"set", "string", DbType.String, Some (nameof MySqlDbType.Set), nameof r.GetString
"json", "string", DbType.String, Some (nameof MySqlDbType.JSON), nameof r.GetString
"date", "System.DateOnly", DbType.DateTime, Some (nameof MySqlDbType.Date), "GetDateOnly"
"time", "System.TimeOnly", DbType.Time, Some (nameof MySqlDbType.Time), "GetTimeOnly"
"datetime", "System.DateTime", DbType.DateTime, Some (nameof MySqlDbType.DateTime), nameof r.GetDateTime
"timestamp", "System.DateTime", DbType.DateTime, Some (nameof MySqlDbType.Timestamp), nameof r.GetDateTime
"year", "int16", DbType.Int16, Some (nameof MySqlDbType.Year), nameof r.GetInt16
// skipped unsupported
"bool", "bool", DbType.Boolean, Some (nameof MySqlDbType.Int16), nameof r.GetBoolean
"boolean", "bool", DbType.Boolean, Some (nameof MySqlDbType.Int16), nameof r.GetBoolean
"float4", "float", DbType.Single, Some (nameof MySqlDbType.Float), nameof r.GetFloat
"float8", "double", DbType.Double, Some (nameof MySqlDbType.Double), nameof r.GetDouble
"numeric", "decimal", DbType.Decimal, Some (nameof MySqlDbType.Decimal), nameof r.GetDecimal
"long", "string", DbType.String, Some (nameof MySqlDbType.MediumText), nameof r.GetString
]

let typeMappingsByName =
supportedTypeMappings

|> List.map (fun (columnTypeAlias, clrType, dbType, providerDbType, readerMethod) ->
columnTypeAlias,
{
TypeMapping.ColumnTypeAlias = columnTypeAlias
TypeMapping.ClrType = clrType
TypeMapping.DbType = dbType
TypeMapping.ProviderDbType = providerDbType
TypeMapping.ReaderMethod = readerMethod
}
)
|> Map.ofList

let tryFindTypeMapping (providerTypeName: string) =
typeMappingsByName.TryFind (providerTypeName.ToLower().Trim())

let primitiveTypeReaders =
supportedTypeMappings
|> List.map(fun (_, clrType, _, _, readerMethod) ->
{ PrimitiveTypeReader.ClrType = clrType; PrimitiveTypeReader.ReaderMethod = readerMethod }
)
|> List.distinctBy (fun ptr -> ptr.ClrType)
125 changes: 125 additions & 0 deletions src/SqlHydra.Cli/MySql/MySqlSchemaProvider.fs
Original file line number Diff line number Diff line change
@@ -0,0 +1,125 @@
module SqlHydra.MySql.MySqlSchemaProvider

open System.Data
open MySql.Data
open SqlHydra.Domain
open SqlHydra

let getSchema (cfg: Config) : Schema =
use conn = new MySqlClient.MySqlConnection(cfg.ConnectionString)
conn.Open()

let sTables = conn.GetSchema("Tables", cfg.Filters.TryGetRestrictionsByKey("Tables"))
let sColumns = conn.GetSchema("Columns", cfg.Filters.TryGetRestrictionsByKey("Columns"))

let pks =
let sql =
"""
SELECT
tc.table_schema,
tc.constraint_name,
tc.table_name,
kcu.column_name
FROM
information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu
ON tc.constraint_name = kcu.constraint_name
AND tc.table_schema = kcu.table_schema
WHERE
tc.constraint_type = 'PRIMARY KEY';
"""

use cmd = new MySqlClient.MySqlCommand(sql, conn)
use rdr = cmd.ExecuteReader()
[
while rdr.Read() do
rdr.["TABLE_SCHEMA"] :?> string,
rdr.["TABLE_NAME"] :?> string,
rdr.["COLUMN_NAME"] :?> string
]
|> Set.ofList

let allColumns =
sColumns.Rows
|> Seq.cast<DataRow>
|> Seq.map (fun col ->
{|
TableCatalog = col["TABLE_CATALOG"] :?> string
TableSchema = col["TABLE_SCHEMA"] :?> string
TableName = col["TABLE_NAME"] :?> string
ColumnName = col["COLUMN_NAME"] :?> string
ProviderTypeName = col["DATA_TYPE"] :?> string
OrdinalPosition = col["ORDINAL_POSITION"] :?> uint64
IsNullable =
match col["IS_NULLABLE"] :?> string with
| "YES" -> true
| _ -> false
IsPK =
match col["COLUMN_KEY"] :?> string with
| "PRI" -> true
| _ -> false
|}
)
|> Seq.sortBy (fun column -> column.OrdinalPosition)

let tables =
sTables.Rows
|> Seq.cast<DataRow>
|> Seq.map (fun tbl ->
{|
Catalog = tbl["TABLE_CATALOG"] :?> string
Schema = tbl["TABLE_SCHEMA"] :?> string
Name = tbl["TABLE_NAME"] :?> string
Type = tbl["TABLE_TYPE"] :?> string
|}
)
|> Seq.filter (fun tbl -> tbl.Type <> "SYSTEM_TABLE")
|> SchemaFilters.filterTables cfg.Filters
|> Seq.choose (fun tbl ->
let tableColumns =
allColumns
|> Seq.filter (fun col ->
col.TableCatalog = tbl.Catalog &&
col.TableSchema = tbl.Schema &&
col.TableName = tbl.Name
)

let supportedColumns =
tableColumns
|> Seq.choose (fun col ->
MySqlDataTypes.tryFindTypeMapping(col.ProviderTypeName)
|> Option.map (fun typeMapping ->
{
Column.Name = col.ColumnName
Column.IsNullable = col.IsNullable
Column.TypeMapping = typeMapping
Column.IsPK = pks.Contains(col.TableSchema, col.TableName, col.ColumnName)
}
)
)
|> Seq.toList

let filteredColumns =
supportedColumns
|> SchemaFilters.filterColumns cfg.Filters tbl.Schema tbl.Name
|> Seq.toList

if filteredColumns |> Seq.isEmpty then
None
else
Some {
Table.Catalog = tbl.Catalog
Table.Schema = tbl.Schema
Table.Name = tbl.Name
Table.Type = if tbl.Type = "table" then TableType.Table else TableType.View
Table.Columns = filteredColumns
Table.TotalColumns = tableColumns |> Seq.length
}
)
|> Seq.toList

{
Tables = tables
Enums = []
PrimitiveTypeReaders = MySqlDataTypes.primitiveTypeReaders
}
13 changes: 7 additions & 6 deletions src/SqlHydra.Cli/Program.fs
Original file line number Diff line number Diff line change
Expand Up @@ -3,23 +3,24 @@
open System
open FSharp.SystemCommandLine

let handler (provider: string, tomlFile: IO.FileInfo option, project: IO.FileInfo option, connString: string option) =
let handler (provider: string, tomlFile: IO.FileInfo option, project: IO.FileInfo option, connString: string option) =

let info, getSchema =
let info, getSchema =
match provider with
| "mssql" -> SqlServer.AppInfo.info, SqlServer.SqlServerSchemaProvider.getSchema
| "npgsql" -> Npgsql.AppInfo.info, Npgsql.NpgsqlSchemaProvider.getSchema
| "sqlite" -> Sqlite.AppInfo.info, Sqlite.SqliteSchemaProvider.getSchema
| "mysql" -> MySql.AppInfo.info, MySql.MySqlSchemaProvider.getSchema
| "oracle" -> Oracle.AppInfo.info, Oracle.OracleSchemaProvider.getSchema
| _ -> failwith "Unsupported db provider. Valid options are: 'mssql', 'npgsql', 'sqlite', or 'oracle'."
| _ -> failwith "Unsupported db provider. Valid options are: 'mssql', 'npgsql', 'sqlite', 'mysql', or 'oracle'."

let projectOrFirstFound =
let projectOrFirstFound =
project
|> Option.map (fun p -> if p.Exists then p else failwith $"Unable to find the specified project file: '{p.FullName}'.")
|> Option.orElse (IO.DirectoryInfo(".").EnumerateFiles("*.fsproj") |> Seq.tryHead)
|> Option.defaultWith (fun () -> failwith "Unable to find a .fsproj file in the run directory. Please specify one using the `--project` option.")

let args : Console.Args =
let args : Console.Args =
{
Provider = provider
AppInfo = info
Expand All @@ -37,7 +38,7 @@ let main argv =
rootCommand argv {
description "SqlHydra"
inputs (
Input.Argument<string>("provider", "The database provider name: 'mssql', 'npgsql', 'sqlite', or 'oracle'"),
Input.Argument<string>("provider", "The database provider name: 'mssql', 'npgsql', 'sqlite', 'mysql', or 'oracle'"),
Input.OptionMaybe<IO.FileInfo>(["-t"; "--toml-file"], "The toml configuration filename. Default: 'sqlhydra-{provider}.toml'"),
Input.OptionMaybe<IO.FileInfo>(["-p"; "--project"], "The project file to update. If not configured, the first .fsproj found in the run directory will be used."),
Input.OptionMaybe<string>(["-cs"; "--connection-string"], "The DB connection string to use. This will override the connection string in the toml file.")
Expand Down
Loading

0 comments on commit a6e9cd7

Please sign in to comment.