Saturday, March 17, 2007 10:19 AM tonyrogerson

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Ever had the need to pass in a list of values to a stored procedure (like an array), may be the middle tier passing in a set of pools for a race, passing a set of emails associated with an event.

If you listen to Joe Celko (some links at the bottom), self proclaimed “SQL Guru” you’d be coding one parameter per passed value, for instance passing in a set of emails you’d have @email0001, @email0002 right through to @emailnnnn . He feels and arguments strongly against people who dare suggest or god forbid use a single parameter, @email_csv or @email_xml and pass in a CSV (Comma Separated Value) or XML to the procedure.

I just had to write this up, I'm getting real tired of this guy stating x, y and z when x, y, z only works in the class room and if anybody actually did this in a real application they'd end up in a real mess - if only he'd do some research before opening his mouth, but hey - when you are as 'Guru' as he is perhaps you don't need to - may be one day....

Well here’s the proof just how wrong Celko is.

Test

CPU

Reads

Writes

Duration
(secs)

1,000 Parameters

345,984

45,298

33

350

1,000 Proc Generation Cost

109

7,334

27

>1

CSV – Number Table

378,047

33,768,734

1,652

384

CSV – Dynamic SQL

27,266

40,006

0

27

Note: Figures from SQL Profiler captured on a machine dedicated to this test.

This test is as vanilla as it gets, in reality the figures for the 1,000 parameter approach would be significantly worse because of interaction with other SQL within the procedure. Imagine this out in a real system with many concurrent connections etc... There are better ways of doing the array than using the number table, dynamic SQL will always be the best performer and in 2005 security can be locked down.

This is before maintainability again for which he strongly argues that maintaining the 1,000 parameter approaches would cost less than using CSV or XML! Can you imagine the client/middle tier side code to that – the amount of additional memory required for the command object and all those parameter classes?

Practicalities around maintaining the 1,000 parameter stored procedure, even on my 4GB Dual Core machine with a fast AMD processor Management Studio takes over a minute to open the thing for edit.

Anyway, I’ll let you decide – here is the SQL that proves the results above, this was run on SQL 2005 SP2.

create database csvtosp

go

use csvtosp

go

 

create table numbers (

      number      smallint    not null primary key clustered

)

declare @i int

set @i = 1

while @i <= 32767

begin

      insert numbers ( number ) values( @i )

      set @i = @i + 1

end

go

 

create table somedata (

      avalue      int   not null primary key clustered

      )

 

--    populate

set nocount on

declare @i int

set @i = 1

while @i <= 1000

begin

      insert somedata ( avalue ) values( @i )

      set @i = @i + 1

 

end

go

 

 

--    We will pass CSV but use the numbers to split the string up

create proc getdata_csv

      @csv varchar(max)

as

      DECLARE @c int

      DECLARE @csv_extracted TABLE ( input smallint not null )

 

      INSERT @csv_extracted ( input )

      SELECT SUBSTRING( ',' + @csv + ',', n1.Number + 1,

                    CHARINDEX(',', ',' + @csv + ',', n1.Number + 1) - n1.Number - 1)

      FROM   Numbers n1

      WHERE  n1.Number <= len(',' + @csv + ',') - 1

        AND  substring(',' + @csv + ',', n1.Number, 1) = ','

 

      SELECT @c = count(*)

      FROM @csv_extracted e

            INNER JOIN somedata d ON d.avalue = e.input

 

 

go

 

--    We will use dynamic SQL, note the replace on ' to make sure there are no open ended ' to allow injection

create proc getdata_dynamic

      @csv varchar(max)

as

      set @csv = replace( @csv, '''', '''''' )

      exec( '     DECLARE @c int

 

               select @c = count(*)

               from somedata

               where avalue in ( ' + @csv + ' )'

            )

go

 

--    Create the 1,000 parm query; best this way because the actual proc once created is over 15KBytes of text!

dbcc freeproccache

go

 

declare @i int

set @i = 2

 

drop proc getdata_parms

 

declare @sql varchar(max)

set @sql = 'create proc getdata_parms @p1 int'

 

declare @sql2 varchar(max)

set @sql2 = 'exec getdata_parms @p1=1'

 

declare @in_list varchar(max)

set @in_list = '1'

 

while @i <= 1000

begin

      set @sql = @sql + ', @p' + cast( @i as varchar(4) ) + ' int'

      set @sql2 = @sql2 + ', @p' + cast( @i as varchar(4) ) + ' = ' + cast( @i as varchar(4) )

      set @in_list = @in_list + ', @p' + cast( @i as varchar(4) )

      set @i = @i + 1

 

end

 

set @sql = @sql + ' as declare @c int; select @c = count(*) from somedata where avalue in ( ' + @in_list + ' )'

 

print @sql

print @sql2

print @in_list

 

exec( @sql )

 

dbcc freeproccache

dbcc dropcleanbuffers

 

set @i = 1

while @i <= 10000

begin

      exec( @sql2 )

      set @i = @i + 1

end

 

print '---------------------------------------------------'

print '---------------------------------------------------'

go

 

dbcc freeproccache

dbcc dropcleanbuffers

 

declare @i int

set @i = 1

while @i <= 10000

begin

      exec getdata_csv '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'

      set @i = @i + 1

end

 

print '---------------------------------------------------'

print '---------------------------------------------------'

go

 

dbcc freeproccache

dbcc dropcleanbuffers

 

declare @i int

set @i = 1

while @i <= 10000

begin

      exec getdata_dynamic '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'

      set @i = @i + 1

end

 

Links to Celko’s rants...

http://groups.google.co.uk/group/microsoft.public.sqlserver.programming/browse_thread/thread/1407cc57fb65d1ac/1006816b3f75e845?lnk=st&q=celko+%221000+parameters%22&rnum=9&hl=en

http://www.google.co.uk/search?hl=en&q=celko+%221000+parameters%22&meta=

Filed under:

Comments

# re: Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Sunday, March 25, 2007 1:47 PM by tonyrogerson

Spot my mistake, the dynamic SQL one uses a cached statement for the IN because a) it never changes and b) SQL doesn't parameterise it; by making the IN list contain a random number I get adhoc plans all over the place - I'm researching the possibility of using a plan guide but that would mean I knew how many items where on the IN - more blog entry to follow.

Anyway, the whole point was the idiotic use of 1,000 parameters to the stored procedure and his statement that its more maintainable etc...

# re: Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Sunday, March 25, 2007 9:17 PM by Phil Factor

Tony,

Well, actually, Joe Celco is not a 'self-styled' SQL guru but a guy who has spent ten yars on the ANSI SQL standards committee. He has written at least four books to my knowledge, and is one of the best-known names in the SQL Community. Unquestioningly, he is a SQL expert, acclaimed by his peers.

I, personally, admire Joe Celco more than any other writer about SQL. I read his books over and over again, for sheer pleasure. I don't always agree with what he writes but I know that Joe loves to take part in a reasoned debate. I have no difficulty in acknowledging him as a SQL Guru, and acknowledge my own debt to him.

I don't think that calling poor Joe a 'self-styled expert' enhances your argument at all.

Phil Factor. Simple-talk

# re: Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Sunday, March 25, 2007 9:33 PM by tonyrogerson

Interesting comment Phil, you obviously haven't done much posting in the public NNTP forums on SQL Server over the past few years.

Celko's bully rantings against anybody who doesn't share his view, mostly beginners doesn't actually measure up to what you'd describe as 'reasoned debate'.

I have no difficulty in acknowledging him as a really good theorist on SQL - that's all; his implementation skills let him down badly and unforunetly his ego does not allow for him to realise that - there are countless occaisons where his solutions produce extremely poor and unscalable solutions - the 1,000 parameter I discuss is just one of many. Unfortunetly the guy doesn't allow for an alternate opinion - all that matters to him is portability and everything else is secondary.

Also, I said 'self-proclaimed', whenever anybody argues against his position he pulls the 'I've been in the industry for 35 years, been on the standards committee....' so how dare you have an opposing view. Afterall, if the guy is such a expert why does he keep dissing the csv / xml solution and recommend people have 50 - 1000 parameters instead?

# re: Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Tuesday, March 27, 2007 9:59 AM by Phil Factor

Joe's contributions on the forums are done in a vituperative style that is a deliberate journalistic affectation. If you take it seriously, you probably believe that Anne Robinson in 'The Weakest Link' is the real Anne Robinson. Joe livens up discussions magnificently and I ame in awe of his talent. He is the salt in the dough on the forums.

I recommend his books as being the authentic Joe. SQL Programming Style is a pleasure to read. He would actually smile on your Dynamic SQL Solution. ('I would use SQL to write SQL Statements. This is a neat trick that is not used enough' he says in Chapter 5 of SQL Puzzles and Answers;  p185).

One thing puzzles me about your timings. You mention XML as a way of passing a large number of parameters. I can't see any timings. I ran some tests and found that XML was much faster than the CSV solution. As one can check, or validate, the XML against an XML Schema, it would seem a much better solution than your Dynamic SQL solution, even if it took longer.

I'd also want to see a procedure that did some real work, so as to simulate the sort of task one might find in the production environment, and I'd worry about all the validation that is required in a production data-feed.

# re: Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead!

Tuesday, March 27, 2007 11:06 AM by tonyrogerson

Phil, please blog your research on the XML, I've done a lot of testing on this at a client who required massive throughput and XML performance was just shocking so we used CSV instead.

You have to watch out for a bug in the optimiser that forces a compilation when using varchar(max) though which maybe what you've hit.

So you condone celko bully boy tatics on newbies on the forums, people who are entering the field, you  etc... celko livens up nothing, he simply insults people.

When I get time I'll finish off the plan guides stuff - I need a method of getting round the adhoc plans being created in the dynamic SQL method.

Probably the best method would be CLR.

Validation - that can be done middle tier side or via relational schema in the database.

# hay day cheats 2014|hay day coins hack|hay day diamonds hack|hay day hack no survey

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead! - Tony Rogerson's ramblings on SQL Server

# Call Of Duty Advanced Warfare Playstation Hack

Wednesday, September 24, 2014 10:24 PM by Call Of Duty Advanced Warfare Playstation Hack

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead! - Tony Rogerson's ramblings on SQL Server

# article source

Tuesday, September 30, 2014 2:45 AM by article source

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead! - Tony Rogerson's ramblings on SQL Server

# http://zion.inode.at/phpinfo.php?a%5B%5D=%3Ca+href%3Dhttp%3A%2F%2Fconfidencegames.com%2Ffifa-15-coin-generator%2F%3Ehttp%3A%2F%2Fconfidencegames.com%2Ffifa-15-coin-generator%2F%3C%2Fa%3E

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead! - Tony Rogerson's ramblings on SQL Server

# http://www.jobs-personalberatung.com/_cms/lib/phpinfo.php?a%5B%5D=%3Ca+href%3Dhttp%3A%2F%2Fconfidencegames.com%2Fdragon-city-hack%2F%3EDragon+City+Hack%3C%2Fa%3E

Joe Celko - Don't use CSV/XML - use 1,000 Parameters instead! - Tony Rogerson's ramblings on SQL Server