Skip to content

Commit dc29ec0

Browse files
authored
Merge pull request #52 from MozgC/master
Added 2 articles
2 parents ef2d7ed + d85c4b8 commit dc29ec0

File tree

2 files changed

+483
-0
lines changed

2 files changed

+483
-0
lines changed
Lines changed: 313 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,313 @@
1+
# How to teach LINQ to DB to convert custom .NET methods and objects to SQL
2+
You may run into a situation where LINQ to DB does not know how to convert some .NET method, property or object to SQL. But that is not a problem because LINQ to DB likes to learn. Just teach it :). In one of our previous blog posts we wrote about [Using this MapValueAttribute to control mapping with linq2db](xref:using-mapvalue-attribute-to-control-mapping.md). In this article we will go a little bit deeper.
3+
4+
There are multiple ways to teach LINQ to DB how to convert custom properties and methods into SQL, but the primary ones are:
5+
6+
<ul>
7+
<li>
8+
9+
[LinqToDB.Sql.ExpressionAttribute](#sqlexpression) and [LinqToDB.Sql.FunctionAttribute](#sqlfunction-attribute)</li>
10+
11+
<li>
12+
13+
[LinqToDB.ExpressionMethodAttribute](#expressionmethod)
14+
</li>
15+
<li>
16+
17+
[LinqToDB.Linq.Expressions.MapMember()](#mapmember) method
18+
<li>
19+
20+
[LinqToDB.Mapping.MappingSchema.SetValueToSqlConverter()](#setvaluetosqlconverter) method
21+
</ol>
22+
23+
Let's see how to use each of these methods.
24+
25+
### Sql.Expression
26+
Let's say you love SQL's BETWEEN operator and you find out that LINQ to DB does not have `Between()` method out of the box, so you have to write something like this:
27+
28+
```cs
29+
var query = db.Customers.Where(c => c.ID >= 1000 && c.ID <= 2000);
30+
```
31+
32+
Here is how the `Sql.Expression` attribute can help us bring Between to .NET:
33+
34+
```cs
35+
[Sql.Expression("{0} BETWEEN {1} AND {2}", PreferServerSide = true)]
36+
public static bool Between<T>(this T x, T low, T high) where T : IComparable<T>
37+
{
38+
// x >= low && x <= high
39+
return x.CompareTo(low) >= 0 && x.CompareTo(high) <= 0;
40+
}
41+
```
42+
43+
Let's test it:
44+
45+
```cs
46+
[Test]
47+
public void SqlExpressionAttributeTest()
48+
{
49+
using (var db = new DataModel())
50+
{
51+
db.InlineParameters = true; // inlined parameters can be helpful when debugging
52+
db.Customers.Where(c => c.DateOfBirth.Between(new DateTime(2000, 1, 1), new DateTime(2000, 12, 31))).ToList();
53+
}
54+
}
55+
```
56+
57+
The SQL generated for SQL Server 2012 is:
58+
59+
```sql
60+
SELECT
61+
[t1].[ID],
62+
[t1].[DateOfBirth],
63+
[t1].[FirstName],
64+
[t1].[LastName],
65+
[t1].[Email]
66+
FROM
67+
[dbo].[Customer] [t1]
68+
WHERE
69+
[t1].[DateOfBirth] BETWEEN '2000-01-01' AND '2000-12-31'
70+
```
71+
72+
Notice the use of the `Sql.ExpressionAttribute.PreferServerSide` property set to true. `PreferServerSide = true` tells LINQ to DB to convert the method to SQL if possible, and if it's not possible for some reason - then to execute the method locally.
73+
74+
There is another similar property – `ServerSideOnly`. If it's set to True, LINQ to DB will throw an exception if it can't convert a method to SQL. It can be set to true when you can't, don't need or don't want to write a client-side implementation.
75+
76+
You may have a valid question: When can't LINQ to DB generate SQL? How is that possible if we show LINQ to DB what we want to generate? Here is a simple example:
77+
78+
```cs
79+
var q =
80+
from c in db.Customers
81+
select
82+
SomeServerSideOnlyMethod(SomeLocalApplicationMethod(c.ID));
83+
```
84+
85+
Let's say `SomeServerSideOnlyMethod()` is a method with the `Sql.Expression` attribute and `ServerSideOnly = true`, and `SomeLocalApplicationMethod()` is an ordinary .NET method that can only be executed locally.
86+
87+
Since `SomeLocalApplicationMethod()` must be executed locally, LINQ to DB has to first read the `Customer.ID` field values from the table to pass them to `SomeLocalApplicationMethod()` on the client side. From this moment the query, including the call to `SomeServerSideOnlyMethod()`, will have to be executed locally. But considering that `SomeServerSideOnlyMethod()` is marked as `ServerSideOnly = true`, LINQ to DB will throw an exception.
88+
89+
### Sql.Function attribute
90+
Presume that we are using SQL Server and we want to check if a string contains a representation of a numeric value. SQL Server has the `IsNumeric()` function, but LINQ to DB does not support it out of the box. It's easy to fix:
91+
92+
```cs
93+
[Sql.Function("IsNumeric", ServerSideOnly = true)]
94+
public static bool IsNumeric(string s)
95+
{
96+
throw new InvalidOperationException();
97+
}
98+
99+
[Test]
100+
public void SqlFunctionAttributeTest()
101+
{
102+
using (var db = new DataModel())
103+
{
104+
db.InlineParameters = true;
105+
db.Customers.Where(c => SqlFunctions.IsNumeric(c.LastName)).ToList();
106+
}
107+
}
108+
```
109+
110+
The generated SQL:
111+
112+
```sql
113+
SELECT
114+
[t1].[ID],
115+
[t1].[DateOfBirth],
116+
[t1].[FirstName],
117+
[t1].[LastName],
118+
[t1].[Email]
119+
FROM
120+
[dbo].[Customer] [t1]
121+
WHERE
122+
IsNumeric([t1].[LastName]) = 1
123+
```
124+
125+
Please note, that you may omit specifying the function name in the attribute explicitly - in this case the method name (that the attribute is applied to) will be used as a function name.
126+
127+
### ExpressionMethod
128+
Let us now examine the next attribute - `LinqToDB.ExpressionMethodAttribute`, a very powerful one. The `ExpressionMethodAttribute` allows specifying an expression that LINQ to DB will translate into SQL.
129+
130+
For those of us who are fans of the SQL's `IN` operator, let's show how we can make LINQ to DB support it:
131+
132+
```cs
133+
[ExpressionMethod("InImpl")]
134+
public static bool In<T>(this T item, IEnumerable<T> items)
135+
{
136+
return items.Contains(item); // this code will run if we execute the method locally
137+
}
138+
139+
public static Expression<Func<T, IEnumerable<T>, bool>> InImpl<T>()
140+
{
141+
// LINQ to DB will translate this expression into SQL
142+
// (it knows out of the box how to translate Contains()
143+
return (item, items) => items.Contains(item);
144+
}
145+
```
146+
147+
Here we are using the `ExpressionMethod` attribute to specify a method that will return an `Expression`, and LINQ to DB will convert that `Expression` into SQL (basically, LINQ to DB uses the expression tree returned by the method specified with the `ExpressionMethod` attribute to replace a part of a bigger expression tree that will later be converted to SQL). The generic type parameter of the `Expression` should be a `Func<T>` delegate, representing a function that takes the same parameters and returns the same type as a local method. For example, if a local method has this declaration:
148+
149+
```cs
150+
T1 MyMethod(T2, T3)
151+
```
152+
153+
Then the `ExpressionMethod` attribute should point to a method with the following declaration:
154+
155+
```cs
156+
Expression<Func<T2, T3, T1>> MyMethodImpl()
157+
```
158+
159+
The test:
160+
161+
```cs
162+
[Test]
163+
public void InTest()
164+
{
165+
using (var db = new DataModel())
166+
{
167+
var customers = db.Customers.Where(c => c.FirstName.In(new[] {"Pavel", "John", "Jack"})).ToList();
168+
}
169+
}
170+
```
171+
172+
This will generate the following SQL:
173+
174+
```sql
175+
SELECT
176+
[t1].[ID],
177+
[t1].[DateOfBirth],
178+
[t1].[FirstName],
179+
[t1].[LastName],
180+
[t1].[Email]
181+
FROM
182+
[dbo].[Customer] [t1]
183+
WHERE
184+
[t1].[FirstName] IN (N'Pavel', N'John', N'Jack')
185+
```
186+
187+
Another example, showing that `ExpressionMethod` can be applied to properties:
188+
189+
```cs
190+
public partial class Issue
191+
{
192+
[ExpressionMethod("GetAgeExpression")]
193+
public double AgeInDays
194+
{
195+
get { return (DateTime.Now - CreatedOn).TotalDays; }
196+
}
197+
198+
private static Expression<Func<Issue, double>> GetAgeExpression()
199+
{
200+
return issue => (Sql.CurrentTimestamp - issue.CreatedOn).TotalDays;
201+
}
202+
}
203+
```
204+
205+
Test:
206+
207+
```cs
208+
[Test]
209+
public void ExpressionMethodTest2()
210+
{
211+
using (var db = new DataModel())
212+
{
213+
var issues = db.Issues.Where(issue => issue.AgeInDays > 30).ToList();
214+
}
215+
}
216+
```
217+
218+
The generated SQL:
219+
220+
```sql
221+
SELECT
222+
[t1].[ID],
223+
[t1].[Subject],
224+
[t1].[Description],
225+
[t1].[Status],
226+
[t1].[CreatedOn]
227+
FROM
228+
[dbo].[Issue] [t1]
229+
WHERE
230+
DateDiff(Day, [t1].[CreatedOn], CURRENT_TIMESTAMP) > 30
231+
```
232+
233+
You can find more examples of ExpressionMethod usage (including a possible `LeftJoin()` implementation that may be of interest to you) here: [ExpressionTests.cs](https://github.com/linq2db/linq2db/blob/master/Tests/Linq/Linq/ExpressionsTests.cs)
234+
235+
### MapMember()
236+
The next method we will discuss is the `LinqToDB.Linq.Expressions.MapMember()` method (having numerous overloads). It allows you to specify how to convert existing methods and properties. Basically, you provide the original method or property and the corresponding `Expression` that will be used by LINQ to DB instead of the original method. Internally LINQ to DB uses `MapMember()` to map hundreds of standard .NET framework methods and properties.
237+
238+
For example, we would like to make LINQ to DB support the `String.IsNullOrWhitespace()` method and we can't add the `ExpressionMethod` attribute to `IsNullOrWhitespace()` because it's a framework's method and we can't change it.
239+
240+
The `MapMember()` method comes to the rescue!
241+
242+
```cs
243+
public partial class DataModel
244+
{
245+
static DataModel()
246+
{
247+
LinqToDB.Linq.Expressions.MapMember((string s) => string.IsNullOrWhiteSpace(s), s => s == null || s.TrimEnd() == string.Empty);
248+
}
249+
}
250+
251+
[Test]
252+
public void MapMemberTest()
253+
{
254+
using (var db = new DataModel())
255+
{
256+
var customers = db.Customers.Where(c => string.IsNullOrWhiteSpace(c.Email)).ToList();
257+
}
258+
}
259+
```
260+
261+
The generated SQL:
262+
263+
```sql
264+
SELECT
265+
[t1].[ID],
266+
[t1].[DateOfBirth],
267+
[t1].[FirstName],
268+
[t1].[LastName],
269+
[t1].[Email]
270+
FROM
271+
[dbo].[Customer] [t1]
272+
WHERE
273+
[t1].[Email] IS NULL OR RTrim([t1].[Email]) = N''
274+
```
275+
276+
### SetValueToSqlConverter()
277+
278+
The last method we will examine is `LinqToDB.Mapping.MappingSchema.SetValueToSqlConverter()`. It is used to control exactly how a value will be converted to SQL. The two primary use cases for this method are:
279+
280+
<ol>
281+
<li>
282+
283+
When adding support for a new database provider. For example, when working with the `Boolean` data type in Informix RDBMS, `t` represents the logical value TRUE and `f` represents FALSE. Here is how this is implemented in LinqToDB as a part of its Informix support:
284+
285+
```cs
286+
public class InformixMappingSchema : MappingSchema
287+
{
288+
protected InformixMappingSchema(string configuration) : base(configuration)
289+
{
290+
SetValueToSqlConverter(typeof(bool), (sb,dt,v) => sb.Append("'").Append((bool)v ? 't' : 'f').Append("'"));
291+
}
292+
}
293+
```
294+
</li>
295+
296+
<li>
297+
298+
When adding support for a new data type. For example, here is how to teach LINQ to DB to consider the `SqlDecimal.IsNull` property and correctly convert `SqlDecimal` objects to SQL:
299+
300+
```cs
301+
MappingSchema.Default.SetValueToSqlConverter(
302+
typeof(SqlDecimal),
303+
(sb, dt, v) =>
304+
{
305+
var value = (SqlDecimal)v;
306+
307+
if (value.IsNull)
308+
sb.Append("NULL");
309+
else
310+
sb.Append(v);
311+
});
312+
```
313+
</li>

0 commit comments

Comments
 (0)