WIP on InArray comparison

This commit is contained in:
Daniel J. Summers 2024-09-15 23:09:20 -04:00
parent 566e5ce74d
commit 0aa91b8a00
5 changed files with 97 additions and 70 deletions

View File

@ -5,23 +5,23 @@ open System.Security.Cryptography
/// The types of comparisons available for JSON fields
type Comparison =
/// Equals (=)
| Equal of obj
| Equal of Value: obj
/// Greater Than (>)
| Greater of obj
| Greater of Value: obj
/// Greater Than or Equal To (>=)
| GreaterOrEqual of obj
| GreaterOrEqual of Value: obj
/// Less Than (<)
| Less of obj
| Less of Value: obj
/// Less Than or Equal To (<=)
| LessOrEqual of obj
| LessOrEqual of Value: obj
/// Not Equal to (<>)
| NotEqual of obj
| NotEqual of Value: obj
/// Between (BETWEEN)
| Between of obj * obj
| Between of Min: obj * Max: obj
/// In (IN)
| In of obj seq
// Array Contains (PostgreSQL: |? SQLite: EXISTS / json_each / IN)
| Contains of obj
| In of Values: obj seq
/// In Array (PostgreSQL: |?, SQLite: EXISTS / json_each / IN)
| InArray of Table: string * Values: obj seq
/// Exists (IS NOT NULL)
| Exists
/// Does Not Exist (IS NULL)
@ -38,7 +38,7 @@ type Comparison =
| NotEqual _ -> "<>"
| Between _ -> "BETWEEN"
| In _ -> "IN"
| Contains _ -> "|?" // PostgreSQL only; SQL needs a subquery for this
| InArray _ -> "|?" // PostgreSQL only; SQL needs a subquery for this
| Exists -> "IS NOT NULL"
| NotExists -> "IS NULL"
@ -49,6 +49,16 @@ type Dialect =
| PostgreSQL
| SQLite
/// The format in which an element of a JSON field should be extracted
[<Struct>]
type FieldFormat =
/// Use ->> or #>>; extracts a text (PostgreSQL) or SQL (SQLite) value
| AsSql
/// Use -> or #>; extracts a JSONB (PostgreSQL) or JSON (SQLite) value
| AsJson
/// Criteria for a field WHERE clause
type Field =
{ /// The name of the field
@ -139,13 +149,20 @@ with
static member NEX name = Field.NotExists name
/// Transform a field name (a.b.c) to a path for the given SQL dialect
static member NameToPath (name: string) dialect =
static member NameToPath (name: string) dialect format =
let path =
if name.Contains '.' then
match dialect with
| PostgreSQL -> "#>>'{" + String.concat "," (name.Split '.') + "}'"
| SQLite -> "->>'" + String.concat "'->>'" (name.Split '.') + "'"
else $"->>'{name}'"
| PostgreSQL ->
(match format with AsJson -> "#>" | AsSql -> "#>>")
+ "'{" + String.concat "," (name.Split '.') + "}'"
| SQLite ->
let parts = name.Split '.'
let last = Array.last parts
let final = (match format with AsJson -> "'->'" | AsSql -> "'->>'") + $"{last}'"
"->'" + String.concat "'->'" (Array.truncate (Array.length parts - 1) parts) + final
else
match format with AsJson -> $"->'{name}'" | AsSql -> $"->>'{name}'"
$"data{path}"
/// Create a field with a given name, but no other properties filled (op will be EQ, value will be "")
@ -161,8 +178,9 @@ with
{ this with Qualifier = Some alias }
/// Get the qualified path to the field
member this.Path dialect =
(this.Qualifier |> Option.map (fun q -> $"{q}.") |> Option.defaultValue "") + Field.NameToPath this.Name dialect
member this.Path dialect format =
(this.Qualifier |> Option.map (fun q -> $"{q}.") |> Option.defaultValue "")
+ Field.NameToPath this.Name dialect format
/// How fields should be matched
@ -378,7 +396,7 @@ module Query =
let parts = it.Split ' '
let fieldName = if Array.length parts = 1 then it else parts[0]
let direction = if Array.length parts < 2 then "" else $" {parts[1]}"
$"({Field.NameToPath fieldName dialect}){direction}")
$"({Field.NameToPath fieldName dialect AsSql}){direction}")
|> String.concat ", "
$"CREATE INDEX IF NOT EXISTS idx_{tbl}_%s{indexName} ON {tableName} ({jsonFields})"
@ -444,11 +462,13 @@ module Query =
|> Seq.map (fun (field, direction) ->
if field.Name.StartsWith "n:" then
let f = { field with Name = field.Name[2..] }
match dialect with PostgreSQL -> $"({f.Path PostgreSQL})::numeric" | SQLite -> f.Path SQLite
match dialect with
| PostgreSQL -> $"({f.Path PostgreSQL AsSql})::numeric"
| SQLite -> f.Path SQLite AsSql
elif field.Name.StartsWith "i:" then
let p = { field with Name = field.Name[2..] }.Path dialect
let p = { field with Name = field.Name[2..] }.Path dialect AsSql
match dialect with PostgreSQL -> $"LOWER({p})" | SQLite -> $"{p} COLLATE NOCASE"
else field.Path dialect
else field.Path dialect AsSql
|> function path -> path + defaultArg direction "")
|> String.concat ", "
|> function it -> $" ORDER BY {it}"

View File

@ -100,7 +100,9 @@ module Parameters =
|> Seq.mapi (fun idx v ->
let paramName = $"{p}_{idx}"
paramName, Sql.parameter (NpgsqlParameter(paramName, v)))
| Contains _ -> () // TODO
| InArray (_, values) ->
let p = name.Derive it.ParameterName
yield (p, Sql.stringArray (values |> Seq.map string |> Array.ofSeq))
| Equal v | Greater v | GreaterOrEqual v | Less v | LessOrEqual v | NotEqual v ->
let p = name.Derive it.ParameterName
yield (p, parameterFor v (fun l -> Sql.parameter (NpgsqlParameter(p, l)))) })
@ -137,7 +139,8 @@ module Query =
fields
|> Seq.map (fun it ->
match it.Comparison with
| Exists | NotExists -> $"{it.Path PostgreSQL} {it.Comparison.OpSql}"
| Exists | NotExists -> $"{it.Path PostgreSQL AsSql} {it.Comparison.OpSql}"
| InArray _ -> $"{it.Path PostgreSQL AsJson} {it.Comparison.OpSql} {name.Derive it.ParameterName}"
| _ ->
let p = name.Derive it.ParameterName
let param, value =
@ -146,12 +149,11 @@ module Query =
| In values ->
let paramNames = values |> Seq.mapi (fun idx _ -> $"{p}_{idx}") |> String.concat ", "
$"({paramNames})", defaultArg (Seq.tryHead values) (obj ())
| Contains _ -> p, "" // TODO: may need to use -> vs ->> in field SQL
| Equal v | Greater v | GreaterOrEqual v | Less v | LessOrEqual v | NotEqual v -> p, v
| _ -> p, ""
if isNumeric value then
$"({it.Path PostgreSQL})::numeric {it.Comparison.OpSql} {param}"
else $"{it.Path PostgreSQL} {it.Comparison.OpSql} {param}")
$"({it.Path PostgreSQL AsSql})::numeric {it.Comparison.OpSql} {param}"
else $"{it.Path PostgreSQL AsSql} {it.Comparison.OpSql} {param}")
|> String.concat $" {howMatched} "
/// Create a WHERE clause fragment to implement an ID-based query

View File

@ -38,16 +38,19 @@ module Query =
fields
|> Seq.map (fun it ->
match it.Comparison with
| Exists | NotExists -> $"{it.Path SQLite} {it.Comparison.OpSql}"
| Exists | NotExists -> $"{it.Path SQLite AsSql} {it.Comparison.OpSql}"
| Between _ ->
let p = name.Derive it.ParameterName
$"{it.Path SQLite} {it.Comparison.OpSql} {p}min AND {p}max"
$"{it.Path SQLite AsSql} {it.Comparison.OpSql} {p}min AND {p}max"
| In values ->
let p = name.Derive it.ParameterName
let paramNames = values |> Seq.mapi (fun idx _ -> $"{p}_{idx}") |> String.concat ", "
$"{it.Path SQLite} {it.Comparison.OpSql} ({paramNames})"
| Contains _ -> "" // TODO
| _ -> $"{it.Path SQLite} {it.Comparison.OpSql} {name.Derive it.ParameterName}")
$"{it.Path SQLite AsSql} {it.Comparison.OpSql} ({paramNames})"
| InArray (table, values) ->
let p = name.Derive it.ParameterName
let paramNames = values |> Seq.mapi (fun idx _ -> $"{p}_{idx}") |> String.concat ", "
$"EXISTS (SELECT 1 FROM json_each({table}.data, '$.{it.Name}') WHERE value IN ({paramNames}))"
| _ -> $"{it.Path SQLite AsSql} {it.Comparison.OpSql} {name.Derive it.ParameterName}")
|> String.concat $" {howMatched} "
/// Create a WHERE clause fragment to implement an ID-based query
@ -113,10 +116,9 @@ module Parameters =
| Between (min, max) ->
let p = name.Derive it.ParameterName
yield! [ SqliteParameter($"{p}min", min); SqliteParameter($"{p}max", max) ]
| In values ->
| In values | InArray (_, values) ->
let p = name.Derive it.ParameterName
yield! values |> Seq.mapi (fun idx v -> SqliteParameter($"{p}_{idx}", v))
| Contains _ -> () // TODO
| Equal v | Greater v | GreaterOrEqual v | Less v | LessOrEqual v | NotEqual v ->
yield SqliteParameter(name.Derive it.ParameterName, v) })
|> Seq.collect id

View File

@ -57,9 +57,9 @@ public static class CommonCSharpTests
{
Expect.equal(Comparison.NewIn([]).OpSql, "IN", "The In SQL was not correct");
}),
TestCase("Contains succeeds", () =>
TestCase("InArray succeeds", () =>
{
Expect.equal(Comparison.NewContains("").OpSql, "|?", "The Contains SQL was not correct");
Expect.equal(Comparison.NewInArray("", []).OpSql, "|?", "The InArray SQL was not correct");
}),
TestCase("Exists succeeds", () =>
{
@ -123,7 +123,7 @@ public static class CommonCSharpTests
var field = Field.In("Here", [8, 16, 32]);
Expect.equal(field.Name, "Here", "Field name incorrect");
Expect.isTrue(field.Comparison.IsIn, "Comparison incorrect");
Expect.sequenceEqual(((Comparison.In)field.Comparison).Item, [8, 16, 32], "Value incorrect");
Expect.sequenceEqual(((Comparison.In)field.Comparison).Values, [8, 16, 32], "Value incorrect");
}),
TestCase("Exists succeeds", () =>
{
@ -141,24 +141,24 @@ public static class CommonCSharpTests
[
TestCase("succeeds for PostgreSQL and a simple name", () =>
{
Expect.equal("data->>'Simple'", Field.NameToPath("Simple", Dialect.PostgreSQL),
Expect.equal("data->>'Simple'", Field.NameToPath("Simple", Dialect.PostgreSQL, FieldFormat.AsSql),
"Path not constructed correctly");
}),
TestCase("succeeds for SQLite and a simple name", () =>
{
Expect.equal("data->>'Simple'", Field.NameToPath("Simple", Dialect.SQLite),
Expect.equal("data->>'Simple'", Field.NameToPath("Simple", Dialect.SQLite, FieldFormat.AsSql),
"Path not constructed correctly");
}),
TestCase("succeeds for PostgreSQL and a nested name", () =>
{
Expect.equal("data#>>'{A,Long,Path,to,the,Property}'",
Field.NameToPath("A.Long.Path.to.the.Property", Dialect.PostgreSQL),
Field.NameToPath("A.Long.Path.to.the.Property", Dialect.PostgreSQL, FieldFormat.AsSql),
"Path not constructed correctly");
}),
TestCase("succeeds for SQLite and a nested name", () =>
{
Expect.equal("data->>'A'->>'Long'->>'Path'->>'to'->>'the'->>'Property'",
Field.NameToPath("A.Long.Path.to.the.Property", Dialect.SQLite),
Expect.equal("data->'A'->'Long'->'Path'->'to'->'the'->>'Property'",
Field.NameToPath("A.Long.Path.to.the.Property", Dialect.SQLite, FieldFormat.AsSql),
"Path not constructed correctly");
})
]),
@ -179,47 +179,50 @@ public static class CommonCSharpTests
TestCase("succeeds for a PostgreSQL single field with no qualifier", () =>
{
var field = Field.GreaterOrEqual("SomethingCool", 18);
Expect.equal("data->>'SomethingCool'", field.Path(Dialect.PostgreSQL),
Expect.equal("data->>'SomethingCool'", field.Path(Dialect.PostgreSQL, FieldFormat.AsSql),
"The PostgreSQL path is incorrect");
}),
TestCase("succeeds for a PostgreSQL single field with a qualifier", () =>
{
var field = Field.Less("SomethingElse", 9).WithQualifier("this");
Expect.equal("this.data->>'SomethingElse'", field.Path(Dialect.PostgreSQL),
Expect.equal("this.data->>'SomethingElse'", field.Path(Dialect.PostgreSQL, FieldFormat.AsSql),
"The PostgreSQL path is incorrect");
}),
TestCase("succeeds for a PostgreSQL nested field with no qualifier", () =>
{
var field = Field.Equal("My.Nested.Field", "howdy");
Expect.equal("data#>>'{My,Nested,Field}'", field.Path(Dialect.PostgreSQL),
Expect.equal("data#>>'{My,Nested,Field}'", field.Path(Dialect.PostgreSQL, FieldFormat.AsSql),
"The PostgreSQL path is incorrect");
}),
TestCase("succeeds for a PostgreSQL nested field with a qualifier", () =>
{
var field = Field.Equal("Nest.Away", "doc").WithQualifier("bird");
Expect.equal("bird.data#>>'{Nest,Away}'", field.Path(Dialect.PostgreSQL),
Expect.equal("bird.data#>>'{Nest,Away}'", field.Path(Dialect.PostgreSQL, FieldFormat.AsSql),
"The PostgreSQL path is incorrect");
}),
TestCase("succeeds for a SQLite single field with no qualifier", () =>
{
var field = Field.GreaterOrEqual("SomethingCool", 18);
Expect.equal("data->>'SomethingCool'", field.Path(Dialect.SQLite), "The SQLite path is incorrect");
Expect.equal("data->>'SomethingCool'", field.Path(Dialect.SQLite, FieldFormat.AsSql),
"The SQLite path is incorrect");
}),
TestCase("succeeds for a SQLite single field with a qualifier", () =>
{
var field = Field.Less("SomethingElse", 9).WithQualifier("this");
Expect.equal("this.data->>'SomethingElse'", field.Path(Dialect.SQLite), "The SQLite path is incorrect");
Expect.equal("this.data->>'SomethingElse'", field.Path(Dialect.SQLite, FieldFormat.AsSql),
"The SQLite path is incorrect");
}),
TestCase("succeeds for a SQLite nested field with no qualifier", () =>
{
var field = Field.Equal("My.Nested.Field", "howdy");
Expect.equal("data->>'My'->>'Nested'->>'Field'", field.Path(Dialect.SQLite),
Expect.equal("data->'My'->'Nested'->>'Field'", field.Path(Dialect.SQLite, FieldFormat.AsSql),
"The SQLite path is incorrect");
}),
TestCase("succeeds for a SQLite nested field with a qualifier", () =>
{
var field = Field.Equal("Nest.Away", "doc").WithQualifier("bird");
Expect.equal("bird.data->>'Nest'->>'Away'", field.Path(Dialect.SQLite), "The SQLite path is incorrect");
Expect.equal("bird.data->'Nest'->>'Away'", field.Path(Dialect.SQLite, FieldFormat.AsSql),
"The SQLite path is incorrect");
})
])
]);
@ -536,7 +539,7 @@ public static class CommonCSharpTests
{
Expect.equal(
Query.Definition.EnsureIndexOn("tbl", "nest", ["a.b.c"], Dialect.SQLite),
"CREATE INDEX IF NOT EXISTS idx_tbl_nest ON tbl ((data->>'a'->>'b'->>'c'))",
"CREATE INDEX IF NOT EXISTS idx_tbl_nest ON tbl ((data->'a'->'b'->>'c'))",
"CREATE INDEX for nested SQLite field incorrect");
})
])
@ -608,7 +611,7 @@ public static class CommonCSharpTests
Field.Named("Nested.Test.Field DESC"), Field.Named("AnotherField"),
Field.Named("It DESC")
], Dialect.SQLite),
" ORDER BY data->>'Nested'->>'Test'->>'Field' DESC, data->>'AnotherField', data->>'It' DESC",
" ORDER BY data->'Nested'->'Test'->>'Field' DESC, data->>'AnotherField', data->>'It' DESC",
"Order By not constructed correctly");
}),
TestCase("succeeds for PostgreSQL numeric fields", () =>
@ -630,7 +633,7 @@ public static class CommonCSharpTests
TestCase("succeeds for SQLite case-insensitive ordering", () =>
{
Expect.equal(Query.OrderBy([Field.Named("i:Test.Field ASC NULLS LAST")], Dialect.SQLite),
" ORDER BY data->>'Test'->>'Field' COLLATE NOCASE ASC NULLS LAST",
" ORDER BY data->'Test'->>'Field' COLLATE NOCASE ASC NULLS LAST",
"Order By not constructed correctly for case-insensitive field");
})
])

View File

@ -32,8 +32,8 @@ let comparisonTests = testList "Comparison.OpSql" [
test "In succeeds" {
Expect.equal (In []).OpSql "IN" "The In SQL was not correct"
}
test "Contains succeeds" {
Expect.equal (Contains "").OpSql "|?" "The Contains SQL was not correct"
test "InArray succeeds" {
Expect.equal (InArray("", [])).OpSql "|?" "The InArray SQL was not correct"
}
test "Exists succeeds" {
Expect.equal Exists.OpSql "IS NOT NULL" "The Exists SQL was not correct"
@ -117,21 +117,21 @@ let fieldTests = testList "Field" [
}
testList "NameToPath" [
test "succeeds for PostgreSQL and a simple name" {
Expect.equal "data->>'Simple'" (Field.NameToPath "Simple" PostgreSQL) "Path not constructed correctly"
Expect.equal "data->>'Simple'" (Field.NameToPath "Simple" PostgreSQL AsSql) "Path not constructed correctly"
}
test "succeeds for SQLite and a simple name" {
Expect.equal "data->>'Simple'" (Field.NameToPath "Simple" SQLite) "Path not constructed correctly"
Expect.equal "data->>'Simple'" (Field.NameToPath "Simple" SQLite AsSql) "Path not constructed correctly"
}
test "succeeds for PostgreSQL and a nested name" {
Expect.equal
"data#>>'{A,Long,Path,to,the,Property}'"
(Field.NameToPath "A.Long.Path.to.the.Property" PostgreSQL)
(Field.NameToPath "A.Long.Path.to.the.Property" PostgreSQL AsSql)
"Path not constructed correctly"
}
test "succeeds for SQLite and a nested name" {
Expect.equal
"data->>'A'->>'Long'->>'Path'->>'to'->>'the'->>'Property'"
(Field.NameToPath "A.Long.Path.to.the.Property" SQLite)
"data->'A'->'Long'->'Path'->'to'->'the'->>'Property'"
(Field.NameToPath "A.Long.Path.to.the.Property" SQLite AsSql)
"Path not constructed correctly"
}
]
@ -148,35 +148,35 @@ let fieldTests = testList "Field" [
testList "Path" [
test "succeeds for a PostgreSQL single field with no qualifier" {
let field = Field.GreaterOrEqual "SomethingCool" 18
Expect.equal "data->>'SomethingCool'" (field.Path PostgreSQL) "The PostgreSQL path is incorrect"
Expect.equal "data->>'SomethingCool'" (field.Path PostgreSQL AsSql) "The PostgreSQL path is incorrect"
}
test "succeeds for a PostgreSQL single field with a qualifier" {
let field = { Field.Less "SomethingElse" 9 with Qualifier = Some "this" }
Expect.equal "this.data->>'SomethingElse'" (field.Path PostgreSQL) "The PostgreSQL path is incorrect"
Expect.equal "this.data->>'SomethingElse'" (field.Path PostgreSQL AsSql) "The PostgreSQL path is incorrect"
}
test "succeeds for a PostgreSQL nested field with no qualifier" {
let field = Field.Equal "My.Nested.Field" "howdy"
Expect.equal "data#>>'{My,Nested,Field}'" (field.Path PostgreSQL) "The PostgreSQL path is incorrect"
Expect.equal "data#>>'{My,Nested,Field}'" (field.Path PostgreSQL AsSql) "The PostgreSQL path is incorrect"
}
test "succeeds for a PostgreSQL nested field with a qualifier" {
let field = { Field.Equal "Nest.Away" "doc" with Qualifier = Some "bird" }
Expect.equal "bird.data#>>'{Nest,Away}'" (field.Path PostgreSQL) "The PostgreSQL path is incorrect"
Expect.equal "bird.data#>>'{Nest,Away}'" (field.Path PostgreSQL AsSql) "The PostgreSQL path is incorrect"
}
test "succeeds for a SQLite single field with no qualifier" {
let field = Field.GreaterOrEqual "SomethingCool" 18
Expect.equal "data->>'SomethingCool'" (field.Path SQLite) "The SQLite path is incorrect"
Expect.equal "data->>'SomethingCool'" (field.Path SQLite AsSql) "The SQLite path is incorrect"
}
test "succeeds for a SQLite single field with a qualifier" {
let field = { Field.Less "SomethingElse" 9 with Qualifier = Some "this" }
Expect.equal "this.data->>'SomethingElse'" (field.Path SQLite) "The SQLite path is incorrect"
Expect.equal "this.data->>'SomethingElse'" (field.Path SQLite AsSql) "The SQLite path is incorrect"
}
test "succeeds for a SQLite nested field with no qualifier" {
let field = Field.Equal "My.Nested.Field" "howdy"
Expect.equal "data->>'My'->>'Nested'->>'Field'" (field.Path SQLite) "The SQLite path is incorrect"
Expect.equal "data->'My'->'Nested'->>'Field'" (field.Path SQLite AsSql) "The SQLite path is incorrect"
}
test "succeeds for a SQLite nested field with a qualifier" {
let field = { Field.Equal "Nest.Away" "doc" with Qualifier = Some "bird" }
Expect.equal "bird.data->>'Nest'->>'Away'" (field.Path SQLite) "The SQLite path is incorrect"
Expect.equal "bird.data->'Nest'->>'Away'" (field.Path SQLite AsSql) "The SQLite path is incorrect"
}
]
]
@ -379,7 +379,7 @@ let queryTests = testList "Query" [
test "succeeds for nested SQLite field" {
Expect.equal
(Query.Definition.ensureIndexOn tbl "nest" [ "a.b.c" ] SQLite)
$"CREATE INDEX IF NOT EXISTS idx_{tbl}_nest ON {tbl} ((data->>'a'->>'b'->>'c'))"
$"CREATE INDEX IF NOT EXISTS idx_{tbl}_nest ON {tbl} ((data->'a'->'b'->>'c'))"
"CREATE INDEX for nested SQLite field incorrect"
}
]
@ -441,7 +441,7 @@ let queryTests = testList "Query" [
(Query.orderBy
[ Field.Named "Nested.Test.Field DESC"; Field.Named "AnotherField"; Field.Named "It DESC" ]
SQLite)
" ORDER BY data->>'Nested'->>'Test'->>'Field' DESC, data->>'AnotherField', data->>'It' DESC"
" ORDER BY data->'Nested'->'Test'->>'Field' DESC, data->>'AnotherField', data->>'It' DESC"
"Order By not constructed correctly"
}
test "succeeds for PostgreSQL numeric fields" {
@ -465,7 +465,7 @@ let queryTests = testList "Query" [
test "succeeds for SQLite case-insensitive ordering" {
Expect.equal
(Query.orderBy [ Field.Named "i:Test.Field ASC NULLS LAST" ] SQLite)
" ORDER BY data->>'Test'->>'Field' COLLATE NOCASE ASC NULLS LAST"
" ORDER BY data->'Test'->>'Field' COLLATE NOCASE ASC NULLS LAST"
"Order By not constructed correctly for case-insensitive field"
}
]