forked from DapperLib/Dapper
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathParameterTests.cs
1331 lines (1150 loc) · 49.7 KB
/
ParameterTests.cs
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
using System;
using System.Collections;
using System.Collections.Generic;
using System.ComponentModel;
using System.Data;
using System.Data.SqlClient;
using System.Data.SqlTypes;
using System.Dynamic;
using System.Linq;
using Xunit;
using System.Globalization;
using System.Text.RegularExpressions;
#if ENTITY_FRAMEWORK
using System.Data.Entity.Spatial;
using Microsoft.SqlServer.Types;
#endif
namespace Dapper.Tests
{
public class ParameterTests : TestBase
{
public class DbParams : SqlMapper.IDynamicParameters, IEnumerable<IDbDataParameter>
{
private readonly List<IDbDataParameter> parameters = new List<IDbDataParameter>();
public IEnumerator<IDbDataParameter> GetEnumerator() { return parameters.GetEnumerator(); }
IEnumerator IEnumerable.GetEnumerator() { return GetEnumerator(); }
public void Add(IDbDataParameter value)
{
parameters.Add(value);
}
void SqlMapper.IDynamicParameters.AddParameters(IDbCommand command, SqlMapper.Identity identity)
{
foreach (IDbDataParameter parameter in parameters)
command.Parameters.Add(parameter);
}
}
private class IntDynamicParam : SqlMapper.IDynamicParameters
{
private readonly IEnumerable<int> numbers;
public IntDynamicParam(IEnumerable<int> numbers)
{
this.numbers = numbers;
}
public void AddParameters(IDbCommand command, SqlMapper.Identity identity)
{
var sqlCommand = (SqlCommand)command;
sqlCommand.CommandType = CommandType.StoredProcedure;
var number_list = new List<Microsoft.SqlServer.Server.SqlDataRecord>();
// Create an SqlMetaData object that describes our table type.
Microsoft.SqlServer.Server.SqlMetaData[] tvp_definition = { new Microsoft.SqlServer.Server.SqlMetaData("n", SqlDbType.Int) };
foreach (int n in numbers)
{
// Create a new record, using the metadata array above.
var rec = new Microsoft.SqlServer.Server.SqlDataRecord(tvp_definition);
rec.SetInt32(0, n); // Set the value.
number_list.Add(rec); // Add it to the list.
}
// Add the table parameter.
var p = sqlCommand.Parameters.Add("ints", SqlDbType.Structured);
p.Direction = ParameterDirection.Input;
p.TypeName = "int_list_type";
p.Value = number_list;
}
}
private class IntCustomParam : SqlMapper.ICustomQueryParameter
{
private readonly IEnumerable<int> numbers;
public IntCustomParam(IEnumerable<int> numbers)
{
this.numbers = numbers;
}
public void AddParameter(IDbCommand command, string name)
{
var sqlCommand = (SqlCommand)command;
sqlCommand.CommandType = CommandType.StoredProcedure;
var number_list = new List<Microsoft.SqlServer.Server.SqlDataRecord>();
// Create an SqlMetaData object that describes our table type.
Microsoft.SqlServer.Server.SqlMetaData[] tvp_definition = { new Microsoft.SqlServer.Server.SqlMetaData("n", SqlDbType.Int) };
foreach (int n in numbers)
{
// Create a new record, using the metadata array above.
var rec = new Microsoft.SqlServer.Server.SqlDataRecord(tvp_definition);
rec.SetInt32(0, n); // Set the value.
number_list.Add(rec); // Add it to the list.
}
// Add the table parameter.
var p = sqlCommand.Parameters.Add(name, SqlDbType.Structured);
p.Direction = ParameterDirection.Input;
p.TypeName = "int_list_type";
p.Value = number_list;
}
}
/* TODO:
*
public void TestMagicParam()
{
// magic params allow you to pass in single params without using an anon class
// this test fails for now, but I would like to support a single param by parsing the sql with regex and remapping.
var first = connection.Query("select @a as a", 1).First();
Assert.IsEqualTo(first.a, 1);
}
* */
[Fact]
public void TestDoubleParam()
{
connection.Query<double>("select @d", new { d = 0.1d }).First()
.IsEqualTo(0.1d);
}
[Fact]
public void TestBoolParam()
{
connection.Query<bool>("select @b", new { b = false }).First()
.IsFalse();
}
// http://code.google.com/p/dapper-dot-net/issues/detail?id=70
// https://connect.microsoft.com/VisualStudio/feedback/details/381934/sqlparameter-dbtype-dbtype-time-sets-the-parameter-to-sqldbtype-datetime-instead-of-sqldbtype-time
[Fact]
public void TestTimeSpanParam()
{
connection.Query<TimeSpan>("select @ts", new { ts = TimeSpan.FromMinutes(42) }).First()
.IsEqualTo(TimeSpan.FromMinutes(42));
}
[Fact]
public void PassInIntArray()
{
connection.Query<int>("select * from (select 1 as Id union all select 2 union all select 3) as X where Id in @Ids", new { Ids = new int[] { 1, 2, 3 }.AsEnumerable() })
.IsSequenceEqualTo(new[] { 1, 2, 3 });
}
[Fact]
public void PassInEmptyIntArray()
{
connection.Query<int>("select * from (select 1 as Id union all select 2 union all select 3) as X where Id in @Ids", new { Ids = new int[0] })
.IsSequenceEqualTo(new int[0]);
}
[Fact]
public void TestExecuteCommandWithHybridParameters()
{
var p = new DynamicParameters(new { a = 1, b = 2 });
p.Add("c", dbType: DbType.Int32, direction: ParameterDirection.Output);
connection.Execute(@"set @c = @a + @b", p);
p.Get<int>("@c").IsEqualTo(3);
}
[Fact]
public void GuidIn_SO_24177902()
{
// invent and populate
Guid a = Guid.NewGuid(), b = Guid.NewGuid(), c = Guid.NewGuid(), d = Guid.NewGuid();
connection.Execute("create table #foo (i int, g uniqueidentifier)");
connection.Execute("insert #foo(i,g) values(@i,@g)",
new[] { new { i = 1, g = a }, new { i = 2, g = b },
new { i = 3, g = c },new { i = 4, g = d }});
// check that rows 2&3 yield guids b&c
var guids = connection.Query<Guid>("select g from #foo where i in (2,3)").ToArray();
guids.Length.Equals(2);
guids.Contains(a).Equals(false);
guids.Contains(b).Equals(true);
guids.Contains(c).Equals(true);
guids.Contains(d).Equals(false);
// in query on the guids
var rows = connection.Query("select * from #foo where g in @guids order by i", new { guids })
.Select(row => new { i = (int)row.i, g = (Guid)row.g }).ToArray();
rows.Length.Equals(2);
rows[0].i.Equals(2);
rows[0].g.Equals(b);
rows[1].i.Equals(3);
rows[1].g.Equals(c);
}
[FactUnlessCaseSensitiveDatabase]
public void TestParameterInclusionNotSensitiveToCurrentCulture()
{
// note this might fail if your database server is case-sensitive
CultureInfo current = ActiveCulture;
try
{
ActiveCulture = new CultureInfo("tr-TR");
connection.Query<int>("select @pid", new { PId = 1 }).Single();
}
finally
{
ActiveCulture = current;
}
}
[Fact]
public void TestMassiveStrings()
{
var str = new string('X', 20000);
connection.Query<string>("select @a", new { a = str }).First()
.IsEqualTo(str);
}
#if !COREFX
[Fact]
public void TestTVPWithAnonymousObject()
{
try
{
connection.Execute("CREATE TYPE int_list_type AS TABLE (n int NOT NULL PRIMARY KEY)");
connection.Execute("CREATE PROC get_ints @integers int_list_type READONLY AS select * from @integers");
var nums = connection.Query<int>("get_ints", new { integers = new IntCustomParam(new int[] { 1, 2, 3 }) }, commandType: CommandType.StoredProcedure).ToList();
nums[0].IsEqualTo(1);
nums[1].IsEqualTo(2);
nums[2].IsEqualTo(3);
nums.Count.IsEqualTo(3);
}
finally
{
try
{
connection.Execute("DROP PROC get_ints");
}
finally
{
connection.Execute("DROP TYPE int_list_type");
}
}
}
// SQL Server specific test to demonstrate TVP
[Fact]
public void TestTVP()
{
try
{
connection.Execute("CREATE TYPE int_list_type AS TABLE (n int NOT NULL PRIMARY KEY)");
connection.Execute("CREATE PROC get_ints @ints int_list_type READONLY AS select * from @ints");
var nums = connection.Query<int>("get_ints", new IntDynamicParam(new int[] { 1, 2, 3 })).ToList();
nums[0].IsEqualTo(1);
nums[1].IsEqualTo(2);
nums[2].IsEqualTo(3);
nums.Count.IsEqualTo(3);
}
finally
{
try
{
connection.Execute("DROP PROC get_ints");
}
finally
{
connection.Execute("DROP TYPE int_list_type");
}
}
}
private class DynamicParameterWithIntTVP : DynamicParameters, SqlMapper.IDynamicParameters
{
private readonly IEnumerable<int> numbers;
public DynamicParameterWithIntTVP(IEnumerable<int> numbers)
{
this.numbers = numbers;
}
public new void AddParameters(IDbCommand command, SqlMapper.Identity identity)
{
base.AddParameters(command, identity);
var sqlCommand = (SqlCommand)command;
sqlCommand.CommandType = CommandType.StoredProcedure;
var number_list = new List<Microsoft.SqlServer.Server.SqlDataRecord>();
// Create an SqlMetaData object that describes our table type.
Microsoft.SqlServer.Server.SqlMetaData[] tvp_definition = { new Microsoft.SqlServer.Server.SqlMetaData("n", SqlDbType.Int) };
foreach (int n in numbers)
{
// Create a new record, using the metadata array above.
var rec = new Microsoft.SqlServer.Server.SqlDataRecord(tvp_definition);
rec.SetInt32(0, n); // Set the value.
number_list.Add(rec); // Add it to the list.
}
// Add the table parameter.
var p = sqlCommand.Parameters.Add("ints", SqlDbType.Structured);
p.Direction = ParameterDirection.Input;
p.TypeName = "int_list_type";
p.Value = number_list;
}
}
[Fact]
public void TestTVPWithAdditionalParams()
{
try
{
connection.Execute("CREATE TYPE int_list_type AS TABLE (n int NOT NULL PRIMARY KEY)");
connection.Execute("CREATE PROC get_values @ints int_list_type READONLY, @stringParam varchar(20), @dateParam datetime AS select i.*, @stringParam as stringParam, @dateParam as dateParam from @ints i");
var dynamicParameters = new DynamicParameterWithIntTVP(new int[] { 1, 2, 3 });
dynamicParameters.AddDynamicParams(new { stringParam = "stringParam", dateParam = new DateTime(2012, 1, 1) });
var results = connection.Query("get_values", dynamicParameters, commandType: CommandType.StoredProcedure).ToList();
results.Count.IsEqualTo(3);
for (int i = 0; i < results.Count; i++)
{
var result = results[i];
Assert.IsEqualTo(i + 1, result.n);
Assert.IsEqualTo("stringParam", result.stringParam);
Assert.IsEqualTo(new DateTime(2012, 1, 1), result.dateParam);
}
}
finally
{
try
{
connection.Execute("DROP PROC get_values");
}
finally
{
connection.Execute("DROP TYPE int_list_type");
}
}
}
[Fact]
public void DataTableParameters()
{
try { connection.Execute("drop proc #DataTableParameters"); }
catch { /* don't care */ }
try { connection.Execute("drop table #DataTableParameters"); }
catch { /* don't care */ }
try { connection.Execute("drop type MyTVPType"); }
catch { /* don't care */ }
connection.Execute("create type MyTVPType as table (id int)");
connection.Execute("create proc #DataTableParameters @ids MyTVPType readonly as select count(1) from @ids");
var table = new DataTable { Columns = { { "id", typeof(int) } }, Rows = { { 1 }, { 2 }, { 3 } } };
int count = connection.Query<int>("#DataTableParameters", new { ids = table.AsTableValuedParameter() }, commandType: CommandType.StoredProcedure).First();
count.IsEqualTo(3);
count = connection.Query<int>("select count(1) from @ids", new { ids = table.AsTableValuedParameter("MyTVPType") }).First();
count.IsEqualTo(3);
try
{
connection.Query<int>("select count(1) from @ids", new { ids = table.AsTableValuedParameter() }).First();
throw new InvalidOperationException();
}
catch (Exception ex)
{
ex.Message.Equals("The table type parameter 'ids' must have a valid type name.");
}
}
[Fact]
public void SO29533765_DataTableParametersViaDynamicParameters()
{
try { connection.Execute("drop proc #DataTableParameters"); } catch { /* don't care */ }
try { connection.Execute("drop table #DataTableParameters"); } catch { /* don't care */ }
try { connection.Execute("drop type MyTVPType"); } catch { /* don't care */ }
connection.Execute("create type MyTVPType as table (id int)");
connection.Execute("create proc #DataTableParameters @ids MyTVPType readonly as select count(1) from @ids");
var table = new DataTable { TableName="MyTVPType", Columns = { { "id", typeof(int) } }, Rows = { { 1 }, { 2 }, { 3 } } };
table.SetTypeName(table.TableName); // per SO29533765
IDictionary<string, object> args = new Dictionary<string, object>
{
["ids"] = table
};
int count = connection.Query<int>("#DataTableParameters", args, commandType: CommandType.StoredProcedure).First();
count.IsEqualTo(3);
count = connection.Query<int>("select count(1) from @ids", args).First();
count.IsEqualTo(3);
}
[Fact]
public void SO26468710_InWithTVPs()
{
// this is just to make it re-runnable; normally you only do this once
try { connection.Execute("drop type MyIdList"); }
catch { /* don't care */ }
connection.Execute("create type MyIdList as table(id int);");
var ids = new DataTable
{
Columns = { { "id", typeof(int) } },
Rows = { { 1 }, { 3 }, { 5 } }
};
ids.SetTypeName("MyIdList");
int sum = connection.Query<int>(@"
declare @tmp table(id int not null);
insert @tmp (id) values(1), (2), (3), (4), (5), (6), (7);
select * from @tmp t inner join @ids i on i.id = t.id", new { ids }).Sum();
sum.IsEqualTo(9);
}
[Fact]
public void DataTableParametersWithExtendedProperty()
{
try { connection.Execute("drop proc #DataTableParameters"); }
catch { /* don't care */ }
try { connection.Execute("drop table #DataTableParameters"); }
catch { /* don't care */ }
try { connection.Execute("drop type MyTVPType"); }
catch { /* don't care */ }
connection.Execute("create type MyTVPType as table (id int)");
connection.Execute("create proc #DataTableParameters @ids MyTVPType readonly as select count(1) from @ids");
var table = new DataTable { Columns = { { "id", typeof(int) } }, Rows = { { 1 }, { 2 }, { 3 } } };
table.SetTypeName("MyTVPType"); // <== extended metadata
int count = connection.Query<int>("#DataTableParameters", new { ids = table }, commandType: CommandType.StoredProcedure).First();
count.IsEqualTo(3);
count = connection.Query<int>("select count(1) from @ids", new { ids = table }).First();
count.IsEqualTo(3);
try
{
connection.Query<int>("select count(1) from @ids", new { ids = table }).First();
throw new InvalidOperationException();
}
catch (Exception ex)
{
ex.Message.Equals("The table type parameter 'ids' must have a valid type name.");
}
}
[Fact]
public void SupportInit()
{
var obj = connection.Query<WithInit>("select 'abc' as Value").Single();
obj.Value.Equals("abc");
obj.Flags.Equals(31);
}
public class WithInit : ISupportInitialize
{
public string Value { get; set; }
public int Flags { get; set; }
void ISupportInitialize.BeginInit() => Flags++;
void ISupportInitialize.EndInit() => Flags += 30;
}
[Fact]
public void SO29596645_TvpProperty()
{
try { connection.Execute("CREATE TYPE SO29596645_ReminderRuleType AS TABLE (id int NOT NULL)"); }
catch { /* don't care */ }
connection.Execute(@"create proc #SO29596645_Proc (@Id int, @Rules SO29596645_ReminderRuleType READONLY)
as begin select @Id + ISNULL((select sum(id) from @Rules), 0); end");
var obj = new SO29596645_OrganisationDTO();
int val = connection.Query<int>("#SO29596645_Proc", obj.Rules, commandType: CommandType.StoredProcedure).Single();
// 4 + 9 + 7 = 20
val.IsEqualTo(20);
}
private class SO29596645_RuleTableValuedParameters : SqlMapper.IDynamicParameters
{
private string parameterName;
public SO29596645_RuleTableValuedParameters(string parameterName)
{
this.parameterName = parameterName;
}
public void AddParameters(IDbCommand command, SqlMapper.Identity identity)
{
Console.WriteLine("> AddParameters");
var lazy = (SqlCommand)command;
lazy.Parameters.AddWithValue("Id", 7);
var table = new DataTable
{
Columns = { { "Id", typeof(int) } },
Rows = { { 4 }, { 9 } }
};
lazy.Parameters.AddWithValue("Rules", table);
Console.WriteLine("< AddParameters");
}
}
private class SO29596645_OrganisationDTO
{
public SO29596645_RuleTableValuedParameters Rules { get; private set; }
public SO29596645_OrganisationDTO()
{
Rules = new SO29596645_RuleTableValuedParameters("@Rules");
}
}
#endif
#if ENTITY_FRAMEWORK
private class HazGeo
{
public int Id { get; set; }
public DbGeography Geo { get; set; }
public DbGeometry Geometry { get; set; }
}
private class HazSqlGeo
{
public int Id { get; set; }
public SqlGeography Geo { get; set; }
public SqlGeometry Geometry { get; set; }
}
[Fact]
public void DBGeography_SO24405645_SO24402424()
{
EntityFramework.Handlers.Register();
connection.Execute("create table #Geo (id int, geo geography, geometry geometry)");
var obj = new HazGeo
{
Id = 1,
Geo = DbGeography.LineFromText("LINESTRING(-122.360 47.656, -122.343 47.656 )", 4326),
Geometry = DbGeometry.LineFromText("LINESTRING (100 100, 20 180, 180 180)", 0)
};
connection.Execute("insert #Geo(id, geo, geometry) values (@Id, @Geo, @Geometry)", obj);
var row = connection.Query<HazGeo>("select * from #Geo where id=1").SingleOrDefault();
row.IsNotNull();
row.Id.IsEqualTo(1);
row.Geo.IsNotNull();
row.Geometry.IsNotNull();
}
[Fact]
public void SqlGeography_SO25538154()
{
SqlMapper.ResetTypeHandlers();
connection.Execute("create table #SqlGeo (id int, geo geography, geometry geometry)");
var obj = new HazSqlGeo
{
Id = 1,
Geo = SqlGeography.STLineFromText(new SqlChars(new SqlString("LINESTRING(-122.360 47.656, -122.343 47.656 )")), 4326),
Geometry = SqlGeometry.STLineFromText(new SqlChars(new SqlString("LINESTRING (100 100, 20 180, 180 180)")), 0)
};
connection.Execute("insert #SqlGeo(id, geo, geometry) values (@Id, @Geo, @Geometry)", obj);
var row = connection.Query<HazSqlGeo>("select * from #SqlGeo where id=1").SingleOrDefault();
row.IsNotNull();
row.Id.IsEqualTo(1);
row.Geo.IsNotNull();
row.Geometry.IsNotNull();
}
[Fact]
public void NullableSqlGeometry()
{
SqlMapper.ResetTypeHandlers();
connection.Execute("create table #SqlNullableGeo (id int, geometry geometry null)");
var obj = new HazSqlGeo
{
Id = 1,
Geometry = null
};
connection.Execute("insert #SqlNullableGeo(id, geometry) values (@Id, @Geometry)", obj);
var row = connection.Query<HazSqlGeo>("select * from #SqlNullableGeo where id=1").SingleOrDefault();
row.IsNotNull();
row.Id.IsEqualTo(1);
row.Geometry.IsNull();
}
[Fact]
public void SqlHierarchyId_SO18888911()
{
Dapper.SqlMapper.ResetTypeHandlers();
var row = connection.Query<HazSqlHierarchy>("select 3 as [Id], hierarchyid::Parse('/1/2/3/') as [Path]").Single();
row.Id.Equals(3);
row.Path.IsNotNull();
var val = connection.Query<SqlHierarchyId>("select @Path", row).Single();
val.IsNotNull();
}
public class HazSqlHierarchy
{
public int Id { get; set; }
public SqlHierarchyId Path { get; set; }
}
#endif
[Fact]
public void TestCustomParameters()
{
var args = new DbParams {
new SqlParameter("foo", 123),
new SqlParameter("bar", "abc")
};
var result = connection.Query("select Foo=@foo, Bar=@bar", args).Single();
int foo = result.Foo;
string bar = result.Bar;
foo.IsEqualTo(123);
bar.IsEqualTo("abc");
}
[Fact]
public void TestDynamicParamNullSupport()
{
var p = new DynamicParameters();
p.Add("@b", dbType: DbType.Int32, direction: ParameterDirection.Output);
connection.Execute("select @b = null", p);
p.Get<int?>("@b").IsNull();
}
[Fact]
public void TestAppendingAnonClasses()
{
var p = new DynamicParameters();
p.AddDynamicParams(new { A = 1, B = 2 });
p.AddDynamicParams(new { C = 3, D = 4 });
var result = connection.Query("select @A a,@B b,@C c,@D d", p).Single();
((int)result.a).IsEqualTo(1);
((int)result.b).IsEqualTo(2);
((int)result.c).IsEqualTo(3);
((int)result.d).IsEqualTo(4);
}
[Fact]
public void TestAppendingADictionary()
{
var dictionary = new Dictionary<string, object>
{
["A"] = 1,
["B"] = "two"
};
var p = new DynamicParameters();
p.AddDynamicParams(dictionary);
var result = connection.Query("select @A a, @B b", p).Single();
((int)result.a).IsEqualTo(1);
((string)result.b).IsEqualTo("two");
}
[Fact]
public void TestAppendingAnExpandoObject()
{
dynamic expando = new ExpandoObject();
expando.A = 1;
expando.B = "two";
var p = new DynamicParameters();
p.AddDynamicParams(expando);
var result = connection.Query("select @A a, @B b", p).Single();
((int)result.a).IsEqualTo(1);
((string)result.b).IsEqualTo("two");
}
[Fact]
public void TestAppendingAList()
{
var p = new DynamicParameters();
var list = new int[] { 1, 2, 3 };
p.AddDynamicParams(new { list });
var result = connection.Query<int>("select * from (select 1 A union all select 2 union all select 3) X where A in @list", p).ToList();
result[0].IsEqualTo(1);
result[1].IsEqualTo(2);
result[2].IsEqualTo(3);
}
[Fact]
public void TestAppendingAListAsDictionary()
{
var p = new DynamicParameters();
var list = new int[] { 1, 2, 3 };
var args = new Dictionary<string, object> { ["ids"] = list };
p.AddDynamicParams(args);
var result = connection.Query<int>("select * from (select 1 A union all select 2 union all select 3) X where A in @ids", p).ToList();
result[0].IsEqualTo(1);
result[1].IsEqualTo(2);
result[2].IsEqualTo(3);
}
[Fact]
public void TestAppendingAListByName()
{
DynamicParameters p = new DynamicParameters();
var list = new int[] { 1, 2, 3 };
p.Add("ids", list);
var result = connection.Query<int>("select * from (select 1 A union all select 2 union all select 3) X where A in @ids", p).ToList();
result[0].IsEqualTo(1);
result[1].IsEqualTo(2);
result[2].IsEqualTo(3);
}
[Fact]
public void ParameterizedInWithOptimizeHint()
{
const string sql = @"
select count(1)
from(
select 1 as x
union all select 2
union all select 5) y
where y.x in @vals
option (optimize for (@vals unKnoWn))";
int count = connection.Query<int>(sql, new { vals = new[] { 1, 2, 3, 4 } }).Single();
count.IsEqualTo(2);
count = connection.Query<int>(sql, new { vals = new[] { 1 } }).Single();
count.IsEqualTo(1);
count = connection.Query<int>(sql, new { vals = new int[0] }).Single();
count.IsEqualTo(0);
}
[Fact]
public void TestProcedureWithTimeParameter()
{
var p = new DynamicParameters();
p.Add("a", TimeSpan.FromHours(10), dbType: DbType.Time);
connection.Execute(@"CREATE PROCEDURE #TestProcWithTimeParameter
@a TIME
AS
BEGIN
SELECT @a
END");
connection.Query<TimeSpan>("#TestProcWithTimeParameter", p, commandType: CommandType.StoredProcedure).First().IsEqualTo(new TimeSpan(10, 0, 0));
}
[Fact]
public void TestUniqueIdentifier()
{
var guid = Guid.NewGuid();
var result = connection.Query<Guid>("declare @foo uniqueidentifier set @foo = @guid select @foo", new { guid }).Single();
result.IsEqualTo(guid);
}
[Fact]
public void TestNullableUniqueIdentifierNonNull()
{
Guid? guid = Guid.NewGuid();
var result = connection.Query<Guid?>("declare @foo uniqueidentifier set @foo = @guid select @foo", new { guid }).Single();
result.IsEqualTo(guid);
}
[Fact]
public void TestNullableUniqueIdentifierNull()
{
Guid? guid = null;
var result = connection.Query<Guid?>("declare @foo uniqueidentifier set @foo = @guid select @foo", new { guid }).Single();
result.IsEqualTo(guid);
}
[Fact]
public void TestSupportForDynamicParameters()
{
var p = new DynamicParameters();
p.Add("name", "bob");
p.Add("age", dbType: DbType.Int32, direction: ParameterDirection.Output);
connection.Query<string>("set @age = 11 select @name", p).First().IsEqualTo("bob");
p.Get<int>("age").IsEqualTo(11);
}
[Fact]
public void TestSupportForDynamicParametersOutputExpressions()
{
var bob = new Person { Name = "bob", PersonId = 1, Address = new Address { PersonId = 2 } };
var p = new DynamicParameters(bob);
p.Output(bob, b => b.PersonId);
p.Output(bob, b => b.Occupation);
p.Output(bob, b => b.NumberOfLegs);
p.Output(bob, b => b.Address.Name);
p.Output(bob, b => b.Address.PersonId);
connection.Execute(@"
SET @Occupation = 'grillmaster'
SET @PersonId = @PersonId + 1
SET @NumberOfLegs = @NumberOfLegs - 1
SET @AddressName = 'bobs burgers'
SET @AddressPersonId = @PersonId", p);
bob.Occupation.IsEqualTo("grillmaster");
bob.PersonId.IsEqualTo(2);
bob.NumberOfLegs.IsEqualTo(1);
bob.Address.Name.IsEqualTo("bobs burgers");
bob.Address.PersonId.IsEqualTo(2);
}
[Fact]
public void TestSupportForDynamicParametersOutputExpressions_Scalar()
{
using (var connection = GetOpenConnection())
{
var bob = new Person { Name = "bob", PersonId = 1, Address = new Address { PersonId = 2 } };
var p = new DynamicParameters(bob);
p.Output(bob, b => b.PersonId);
p.Output(bob, b => b.Occupation);
p.Output(bob, b => b.NumberOfLegs);
p.Output(bob, b => b.Address.Name);
p.Output(bob, b => b.Address.PersonId);
var result = (int)connection.ExecuteScalar(@"
SET @Occupation = 'grillmaster'
SET @PersonId = @PersonId + 1
SET @NumberOfLegs = @NumberOfLegs - 1
SET @AddressName = 'bobs burgers'
SET @AddressPersonId = @PersonId
select 42", p);
bob.Occupation.IsEqualTo("grillmaster");
bob.PersonId.IsEqualTo(2);
bob.NumberOfLegs.IsEqualTo(1);
bob.Address.Name.IsEqualTo("bobs burgers");
bob.Address.PersonId.IsEqualTo(2);
result.IsEqualTo(42);
}
}
[Fact]
public void TestSupportForDynamicParametersOutputExpressions_Query_Buffered()
{
using (var connection = GetOpenConnection())
{
var bob = new Person { Name = "bob", PersonId = 1, Address = new Address { PersonId = 2 } };
var p = new DynamicParameters(bob);
p.Output(bob, b => b.PersonId);
p.Output(bob, b => b.Occupation);
p.Output(bob, b => b.NumberOfLegs);
p.Output(bob, b => b.Address.Name);
p.Output(bob, b => b.Address.PersonId);
var result = connection.Query<int>(@"
SET @Occupation = 'grillmaster'
SET @PersonId = @PersonId + 1
SET @NumberOfLegs = @NumberOfLegs - 1
SET @AddressName = 'bobs burgers'
SET @AddressPersonId = @PersonId
select 42", p, buffered: true).Single();
bob.Occupation.IsEqualTo("grillmaster");
bob.PersonId.IsEqualTo(2);
bob.NumberOfLegs.IsEqualTo(1);
bob.Address.Name.IsEqualTo("bobs burgers");
bob.Address.PersonId.IsEqualTo(2);
result.IsEqualTo(42);
}
}
[Fact]
public void TestSupportForDynamicParametersOutputExpressions_Query_NonBuffered()
{
using (var connection = GetOpenConnection())
{
var bob = new Person { Name = "bob", PersonId = 1, Address = new Address { PersonId = 2 } };
var p = new DynamicParameters(bob);
p.Output(bob, b => b.PersonId);
p.Output(bob, b => b.Occupation);
p.Output(bob, b => b.NumberOfLegs);
p.Output(bob, b => b.Address.Name);
p.Output(bob, b => b.Address.PersonId);
var result = connection.Query<int>(@"
SET @Occupation = 'grillmaster'
SET @PersonId = @PersonId + 1
SET @NumberOfLegs = @NumberOfLegs - 1
SET @AddressName = 'bobs burgers'
SET @AddressPersonId = @PersonId
select 42", p, buffered: false).Single();
bob.Occupation.IsEqualTo("grillmaster");
bob.PersonId.IsEqualTo(2);
bob.NumberOfLegs.IsEqualTo(1);
bob.Address.Name.IsEqualTo("bobs burgers");
bob.Address.PersonId.IsEqualTo(2);
result.IsEqualTo(42);
}
}
[Fact]
public void TestSupportForDynamicParametersOutputExpressions_QueryMultiple()
{
using (var connection = GetOpenConnection())
{
var bob = new Person { Name = "bob", PersonId = 1, Address = new Address { PersonId = 2 } };
var p = new DynamicParameters(bob);
p.Output(bob, b => b.PersonId);
p.Output(bob, b => b.Occupation);
p.Output(bob, b => b.NumberOfLegs);
p.Output(bob, b => b.Address.Name);
p.Output(bob, b => b.Address.PersonId);
int x, y;
using (var multi = connection.QueryMultiple(@"
SET @Occupation = 'grillmaster'
SET @PersonId = @PersonId + 1
SET @NumberOfLegs = @NumberOfLegs - 1
SET @AddressName = 'bobs burgers'
select 42
select 17
SET @AddressPersonId = @PersonId", p))
{
x = multi.Read<int>().Single();
y = multi.Read<int>().Single();
}
bob.Occupation.IsEqualTo("grillmaster");
bob.PersonId.IsEqualTo(2);
bob.NumberOfLegs.IsEqualTo(1);
bob.Address.Name.IsEqualTo("bobs burgers");
bob.Address.PersonId.IsEqualTo(2);
x.IsEqualTo(42);
y.IsEqualTo(17);
}
}
[Fact]
public void TestSupportForExpandoObjectParameters()
{
dynamic p = new ExpandoObject();
p.name = "bob";
object parameters = p;
string result = connection.Query<string>("select @name", parameters).First();
result.IsEqualTo("bob");
}
[Fact]
public void SO25069578_DynamicParams_Procs()
{
var parameters = new DynamicParameters();
parameters.Add("foo", "bar");
// parameters = new DynamicParameters(parameters);
try { connection.Execute("drop proc SO25069578"); }
catch { /* don't care */ }
connection.Execute("create proc SO25069578 @foo nvarchar(max) as select @foo as [X]");
var tran = connection.BeginTransaction(); // gist used transaction; behaves the same either way, though
var row = connection.Query<HazX>("SO25069578", parameters,
commandType: CommandType.StoredProcedure, transaction: tran).Single();
tran.Rollback();
row.X.IsEqualTo("bar");
}
public class HazX
{
public string X { get; set; }
}
[Fact]
public void SO25297173_DynamicIn()
{
const string query = @"
declare @table table(value int not null);
insert @table values(1);
insert @table values(2);
insert @table values(3);
insert @table values(4);
insert @table values(5);
insert @table values(6);
insert @table values(7);