Skip to content

Commit 6543785

Browse files
Merge pull request #26 from garvincasimir/formatters
Adding custom formatters
2 parents b939bef + 688daa1 commit 6543785

File tree

8 files changed

+272
-23
lines changed

8 files changed

+272
-23
lines changed

README.md

+109-2
Original file line numberDiff line numberDiff line change
@@ -15,6 +15,8 @@ The parser aims to be Database and Provider agnostic. It currently targets Netst
1515
* Sql Server
1616
* PostgreSQL
1717

18+
If you intend to filter your dataset, the default configuration assumes your IQueryable uses a provider with support for .ToString() on DateTime and numeric types. Please note that EFCore will not fail but instead fall back to client evaluation if this requirement is not met. I have mixed feelings about this. I believe client evaluation should be opt-in and not opt-out.
19+
1820
jQuery Datatables
1921
========================
2022

@@ -114,7 +116,112 @@ The following snippets were taken from the aspnet-core-sample project also locat
114116

115117
The included Dockerfile-websample builds, packages and runs the web sample project in a docker image. No tools, frameworks or runtimes are required on the host machine. The image has been published to docker for your convenience.
116118

117-
docker run -p 80:80 garvincasimir/datatables-aspnet-core-sample:0.0.2
119+
docker run -p 80:80 garvincasimir/datatables-aspnet-core-sample:0.0.2
120+
121+
Custom Filter Expressions
122+
========================
123+
The parser builds a set of expressions based on the settings and filter text sent from Datatables. The end result is a *WHERE* clause which looks something like this:
124+
125+
```
126+
FROM [People] AS [val]
127+
WHERE ((((CASE
128+
WHEN CHARINDEX(N'cromie', LOWER([val].[FirstName])) > 0
129+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
130+
END | CASE
131+
WHEN CHARINDEX(N'cromie', LOWER([val].[LastName])) > 0
132+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
133+
END) | CASE
134+
WHEN CHARINDEX(N'cromie', LOWER(CONVERT(VARCHAR(100), [val].[BirthDate]))) > 0
135+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
136+
END) | CASE
137+
WHEN CHARINDEX(N'cromie', LOWER(CONVERT(VARCHAR(100), [val].[Weight]))) > 0
138+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
139+
END) | CASE
140+
WHEN CHARINDEX(N'cromie', LOWER(CONVERT(VARCHAR(11), [val].[Children]))) > 0
141+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
142+
END) = 1
143+
```
144+
145+
In the above example, each of the case statements will attempt to find the filter text 'cromie' within a string representation of the properties from *T*. The exact mechanics and syntax will vary by provider and db engine but this is an example of the actual query sent to your backend database.
146+
147+
The expression generated by the parser looks like this:
148+
149+
```
150+
where val.FirstName.ToLower().Contains("cromie") || val.LastName.ToLower().Contains("cromie") || val.BirthDate.ToString().ToLower().Contains("cromie") || val.Weight.ToString().ToLower().Contains("cromie") || val.Children.ToString().ToLower().Contains("cromie")
151+
```
152+
153+
What is missing in the above expression is the ability to format dates to match the client side. So it may seem strange to a user if they enter a date in the filter text box and no results are returned. It would be nice if providers just supported *DateTime.ToString(string format)* right? Even if they did, the format strings expected by db engines are not consistent at all. As a result, I decided to expose some of the internals of the parser and allow library users to substitute .ToString() with a custom expression.
154+
155+
For example, if your provider does support *DateTime.ToString(string format)*, you can substitute .ToString() with that expression after initializing the parser. This must be explicitly called for each applicable property.
156+
157+
```
158+
var parser = new Parser<Person>(p, context.People)
159+
.SetConverter(x => x.BirthDate, x => x.BirthDate.ToString("M/dd/yyyy"))
160+
.SetConverter(x => x.LastUpdated, x => x.LastUpdated.ToString("M/dd/yyyy"));
161+
```
162+
163+
**EF Core 2**
164+
165+
In EF Core 2 you can map user defined and system scalar valued functions and use them for formatting. The following is an example for SQL Server >= 2012.
166+
167+
PersonContext.cs
168+
```
169+
using Microsoft.EntityFrameworkCore;
170+
using System;
171+
172+
namespace DataTablesParser.Tests
173+
{
174+
public class PersonContext : DbContext
175+
{
176+
public PersonContext(){ }
177+
178+
public PersonContext(DbContextOptions<PersonContext> options)
179+
: base(options){ }
180+
181+
//Sql Server >= 2012
182+
//https://docs.microsoft.com/en-us/sql/t-sql/functions/format-transact-sql
183+
[DbFunction]
184+
public static string Format(DateTime data,string format)
185+
{
186+
throw new Exception();
187+
}
188+
189+
public DbSet<Person> People { get; set; }
190+
}
191+
}
192+
193+
```
194+
Parser initialization
195+
196+
```
197+
198+
var parser = new Parser<Person>(p, context.People)
199+
.SetConverter(x => x.BirthDate, x => PersonContext.Format(x.BirthDate,"M/dd/yyyy"));
200+
```
201+
202+
The *WHERE* clause now looks like this:
203+
204+
```
205+
WHERE ((((CASE
206+
WHEN CHARINDEX(N'9/03/1953', LOWER([val].[FirstName])) > 0
207+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
208+
END | CASE
209+
WHEN CHARINDEX(N'9/03/1953', LOWER([val].[LastName])) > 0
210+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
211+
END) | CASE
212+
WHEN CHARINDEX(N'9/03/1953', LOWER(Format([val].[BirthDate], N'M/dd/yyyy'))) > 0
213+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
214+
END) | CASE
215+
WHEN CHARINDEX(N'9/03/1953', LOWER(CONVERT(VARCHAR(100), [val].[Weight]))) > 0
216+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
217+
END) | CASE
218+
WHEN CHARINDEX(N'9/03/1953', LOWER(CONVERT(VARCHAR(11), [val].[Children]))) > 0
219+
THEN CAST(1 AS BIT) ELSE CAST(0 AS BIT)
220+
END) = 1
221+
```
222+
223+
For examples using MySQL and PostgreSQL please see the test project
224+
118225

119226
Installation
120227
========================
@@ -148,7 +255,7 @@ I welcome any suggestions for improvement, contributions, questions or issues wi
148255
* The diff for your pull request should only show changes related to your fix/addition (Some editors create unnecessary changes).
149256
* When possible include tests that cover the features/changes in your pull request
150257
* Before you submit make sure the existing tests pass with your changes
151-
* Also, issues that are accompanied by failing tests will probably get handleded quicker
258+
* Also, issues that are accompanied by failing tests will probably get handled quicker
152259

153260
Contact
154261
========================

src/DatatablesParser/DatatablesParser.cs

+57-5
Original file line numberDiff line numberDiff line change
@@ -20,6 +20,7 @@ public class Parser<T> where T : class
2020
private int _skip;
2121
private bool _sortDisabled = false;
2222

23+
private Dictionary<string,Expression> _converters = new Dictionary<string, Expression>();
2324

2425
private Type[] _convertable =
2526
{
@@ -63,7 +64,12 @@ where Regex.IsMatch(param.Key,Constants.COLUMN_PROPERTY_PATTERN)
6364
}
6465
}).Distinct().ToDictionary(k => k.index, v => v.map);
6566

66-
67+
68+
if(_propertyMap.Count == 0 )
69+
{
70+
throw new Exception("No properties were found in request. Please map datatable field names to properties in T");
71+
}
72+
6773
if(_config.ContainsKey(Constants.DISPLAY_START))
6874
{
6975
int.TryParse(_config[Constants.DISPLAY_START], out _skip);
@@ -137,6 +143,28 @@ public Results<T> Parse()
137143
return list;
138144
}
139145

146+
///<summary>
147+
/// SetConverter accepts a custom expression for converting a property in T to string.
148+
/// This will be used during filtering.
149+
///</summary>
150+
/// <param name="property">A lambda expression with a member expression as the body</param>
151+
/// <param name="tostring">A lambda given T returns a string by performing a sql translatable operation on property</param>
152+
public Parser<T> SetConverter(Expression<Func<T,object>> property, Expression<Func<T,string>> tostring)
153+
{
154+
Console.WriteLine(property.Body.NodeType);
155+
156+
var memberExp = ((UnaryExpression)property.Body).Operand as MemberExpression;
157+
158+
if(memberExp == null)
159+
{
160+
throw new ArgumentException("Body in property must be a member expression");
161+
}
162+
163+
_converters[memberExp.Member.Name] = tostring.Body;
164+
165+
return this;
166+
}
167+
140168
private void ApplySort()
141169
{
142170
var sorted = false;
@@ -240,19 +268,26 @@ private Expression<Func<T, bool>> GenerateEntityFilter()
240268
var searchExpression = Expression.Constant(search.ToLower());
241269
var paramExpression = Expression.Parameter(_type, "val");
242270
List<MethodCallExpression> searchProps = new List<MethodCallExpression>();
271+
var modifier = new ModifyParam(paramExpression);
243272

244273
foreach (var propMap in _propertyMap)
245274
{
246275
var prop = propMap.Value.Property;
247276
var isString = prop.PropertyType == typeof(string);
248-
if (!prop.CanWrite || !propMap.Value.Searchable || (!_convertable.Any(t => t == prop.PropertyType) && !isString ) )
277+
var hasCustom = _converters.ContainsKey(prop.Name);
278+
279+
if ((!prop.CanWrite || !propMap.Value.Searchable || (!_convertable.Any(t => t == prop.PropertyType) && !isString )) && !hasCustom )
249280
{
250281
continue;
251282
}
252283

253284
Expression propExp = Expression.Property(paramExpression, prop);
254285

255-
if (!isString)
286+
if(hasCustom)
287+
{
288+
propExp = modifier.Visit( _converters[prop.Name]);
289+
}
290+
else if (!isString)
256291
{
257292
var toString = prop.PropertyType.GetMethod("ToString", Type.EmptyTypes);
258293

@@ -267,8 +302,9 @@ private Expression<Func<T, bool>> GenerateEntityFilter()
267302
}
268303

269304
var propertyQuery = searchProps.ToArray();
270-
// we now need to compound the expression by starting with the first
271-
// expression and build through the iterator
305+
306+
//This will all be converted to a giant WHERE clause if translated to sql
307+
//Add the first expression
272308
Expression compoundExpression = propertyQuery[0];
273309

274310
// add the other expressions
@@ -284,6 +320,22 @@ private Expression<Func<T, bool>> GenerateEntityFilter()
284320

285321

286322

323+
public class ModifyParam : ExpressionVisitor
324+
{
325+
private ParameterExpression _replace;
326+
327+
public ModifyParam(ParameterExpression p)
328+
{
329+
_replace = p;
330+
}
331+
332+
protected override Expression VisitParameter(ParameterExpression node)
333+
{
334+
return _replace;
335+
}
336+
337+
}
338+
287339
private class PropertyMap
288340
{
289341
public PropertyInfo Property { get; set; }

src/DatatablesParser/DatatablesParser.csproj

+1-1
Original file line numberDiff line numberDiff line change
@@ -4,7 +4,7 @@
44
<TargetFramework>netstandard1.3</TargetFramework>
55
<AssemblyName>DatatablesParser</AssemblyName>
66
<PackageId>DatatablesParser-core</PackageId>
7-
<PackageVersion>1.0.0</PackageVersion>
7+
<PackageVersion>1.1.0</PackageVersion>
88
<PackageRequireLicenseAcceptance>false</PackageRequireLicenseAcceptance>
99
<PackageTags>C# Datatables Datatables.net javascript parser json Linq entity framework asp.net mvc grid table database query builder core</PackageTags>
1010
<PackageProjectUrl>https://github.com/garvincasimir/csharp-datatables-parser</PackageProjectUrl>

test/DatatablesParser.Tests/MssqlEntityTests.cs

+24-3
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,7 @@ public void TotalRecordsTest()
1717

1818
var p = TestHelper.CreateParams();
1919

20-
var parser = new Parser<Person>(p, context.People.AsQueryable());
20+
var parser = new Parser<Person>(p, context.People);
2121

2222
Console.WriteLine("Mssql - Total People TotalRecordsTest: {0}",context.People.Count());
2323

@@ -37,7 +37,7 @@ public void TotalResultsTest()
3737
//override display length
3838
p[Constants.DISPLAY_LENGTH] = new StringValues(Convert.ToString(resultLength));
3939

40-
var parser = new Parser<Person>(p, context.People.AsQueryable());
40+
var parser = new Parser<Person>(p, context.People);
4141

4242
Console.WriteLine("Mssql - Total People TotalResultsTest: {0}",context.People.Count());
4343

@@ -56,14 +56,35 @@ public void TotalDisplayTest()
5656
//Set filter parameter
5757
p[Constants.SEARCH_KEY] = new StringValues("Cromie");
5858

59-
var parser = new Parser<Person>(p, context.People.AsQueryable());
59+
var parser = new Parser<Person>(p, context.People);
6060

6161
Console.WriteLine("Mssql - Total People TotalDisplayTest: {0}",context.People.Count());
6262

6363
Assert.Equal(displayLength, parser.Parse().recordsFiltered);
6464

6565
}
6666

67+
[Fact]
68+
public void TotalDisplayCustomFormatTest()
69+
{
70+
var context = TestHelper.GetMssqlContext();
71+
var p = TestHelper.CreateParams();
72+
var displayLength = 1;
73+
74+
75+
//Set filter parameter
76+
p[Constants.SEARCH_KEY] = new StringValues("9/03/1953");
77+
78+
var parser = new Parser<Person>(p, context.People)
79+
.SetConverter(x => x.BirthDate, x => PersonContext.Format(x.BirthDate,"M/dd/yyyy"));
80+
81+
82+
Console.WriteLine("Mssql - Total People TotalDisplayCustomFormatTest: {0}",context.People.Count());
83+
84+
Assert.Equal(displayLength, parser.Parse().recordsFiltered);
85+
86+
}
87+
6788

6889
}
6990
}

test/DatatablesParser.Tests/MysqlEntityTests.cs

+24-3
Original file line numberDiff line numberDiff line change
@@ -17,7 +17,7 @@ public void TotalRecordsTest()
1717

1818
var p = TestHelper.CreateParams();
1919

20-
var parser = new Parser<Person>(p, context.People.AsQueryable());
20+
var parser = new Parser<Person>(p, context.People);
2121

2222
Console.WriteLine("Mysql - Total People TotalRecordsTest: {0}",context.People.Count());
2323

@@ -37,7 +37,7 @@ public void TotalResultsTest()
3737
//override display length
3838
p[Constants.DISPLAY_LENGTH] = new StringValues(Convert.ToString(resultLength));
3939

40-
var parser = new Parser<Person>(p, context.People.AsQueryable());
40+
var parser = new Parser<Person>(p, context.People);
4141

4242
Console.WriteLine("Mysql - Total People TotalResultsTest: {0}",context.People.Count());
4343

@@ -56,14 +56,35 @@ public void TotalDisplayTest()
5656
//Set filter parameter
5757
p[Constants.SEARCH_KEY] = new StringValues("Cromie");
5858

59-
var parser = new Parser<Person>(p, context.People.AsQueryable());
59+
var parser = new Parser<Person>(p, context.People);
6060

6161
Console.WriteLine("Mysql - Total People TotalDisplayTest: {0}",context.People.Count());
6262

6363
Assert.Equal(displayLength, parser.Parse().recordsFiltered);
6464

6565
}
6666

67+
[Fact]
68+
public void TotalDisplayCustomFormatTest()
69+
{
70+
var context = TestHelper.GetMysqlContext();
71+
var p = TestHelper.CreateParams();
72+
var displayLength = 1;
73+
74+
75+
//Set filter parameter
76+
p[Constants.SEARCH_KEY] = new StringValues("09/03/1953");
77+
78+
var parser = new Parser<Person>(p, context.People)
79+
.SetConverter(x => x.BirthDate, x => PersonContext.Date_Format(x.BirthDate,"%m/%d/%Y"));
80+
81+
82+
Console.WriteLine("MySql - Total People TotalDisplayCustomFormatTest: {0}",context.People.Count());
83+
84+
Assert.Equal(displayLength, parser.Parse().recordsFiltered);
85+
86+
}
87+
6788

6889
}
6990
}

0 commit comments

Comments
 (0)