Skip to content

Commit

Permalink
Change the way like expressions work
Browse files Browse the repository at this point in the history
- Add `LikeExpression` to `ISqlBuilder`
- Remove `lower()` from startswith/endswith/contains-expressions since that doesn't work well with indexed columns
- Use `ilike` for Postgres to make like queries case-insensitive
- Bump package version to 3.0 as it's a breaking change
  • Loading branch information
henkmollema committed Dec 21, 2021
1 parent fc56abd commit bf98b3b
Show file tree
Hide file tree
Showing 13 changed files with 45 additions and 20 deletions.
2 changes: 1 addition & 1 deletion Directory.Build.props
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
<Project>
<PropertyGroup>
<Copyright>Copyright © Henk Mollema 2014</Copyright>
<VersionPrefix>2.4.0</VersionPrefix>
<VersionPrefix>3.0.0</VersionPrefix>
<Authors>Henk Mollema</Authors>
<LangVersion>latest</LangVersion>
<Nullable>enable</Nullable>
Expand Down
10 changes: 9 additions & 1 deletion src/Dommel/ISqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -41,9 +41,17 @@ public interface ISqlBuilder
string QuoteIdentifier(string identifier);

/// <summary>
/// Adds a limit clause to query.
/// Returns a limit clause for the specified <paramref name="count"/>.
/// </summary>
/// <param name="count">The count of limit clause.</param>
/// <returns>A limit clause of the specified count.</returns>
string LimitClause(int count);

/// <summary>
/// Returns a like-expresion for the specified <paramref name="columnName"/> and <paramref name="parameterName"/>.
/// </summary>
/// <param name="columnName">The column name of the like-expression.</param>
/// <param name="parameterName">The parameter name of the like-expression.</param>
/// <returns>A like-expression.</returns>
string LikeExpression(string columnName, string parameterName);
}
3 changes: 3 additions & 0 deletions src/Dommel/MySqlSqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -26,4 +26,7 @@ public virtual string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"limit {count}";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} like {parameterName}";
}
3 changes: 3 additions & 0 deletions src/Dommel/PostgresSqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -42,4 +42,7 @@ public virtual string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"limit {count}";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} ilike {parameterName}";
}
3 changes: 1 addition & 2 deletions src/Dommel/SqlExpression.cs
Original file line number Diff line number Diff line change
Expand Up @@ -393,8 +393,7 @@ protected virtual object VisitContainsExpression(MethodCallExpression expression
};
AddParameter(textLike, out var paramName);

// Use lower() to make the queries case-insensitive
return $"lower({column}) like lower({paramName})";
return SqlBuilder.LikeExpression(column.ToString(), paramName);
}

/// <summary>
Expand Down
3 changes: 3 additions & 0 deletions src/Dommel/SqlServerCeSqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -26,4 +26,7 @@ public virtual string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"order by 1 offset 0 rows fetch next {count} rows only";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} like {parameterName}";
}
3 changes: 3 additions & 0 deletions src/Dommel/SqlServerSqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -26,4 +26,7 @@ public virtual string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"order by 1 offset 0 rows fetch next {count} rows only";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} like {parameterName}";
}
3 changes: 3 additions & 0 deletions src/Dommel/SqliteSqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -26,4 +26,7 @@ public virtual string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"limit {count}";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} like {parameterName}";
}
Original file line number Diff line number Diff line change
Expand Up @@ -12,10 +12,10 @@ public JsonDatabaseTestData()
// DatabaseFixture as well.
if (!CI.IsTravis)
{
//Add(new JsonSqlServerDatabaseDriver());
Add(new JsonSqlServerDatabaseDriver());
}

Add(new JsonMySqlDatabaseDriver());
//Add(new JsonPostgresDatabaseDriver());
Add(new JsonPostgresDatabaseDriver());
}
}
12 changes: 6 additions & 6 deletions test/Dommel.Json.Tests/LikeTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ public void LikeOperandContains_WithConstant()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -33,7 +33,7 @@ public void LikeOperand_WithVariable()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -49,7 +49,7 @@ public void LikeOperandStartsWith_WithConstant()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -66,7 +66,7 @@ public void LikeOperandStartsWith_WithVariable()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -82,7 +82,7 @@ public void LikeOperandEndsWith_WithConstant()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -99,7 +99,7 @@ public void LikeOperandEndsWith_WithVariable()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower(`Leads`.`Data`->'$.FirstName') like lower(@p1))", sql.Trim());
Assert.Equal("where (`Leads`.`Data`->'$.FirstName' like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test", dynamicParameters.Get<string>("p1"));
}
Expand Down
3 changes: 3 additions & 0 deletions test/Dommel.Tests/DummySqlBuilder.cs
Original file line number Diff line number Diff line change
Expand Up @@ -23,4 +23,7 @@ public string BuildPaging(string? orderBy, int pageNumber, int pageSize)

/// <inheritdoc/>
public string LimitClause(int count) => $"limit {count}";

/// <inheritdoc/>
public string LikeExpression(string columnName, string parameterName) => $"{columnName} like {parameterName}";
}
8 changes: 4 additions & 4 deletions test/Dommel.Tests/SqlExpressions/DynamicExpressionTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ public void CommonAndExpression()
var dommelExpression = _sqlExpression.Where(p => p.Id == 1 && p.Bar.Contains("test"));
var sql = dommelExpression.ToSql(out var dynamicParameters);

Assert.Equal("where ([tblFoo].[Id] = @p1 and lower([tblFoo].[Bar]) like lower(@p2))", sql.Trim());
Assert.Equal("where ([tblFoo].[Id] = @p1 and [tblFoo].[Bar] like @p2)", sql.Trim());
Assert.Equal(1, dynamicParameters.Get<int>("p1"));
Assert.Equal("%test%", dynamicParameters.Get<string>("p2"));
}
Expand All @@ -32,7 +32,7 @@ public void AndExpression()
var dommelExpression = _sqlExpression.Where(expression);
var sql = dommelExpression.ToSql(out var dynamicParameters);

Assert.Equal("where ([tblFoo].[Id] = @p1 and lower([tblFoo].[Bar]) like lower(@p2))", sql.Trim());
Assert.Equal("where ([tblFoo].[Id] = @p1 and [tblFoo].[Bar] like @p2)", sql.Trim());
Assert.Equal(1, dynamicParameters.Get<int>("p1"));
Assert.Equal("%test%", dynamicParameters.Get<string>("p2"));
}
Expand All @@ -43,7 +43,7 @@ public void CommonOrExpression()
var dommelExpression = _sqlExpression.Where(p => p.Id == 1 || p.Bar.Contains("testOr"));
var sql = dommelExpression.ToSql(out var dynamicParameters);

Assert.Equal("where ([tblFoo].[Id] = @p1 or lower([tblFoo].[Bar]) like lower(@p2))", sql.Trim());
Assert.Equal("where ([tblFoo].[Id] = @p1 or [tblFoo].[Bar] like @p2)", sql.Trim());
Assert.Equal(1, dynamicParameters.Get<int>("p1"));
Assert.Equal("%testOr%", dynamicParameters.Get<string>("p2"));
}
Expand Down Expand Up @@ -79,7 +79,7 @@ public void InExpression()
var dommelExpression = _sqlExpression.Where(expression);
var sql = dommelExpression.ToSql(out var dynamicParameters);

Assert.Equal("where ([tblFoo].[Id] in (@p1,@p2) or [tblFoo].[StringId] in (@p3,@p4) or [tblFoo].[DecimalId] in (@p5,@p6) or [tblFoo].[Guid] in (@p7,@p8) or lower([tblFoo].[Bar]) like lower(@p9))", sql.Trim());
Assert.Equal("where ([tblFoo].[Id] in (@p1,@p2) or [tblFoo].[StringId] in (@p3,@p4) or [tblFoo].[DecimalId] in (@p5,@p6) or [tblFoo].[Guid] in (@p7,@p8) or [tblFoo].[Bar] like @p9)", sql.Trim());
Assert.Equal(1, dynamicParameters.Get<int>("p1"));
Assert.Equal(2, dynamicParameters.Get<int>("p2"));
Assert.Equal("1", dynamicParameters.Get<string>("p3"));
Expand Down
8 changes: 4 additions & 4 deletions test/Dommel.Tests/SqlExpressions/LikeTests.cs
Original file line number Diff line number Diff line change
Expand Up @@ -16,7 +16,7 @@ public void LikeOperandContains()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower([tblFoo].[Bar]) like lower(@p1))", sql.Trim());
Assert.Equal("where ([tblFoo].[Bar] like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -33,7 +33,7 @@ public void LikeOperandContainsVariable()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower([tblFoo].[Bar]) like lower(@p1))", sql.Trim());
Assert.Equal("where ([tblFoo].[Bar] like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -49,7 +49,7 @@ public void LikeOperandStartsWith()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower([tblFoo].[Bar]) like lower(@p1))", sql.Trim());
Assert.Equal("where ([tblFoo].[Bar] like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("test%", dynamicParameters.Get<string>("p1"));
}
Expand All @@ -65,7 +65,7 @@ public void LikeOperandEndsWith()
var sql = expression.ToSql(out var dynamicParameters);

// Assert
Assert.Equal("where (lower([tblFoo].[Bar]) like lower(@p1))", sql.Trim());
Assert.Equal("where ([tblFoo].[Bar] like @p1)", sql.Trim());
Assert.Single(dynamicParameters.ParameterNames);
Assert.Equal("%test", dynamicParameters.Get<string>("p1"));
}
Expand Down

0 comments on commit bf98b3b

Please sign in to comment.