1 /// Use a DB via SQL prepared statements. 2 module mysql.prepared; 3 4 import std.algorithm; 5 import std.conv; 6 import std.datetime; 7 import std.exception; 8 import std.range; 9 import std.traits; 10 import std.typecons; 11 import std.variant; 12 13 import mysql.commands; 14 import mysql.connection; 15 import mysql.exceptions; 16 import mysql.protocol.constants; 17 import mysql.protocol.extra_types; 18 import mysql.protocol.packets; 19 import mysql.protocol.packet_helpers; 20 import mysql.protocol.sockets; 21 import mysql.result; 22 import mysql.types; 23 24 /++ 25 A struct to represent specializations of prepared statement parameters. 26 27 Strongly considering the removal of the isNull field, now that Prepared 28 can handle `null` as a value just fine. 29 30 There are two specializations. First you can set an isNull flag to indicate that the 31 parameter is to have the SQL NULL value. 32 33 Second, if you need to send large objects to the database it might be convenient to 34 send them in pieces. These two variables allow for this. If both are provided 35 then the corresponding column will be populated by calling the delegate repeatedly. 36 the source should fill the indicated slice with data and arrange for the delegate to 37 return the length of the data supplied. Af that is less than the chunkSize 38 then the chunk will be assumed to be the last one. 39 +/ 40 struct ParameterSpecialization 41 { 42 import mysql.protocol.constants; 43 44 size_t pIndex; //parameter number 0 - number of params-1 45 SQLType type = SQLType.INFER_FROM_D_TYPE; 46 uint chunkSize; 47 uint delegate(ubyte[]) chunkDelegate; 48 } 49 ///ditto 50 alias PSN = ParameterSpecialization; 51 52 /++ 53 Encapsulation of a prepared statement. 54 55 Commands that are expected to return a result set - queries - have distinctive 56 methods that are enforced. That is it will be an error to call such a method 57 with an SQL command that does not produce a result set. So for commands like 58 SELECT, use the `query` functions. For other commands, like 59 INSERT/UPDATE/CREATE/etc, use `exec`. 60 61 Internally, `Prepared` simply wraps a `PreparedImpl` with 62 $(LINK2 https://dlang.org/phobos/std_typecons.html#.RefCounted, `RefCounted`), 63 and offers access to the `PreparedImpl` members via "alias this". 64 65 See the `PreparedImpl` documentation for the bulk of the `Prepared` interface. 66 +/ 67 struct Prepared 68 { 69 RefCounted!(PreparedImpl, RefCountedAutoInitialize.no) preparedImpl; 70 alias preparedImpl this; 71 72 @property bool isPrepared() pure const 73 { 74 return preparedImpl.refCountedStore.isInitialized && !preparedImpl.isReleased; 75 } 76 } 77 78 /++ 79 Submit an SQL command to the server to be compiled into a prepared statement. 80 81 The result of a successful outcome will be a statement handle - an ID - 82 for the prepared statement, a count of the parameters required for 83 excution of the statement, and a count of the columns that will be present 84 in any result set that the command generates. These values will be stored 85 in the Command struct. 86 87 The server will then proceed to send prepared statement headers, 88 including parameter descriptions, and result set field descriptions, 89 followed by an EOF packet. 90 91 Throws: MySQLException if there are pending result set items, or if the 92 server has a problem. 93 +/ 94 Prepared prepare(Connection conn, string sql) 95 { 96 return Prepared( refCounted(PreparedImpl(conn, sql)) ); 97 } 98 99 /++ 100 Convenience function to create a prepared statement which calls a stored function. 101 102 Throws: MySQLException if there are pending result set items, or if the 103 server has a problem. 104 105 Params: 106 name = The name of the stored function. 107 numArgs = The number of arguments the stored procedure takes. 108 +/ 109 Prepared prepareFunction(Connection conn, string name, int numArgs) 110 { 111 auto sql = "select " ~ name ~ preparedPlaceholderArgs(numArgs); 112 return prepare(conn, sql); 113 } 114 115 /// 116 unittest 117 { 118 debug(MYSQL_INTEGRATION_TESTS) 119 { 120 import mysql.test.common; 121 mixin(scopedCn); 122 123 exec(cn, `DROP FUNCTION IF EXISTS hello`); 124 exec(cn, ` 125 CREATE FUNCTION hello (s CHAR(20)) 126 RETURNS CHAR(50) DETERMINISTIC 127 RETURN CONCAT('Hello ',s,'!') 128 `); 129 130 auto preparedHello = prepareFunction(cn, "hello", 1); 131 preparedHello.setArgs("World"); 132 ResultSet rs = preparedHello.querySet(); 133 assert(rs.length == 1); 134 assert(rs[0][0] == "Hello World!"); 135 } 136 } 137 138 /++ 139 Convenience function to create a prepared statement which calls a stored procedure. 140 141 OUT parameters are currently not supported. It should generally be 142 possible with MySQL to present them as a result set. 143 144 Throws: MySQLException if there are pending result set items, or if the 145 server has a problem. 146 147 Params: 148 name = The name of the stored procedure. 149 numArgs = The number of arguments the stored procedure takes. 150 151 +/ 152 Prepared prepareProcedure(Connection conn, string name, int numArgs) 153 { 154 auto sql = "call " ~ name ~ preparedPlaceholderArgs(numArgs); 155 return prepare(conn, sql); 156 } 157 158 /// 159 unittest 160 { 161 debug(MYSQL_INTEGRATION_TESTS) 162 { 163 import mysql.test.common; 164 import mysql.test.integration; 165 mixin(scopedCn); 166 initBaseTestTables(cn); 167 168 exec(cn, `DROP PROCEDURE IF EXISTS insert2`); 169 exec(cn, ` 170 CREATE PROCEDURE insert2 (IN p1 INT, IN p2 CHAR(50)) 171 BEGIN 172 INSERT INTO basetest (intcol, stringcol) VALUES(p1, p2); 173 END 174 `); 175 176 auto preparedInsert2 = prepareProcedure(cn, "insert2", 2); 177 preparedInsert2.setArgs(2001, "inserted string 1"); 178 preparedInsert2.exec(); 179 180 ResultSet rs = querySet(cn, "SELECT stringcol FROM basetest WHERE intcol=2001"); 181 assert(rs.length == 1); 182 assert(rs[0][0] == "inserted string 1"); 183 } 184 } 185 186 private string preparedPlaceholderArgs(int numArgs) 187 { 188 auto sql = "("; 189 bool comma = false; 190 foreach(i; 0..numArgs) 191 { 192 if (comma) 193 sql ~= ",?"; 194 else 195 { 196 sql ~= "?"; 197 comma = true; 198 } 199 } 200 sql ~= ")"; 201 202 return sql; 203 } 204 205 debug(MYSQL_INTEGRATION_TESTS) 206 unittest 207 { 208 assert(preparedPlaceholderArgs(3) == "(?,?,?)"); 209 assert(preparedPlaceholderArgs(2) == "(?,?)"); 210 assert(preparedPlaceholderArgs(1) == "(?)"); 211 assert(preparedPlaceholderArgs(0) == "()"); 212 } 213 214 /++ 215 This is the internal implementation of `Prepared`. It is not intended to be 216 used directly, as `Prepared` wraps a `PreparedImpl` with 217 $(LINK2 https://dlang.org/phobos/std_typecons.html#.RefCounted, `RefCounted`), 218 and offers access to the public `PreparedImpl` members via "alias this". 219 +/ 220 struct PreparedImpl 221 { 222 private: 223 Connection _conn; 224 string _sql; 225 226 void enforceNotReleased() 227 { 228 enforceNotReleased(_hStmt); 229 } 230 231 static void enforceNotReleased(uint hStmt) 232 { 233 enforceEx!MYXNotPrepared(hStmt); 234 } 235 236 void enforceReadyForCommand() 237 { 238 enforceReadyForCommand(_conn, _hStmt); 239 } 240 241 static void enforceReadyForCommand(Connection conn, uint hStmt) 242 { 243 enforceNotReleased(hStmt); 244 conn.enforceNothingPending(); 245 } 246 247 debug(MYSQL_INTEGRATION_TESTS) 248 unittest 249 { 250 import mysql.prepared; 251 import mysql.test.common; 252 mixin(scopedCn); 253 254 cn.exec("DROP TABLE IF EXISTS `enforceNotReleased`"); 255 cn.exec("CREATE TABLE `enforceNotReleased` ( 256 `val` INTEGER 257 ) ENGINE=InnoDB DEFAULT CHARSET=utf8"); 258 259 immutable insertSQL = "INSERT INTO `enforceNotReleased` VALUES (1), (2)"; 260 immutable selectSQL = "SELECT * FROM `enforceNotReleased`"; 261 Prepared preparedInsert; 262 Prepared preparedSelect; 263 int queryTupleResult; 264 assertNotThrown!MYXNotPrepared(preparedInsert = cn.prepare(insertSQL)); 265 assertNotThrown!MYXNotPrepared(preparedSelect = cn.prepare(selectSQL)); 266 assertNotThrown!MYXNotPrepared(preparedInsert.exec()); 267 assertNotThrown!MYXNotPrepared(preparedSelect.querySet()); 268 assertNotThrown!MYXNotPrepared(preparedSelect.query().each()); 269 assertNotThrown!MYXNotPrepared(preparedSelect.queryRowTuple(queryTupleResult)); 270 271 preparedInsert.release(); 272 assertThrown!MYXNotPrepared(preparedInsert.exec()); 273 assertNotThrown!MYXNotPrepared(preparedSelect.querySet()); 274 assertNotThrown!MYXNotPrepared(preparedSelect.query().each()); 275 assertNotThrown!MYXNotPrepared(preparedSelect.queryRowTuple(queryTupleResult)); 276 277 preparedSelect.release(); 278 assertThrown!MYXNotPrepared(preparedInsert.exec()); 279 assertThrown!MYXNotPrepared(preparedSelect.querySet()); 280 assertThrown!MYXNotPrepared(preparedSelect.query().each()); 281 assertThrown!MYXNotPrepared(preparedSelect.queryRowTuple(queryTupleResult)); 282 } 283 284 @disable this(this); // Not copyable 285 286 /++ 287 Submit an SQL command to the server to be compiled into a prepared statement. 288 289 The result of a successful outcome will be a statement handle - an ID - 290 for the prepared statement, a count of the parameters required for 291 excution of the statement, and a count of the columns that will be present 292 in any result set that the command generates. These values will be stored 293 in the Command struct. 294 295 The server will then proceed to send prepared statement headers, 296 including parameter descriptions, and result set field descriptions, 297 followed by an EOF packet. 298 299 If there is an existing statement handle in the Command struct, that 300 prepared statement is released. 301 302 Throws: MySQLException if there are pending result set items, or if the 303 server has a problem. 304 +/ 305 public this(Connection conn, string sql) 306 { 307 this._conn = conn; 308 this._sql = sql; 309 310 _conn.enforceNothingPending(); 311 312 scope(failure) conn.kill(); 313 314 conn.sendCmd(CommandType.STMT_PREPARE, sql); 315 conn._fieldCount = 0; 316 317 ubyte[] packet = conn.getPacket(); 318 if (packet.front == ResultPacketMarker.ok) 319 { 320 packet.popFront(); 321 _hStmt = packet.consume!int(); 322 conn._fieldCount = packet.consume!short(); 323 _psParams = packet.consume!short(); 324 325 _inParams.length = _psParams; 326 _psa.length = _psParams; 327 328 packet.popFront(); // one byte filler 329 _psWarnings = packet.consume!short(); 330 331 // At this point the server also sends field specs for parameters 332 // and columns if there were any of each 333 _psh = PreparedStmtHeaders(conn, conn._fieldCount, _psParams); 334 } 335 else if(packet.front == ResultPacketMarker.error) 336 { 337 auto error = OKErrorPacket(packet); 338 enforcePacketOK(error); 339 assert(0); // FIXME: what now? 340 } 341 else 342 assert(0); // FIXME: what now? 343 } 344 345 package: 346 uint _hStmt; // Server's identifier for this prepared statement. This is 0 when released. 347 ushort _psParams, _psWarnings; 348 PreparedStmtHeaders _psh; 349 Variant[] _inParams; 350 ParameterSpecialization[] _psa; 351 352 static ubyte[] makeBitmap(in Variant[] inParams) 353 { 354 size_t bml = (inParams.length+7)/8; 355 ubyte[] bma; 356 bma.length = bml; 357 foreach (i; 0..inParams.length) 358 { 359 if(inParams[i].type != typeid(typeof(null))) 360 continue; 361 size_t bn = i/8; 362 size_t bb = i%8; 363 ubyte sr = 1; 364 sr <<= bb; 365 bma[bn] |= sr; 366 } 367 return bma; 368 } 369 370 static ubyte[] makePSPrefix(uint hStmt, ubyte flags = 0) pure nothrow 371 { 372 ubyte[] prefix; 373 prefix.length = 14; 374 375 prefix[4] = CommandType.STMT_EXECUTE; 376 hStmt.packInto(prefix[5..9]); 377 prefix[9] = flags; // flags, no cursor 378 prefix[10] = 1; // iteration count - currently always 1 379 prefix[11] = 0; 380 prefix[12] = 0; 381 prefix[13] = 0; 382 383 return prefix; 384 } 385 386 static ubyte[] analyseParams(Variant[] inParams, ParameterSpecialization[] psa, 387 out ubyte[] vals, out bool longData) 388 { 389 size_t pc = inParams.length; 390 ubyte[] types; 391 types.length = pc*2; 392 size_t alloc = pc*20; 393 vals.length = alloc; 394 uint vcl = 0, len; 395 int ct = 0; 396 397 void reAlloc(size_t n) 398 { 399 if (vcl+n < alloc) 400 return; 401 size_t inc = (alloc*3)/2; 402 if (inc < n) 403 inc = n; 404 alloc += inc; 405 vals.length = alloc; 406 } 407 408 foreach (size_t i; 0..pc) 409 { 410 enum UNSIGNED = 0x80; 411 enum SIGNED = 0; 412 if (psa[i].chunkSize) 413 longData= true; 414 if (inParams[i].type == typeid(typeof(null))) 415 { 416 types[ct++] = SQLType.NULL; 417 types[ct++] = SIGNED; 418 continue; 419 } 420 Variant v = inParams[i]; 421 SQLType ext = psa[i].type; 422 string ts = v.type.toString(); 423 bool isRef; 424 if (ts[$-1] == '*') 425 { 426 ts.length = ts.length-1; 427 isRef= true; 428 } 429 430 switch (ts) 431 { 432 case "bool": 433 if (ext == SQLType.INFER_FROM_D_TYPE) 434 types[ct++] = SQLType.BIT; 435 else 436 types[ct++] = cast(ubyte) ext; 437 types[ct++] = SIGNED; 438 reAlloc(2); 439 bool bv = isRef? *(v.get!(bool*)): v.get!(bool); 440 vals[vcl++] = 1; 441 vals[vcl++] = bv? 0x31: 0x30; 442 break; 443 case "byte": 444 types[ct++] = SQLType.TINY; 445 types[ct++] = SIGNED; 446 reAlloc(1); 447 vals[vcl++] = isRef? *(v.get!(byte*)): v.get!(byte); 448 break; 449 case "ubyte": 450 types[ct++] = SQLType.TINY; 451 types[ct++] = UNSIGNED; 452 reAlloc(1); 453 vals[vcl++] = isRef? *(v.get!(ubyte*)): v.get!(ubyte); 454 break; 455 case "short": 456 types[ct++] = SQLType.SHORT; 457 types[ct++] = SIGNED; 458 reAlloc(2); 459 short si = isRef? *(v.get!(short*)): v.get!(short); 460 vals[vcl++] = cast(ubyte) (si & 0xff); 461 vals[vcl++] = cast(ubyte) ((si >> 8) & 0xff); 462 break; 463 case "ushort": 464 types[ct++] = SQLType.SHORT; 465 types[ct++] = UNSIGNED; 466 reAlloc(2); 467 ushort us = isRef? *(v.get!(ushort*)): v.get!(ushort); 468 vals[vcl++] = cast(ubyte) (us & 0xff); 469 vals[vcl++] = cast(ubyte) ((us >> 8) & 0xff); 470 break; 471 case "int": 472 types[ct++] = SQLType.INT; 473 types[ct++] = SIGNED; 474 reAlloc(4); 475 int ii = isRef? *(v.get!(int*)): v.get!(int); 476 vals[vcl++] = cast(ubyte) (ii & 0xff); 477 vals[vcl++] = cast(ubyte) ((ii >> 8) & 0xff); 478 vals[vcl++] = cast(ubyte) ((ii >> 16) & 0xff); 479 vals[vcl++] = cast(ubyte) ((ii >> 24) & 0xff); 480 break; 481 case "uint": 482 types[ct++] = SQLType.INT; 483 types[ct++] = UNSIGNED; 484 reAlloc(4); 485 uint ui = isRef? *(v.get!(uint*)): v.get!(uint); 486 vals[vcl++] = cast(ubyte) (ui & 0xff); 487 vals[vcl++] = cast(ubyte) ((ui >> 8) & 0xff); 488 vals[vcl++] = cast(ubyte) ((ui >> 16) & 0xff); 489 vals[vcl++] = cast(ubyte) ((ui >> 24) & 0xff); 490 break; 491 case "long": 492 types[ct++] = SQLType.LONGLONG; 493 types[ct++] = SIGNED; 494 reAlloc(8); 495 long li = isRef? *(v.get!(long*)): v.get!(long); 496 vals[vcl++] = cast(ubyte) (li & 0xff); 497 vals[vcl++] = cast(ubyte) ((li >> 8) & 0xff); 498 vals[vcl++] = cast(ubyte) ((li >> 16) & 0xff); 499 vals[vcl++] = cast(ubyte) ((li >> 24) & 0xff); 500 vals[vcl++] = cast(ubyte) ((li >> 32) & 0xff); 501 vals[vcl++] = cast(ubyte) ((li >> 40) & 0xff); 502 vals[vcl++] = cast(ubyte) ((li >> 48) & 0xff); 503 vals[vcl++] = cast(ubyte) ((li >> 56) & 0xff); 504 break; 505 case "ulong": 506 types[ct++] = SQLType.LONGLONG; 507 types[ct++] = UNSIGNED; 508 reAlloc(8); 509 ulong ul = isRef? *(v.get!(ulong*)): v.get!(ulong); 510 vals[vcl++] = cast(ubyte) (ul & 0xff); 511 vals[vcl++] = cast(ubyte) ((ul >> 8) & 0xff); 512 vals[vcl++] = cast(ubyte) ((ul >> 16) & 0xff); 513 vals[vcl++] = cast(ubyte) ((ul >> 24) & 0xff); 514 vals[vcl++] = cast(ubyte) ((ul >> 32) & 0xff); 515 vals[vcl++] = cast(ubyte) ((ul >> 40) & 0xff); 516 vals[vcl++] = cast(ubyte) ((ul >> 48) & 0xff); 517 vals[vcl++] = cast(ubyte) ((ul >> 56) & 0xff); 518 break; 519 case "float": 520 types[ct++] = SQLType.FLOAT; 521 types[ct++] = SIGNED; 522 reAlloc(4); 523 float f = isRef? *(v.get!(float*)): v.get!(float); 524 ubyte* ubp = cast(ubyte*) &f; 525 vals[vcl++] = *ubp++; 526 vals[vcl++] = *ubp++; 527 vals[vcl++] = *ubp++; 528 vals[vcl++] = *ubp; 529 break; 530 case "double": 531 types[ct++] = SQLType.DOUBLE; 532 types[ct++] = SIGNED; 533 reAlloc(8); 534 double d = isRef? *(v.get!(double*)): v.get!(double); 535 ubyte* ubp = cast(ubyte*) &d; 536 vals[vcl++] = *ubp++; 537 vals[vcl++] = *ubp++; 538 vals[vcl++] = *ubp++; 539 vals[vcl++] = *ubp++; 540 vals[vcl++] = *ubp++; 541 vals[vcl++] = *ubp++; 542 vals[vcl++] = *ubp++; 543 vals[vcl++] = *ubp; 544 break; 545 case "std.datetime.Date": 546 types[ct++] = SQLType.DATE; 547 types[ct++] = SIGNED; 548 Date date = isRef? *(v.get!(Date*)): v.get!(Date); 549 ubyte[] da = pack(date); 550 size_t l = da.length; 551 reAlloc(l); 552 vals[vcl..vcl+l] = da[]; 553 vcl += l; 554 break; 555 case "std.datetime.Time": 556 types[ct++] = SQLType.TIME; 557 types[ct++] = SIGNED; 558 TimeOfDay time = isRef? *(v.get!(TimeOfDay*)): v.get!(TimeOfDay); 559 ubyte[] ta = pack(time); 560 size_t l = ta.length; 561 reAlloc(l); 562 vals[vcl..vcl+l] = ta[]; 563 vcl += l; 564 break; 565 case "std.datetime.DateTime": 566 types[ct++] = SQLType.DATETIME; 567 types[ct++] = SIGNED; 568 DateTime dt = isRef? *(v.get!(DateTime*)): v.get!(DateTime); 569 ubyte[] da = pack(dt); 570 size_t l = da.length; 571 reAlloc(l); 572 vals[vcl..vcl+l] = da[]; 573 vcl += l; 574 break; 575 case "connect.Timestamp": 576 types[ct++] = SQLType.TIMESTAMP; 577 types[ct++] = SIGNED; 578 Timestamp tms = isRef? *(v.get!(Timestamp*)): v.get!(Timestamp); 579 DateTime dt = mysql.protocol.packet_helpers.toDateTime(tms.rep); 580 ubyte[] da = pack(dt); 581 size_t l = da.length; 582 reAlloc(l); 583 vals[vcl..vcl+l] = da[]; 584 vcl += l; 585 break; 586 case "immutable(char)[]": 587 if (ext == SQLType.INFER_FROM_D_TYPE) 588 types[ct++] = SQLType.VARCHAR; 589 else 590 types[ct++] = cast(ubyte) ext; 591 types[ct++] = SIGNED; 592 string s = isRef? *(v.get!(string*)): v.get!(string); 593 ubyte[] packed = packLCS(cast(void[]) s); 594 reAlloc(packed.length); 595 vals[vcl..vcl+packed.length] = packed[]; 596 vcl += packed.length; 597 break; 598 case "char[]": 599 if (ext == SQLType.INFER_FROM_D_TYPE) 600 types[ct++] = SQLType.VARCHAR; 601 else 602 types[ct++] = cast(ubyte) ext; 603 types[ct++] = SIGNED; 604 char[] ca = isRef? *(v.get!(char[]*)): v.get!(char[]); 605 ubyte[] packed = packLCS(cast(void[]) ca); 606 reAlloc(packed.length); 607 vals[vcl..vcl+packed.length] = packed[]; 608 vcl += packed.length; 609 break; 610 case "byte[]": 611 if (ext == SQLType.INFER_FROM_D_TYPE) 612 types[ct++] = SQLType.TINYBLOB; 613 else 614 types[ct++] = cast(ubyte) ext; 615 types[ct++] = SIGNED; 616 byte[] ba = isRef? *(v.get!(byte[]*)): v.get!(byte[]); 617 ubyte[] packed = packLCS(cast(void[]) ba); 618 reAlloc(packed.length); 619 vals[vcl..vcl+packed.length] = packed[]; 620 vcl += packed.length; 621 break; 622 case "ubyte[]": 623 if (ext == SQLType.INFER_FROM_D_TYPE) 624 types[ct++] = SQLType.TINYBLOB; 625 else 626 types[ct++] = cast(ubyte) ext; 627 types[ct++] = SIGNED; 628 ubyte[] uba = isRef? *(v.get!(ubyte[]*)): v.get!(ubyte[]); 629 ubyte[] packed = packLCS(cast(void[]) uba); 630 reAlloc(packed.length); 631 vals[vcl..vcl+packed.length] = packed[]; 632 vcl += packed.length; 633 break; 634 case "void": 635 throw new MYX("Unbound parameter " ~ to!string(i), __FILE__, __LINE__); 636 default: 637 throw new MYX("Unsupported parameter type " ~ ts, __FILE__, __LINE__); 638 } 639 } 640 vals.length = vcl; 641 return types; 642 } 643 644 static void sendLongData(Connection conn, uint hStmt, ParameterSpecialization[] psa) 645 { 646 assert(psa.length <= ushort.max); // parameter number is sent as short 647 foreach (ushort i, PSN psn; psa) 648 { 649 if (!psn.chunkSize) continue; 650 uint cs = psn.chunkSize; 651 uint delegate(ubyte[]) dg = psn.chunkDelegate; 652 653 ubyte[] chunk; 654 chunk.length = cs+11; 655 chunk.setPacketHeader(0 /*each chunk is separate cmd*/); 656 chunk[4] = CommandType.STMT_SEND_LONG_DATA; 657 hStmt.packInto(chunk[5..9]); // statement handle 658 packInto(i, chunk[9..11]); // parameter number 659 660 // byte 11 on is payload 661 for (;;) 662 { 663 uint sent = dg(chunk[11..cs+11]); 664 if (sent < cs) 665 { 666 if (sent == 0) // data was exact multiple of chunk size - all sent 667 break; 668 sent += 7; // adjust for non-payload bytes 669 chunk.length = chunk.length - (cs-sent); // trim the chunk 670 packInto!(uint, true)(cast(uint)sent, chunk[0..3]); 671 conn.send(chunk); 672 break; 673 } 674 conn.send(chunk); 675 } 676 } 677 } 678 679 static void sendCommand(Connection conn, uint hStmt, PreparedStmtHeaders psh, 680 Variant[] inParams, ParameterSpecialization[] psa) 681 { 682 ubyte[] packet; 683 conn.resetPacket(); 684 685 ubyte[] prefix = makePSPrefix(hStmt, 0); 686 size_t len = prefix.length; 687 bool longData; 688 689 if (psh.paramCount) 690 { 691 ubyte[] one = [ 1 ]; 692 ubyte[] vals; 693 ubyte[] types = analyseParams(inParams, psa, vals, longData); 694 ubyte[] nbm = makeBitmap(inParams); 695 packet = prefix ~ nbm ~ one ~ types ~ vals; 696 } 697 else 698 packet = prefix; 699 700 if (longData) 701 sendLongData(conn, hStmt, psa); 702 703 assert(packet.length <= uint.max); 704 packet.setPacketHeader(conn.pktNumber); 705 conn.bumpPacket(); 706 conn.send(packet); 707 } 708 709 //TODO: This awkward func is only needed by the deprecated Command struct. 710 // Remove this once Command struct is finally deleted. 711 bool execQueryImpl2(out ulong ra) 712 { 713 return execQueryImpl(_conn, 714 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa), ra); 715 } 716 717 /// Has this statement been released? 718 @property bool isReleased() pure const nothrow 719 { 720 return _hStmt == 0; 721 } 722 723 public: 724 ~this() 725 { 726 release(); 727 } 728 729 /++ 730 Execute a prepared command, such as INSERT/UPDATE/CREATE/etc. 731 732 This method is intended for commands which do not produce a result set 733 (otherwise, use one of the query functions instead.) If the SQL command does 734 produces a result set (such as SELECT), `mysql.exceptions.MySQLResultRecievedException` 735 will be thrown. 736 737 Returns: The number of rows affected. 738 +/ 739 ulong exec() 740 { 741 enforceReadyForCommand(); 742 return execImpl( 743 _conn, 744 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa) 745 ); 746 } 747 748 /++ 749 Execute a prepared SQL SELECT command where you expect the entire 750 result set all at once. 751 752 This is being considered for deprecation in a future release of mysql-native, 753 because the same thing can be achieved via `query`(). 754 $(LINK2 https://dlang.org/phobos/std_array.html#array, `array()`). 755 756 If the SQL command does not produce a result set (such as INSERT/CREATE/etc), 757 then `mysql.exceptions.MySQLNoResultRecievedException` will be thrown. Use 758 `exec` instead for such commands. 759 760 If there are long data items among the expected result columns you can use 761 the csa param to specify that they are to be subject to chunked transfer via a 762 delegate. 763 764 Params: csa = An optional array of ColumnSpecialization structs. 765 Returns: A (possibly empty) ResultSet. 766 +/ 767 ResultSet querySet(ColumnSpecialization[] csa = null) 768 { 769 enforceReadyForCommand(); 770 return querySetImpl( 771 csa, true, _conn, 772 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa) 773 ); 774 } 775 776 ///ditto 777 deprecated("Use querySet instead.") 778 alias queryResult = querySet; 779 780 /++ 781 Execute a prepared SQL SELECT command where you want to deal with the 782 result set one row at a time. 783 784 If you need random access to the resulting Row elements, 785 simply call $(LINK2 https://dlang.org/phobos/std_array.html#array, `std.array.array()`) 786 on the result. 787 788 If the SQL command does not produce a result set (such as INSERT/CREATE/etc), 789 then `mysql.exceptions.MySQLNoResultRecievedException` will be thrown. Use 790 `exec` instead for such commands. 791 792 If there are long data items among the expected result columns you can use 793 the csa param to specify that they are to be subject to chunked transfer via a 794 delegate. 795 796 Params: csa = An optional array of ColumnSpecialization structs. 797 Returns: A (possibly empty) ResultRange. 798 +/ 799 ResultRange query(ColumnSpecialization[] csa = null) 800 { 801 enforceReadyForCommand(); 802 return queryImpl( 803 csa, _conn, 804 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa) 805 ); 806 } 807 808 ///ditto 809 deprecated("Use query instead.") 810 alias querySequence = query; 811 812 /++ 813 Execute a prepared SQL SELECT command where you only want the first Row (if any). 814 815 If the SQL command does not produce a result set (such as INSERT/CREATE/etc), 816 then `mysql.exceptions.MySQLNoResultRecievedException` will be thrown. Use 817 `exec` instead for such commands. 818 819 If there are long data items among the expected result columns you can use 820 the csa param to specify that they are to be subject to chunked transfer via a 821 delegate. 822 823 Params: csa = An optional array of ColumnSpecialization structs. 824 Returns: Nullable!Row: This will be null (check via Nullable.isNull) if the 825 query resulted in an empty result set. 826 +/ 827 Nullable!Row queryRow(ColumnSpecialization[] csa = null) 828 { 829 enforceReadyForCommand(); 830 return queryRowImpl(csa, _conn, 831 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa)); 832 } 833 834 /++ 835 Execute a prepared SQL SELECT command where you only want the first Row, and 836 place result values into a set of D variables. 837 838 This method will throw if any column type is incompatible with the corresponding D variable. 839 840 Unlike the other query functions, queryRowTuple will throw 841 `mysql.exceptions.MySQLException` if the result set is empty 842 (and thus the reference variables passed in cannot be filled). 843 844 If the SQL command does not produce a result set (such as INSERT/CREATE/etc), 845 then `mysql.exceptions.MySQLNoResultRecievedException` will be thrown. Use 846 `exec` instead for such commands. 847 848 Params: args = A tuple of D variables to receive the results. 849 +/ 850 void queryRowTuple(T...)(ref T args) 851 { 852 enforceReadyForCommand(); 853 return queryRowTupleImpl( 854 _conn, 855 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa), 856 args 857 ); 858 } 859 860 ///ditto 861 deprecated("Use queryRowTuple instead.") 862 alias queryTuple = queryRowTuple; 863 864 /++ 865 Execute a prepared SQL SELECT command and returns a single value, 866 the first column of the first row received. 867 868 If the query did not produce any rows, OR the rows it produced have zero columns, 869 this will return `Nullable!Variant()`, ie, null. Test for this with `result.isNull`. 870 871 If the query DID produce a result, but the value actually received is NULL, 872 then `result.isNull` will be FALSE, and `result.get` will produce a Variant 873 which CONTAINS null. Check for this with `result.get.type == typeid(typeof(null))`. 874 875 If the SQL command does not produce a result set (such as INSERT/CREATE/etc), 876 then `mysql.exceptions.MySQLNoResultRecievedException` will be thrown. Use 877 `exec` instead for such commands. 878 879 If there are long data items among the expected result columns you can use 880 the csa param to specify that they are to be subject to chunked transfer via a 881 delegate. 882 883 Params: csa = An optional array of ColumnSpecialization structs. 884 Returns: Nullable!Variant: This will be null (check via Nullable.isNull) if the 885 query resulted in an empty result set. 886 +/ 887 Nullable!Variant queryValue(ColumnSpecialization[] csa = null) 888 { 889 return queryValueImpl(csa, _conn, 890 ExecQueryImplInfo(true, null, _hStmt, _psh, _inParams, _psa)); 891 } 892 893 /++ 894 Prepared statement parameter setter. 895 896 The value may, but doesn't have to be, wrapped in a Variant. If so, 897 null is handled correctly. 898 899 The value may, but doesn't have to be, a pointer to the desired value. 900 901 The value may, but doesn't have to be, wrapped in a Nullable!T. If so, 902 null is handled correctly. 903 904 The value can be null. 905 906 Params: index = The zero based index 907 +/ 908 void setArg(T)(size_t index, T val, ParameterSpecialization psn = PSN(0, SQLType.INFER_FROM_D_TYPE, 0, null)) 909 if(!isInstanceOf!(Nullable, T)) 910 { 911 // Now in theory we should be able to check the parameter type here, since the 912 // protocol is supposed to send us type information for the parameters, but this 913 // capability seems to be broken. This assertion is supported by the fact that 914 // the same information is not available via the MySQL C API either. It is up 915 // to the programmer to ensure that appropriate type information is embodied 916 // in the variant array, or provided explicitly. This sucks, but short of 917 // having a client side SQL parser I don't see what can be done. 918 919 enforceNotReleased(); 920 enforceEx!MYX(index < _psParams, "Parameter index out of range."); 921 922 _inParams[index] = val; 923 psn.pIndex = index; 924 _psa[index] = psn; 925 } 926 927 void setArg(T)(size_t index, Nullable!T val, ParameterSpecialization psn = PSN(0, SQLType.INFER_FROM_D_TYPE, 0, null)) 928 { 929 enforceNotReleased(); 930 if(val.isNull) 931 setArg(index, null, psn); 932 else 933 setArg(index, val.get(), psn); 934 } 935 936 /++ 937 Bind a tuple of D variables to the parameters of a prepared statement. 938 939 You can use this method to bind a set of variables if you don't need any specialization, 940 that is chunked transfer is not neccessary. 941 942 The tuple must match the required number of parameters, and it is the programmer's 943 responsibility to ensure that they are of appropriate types. 944 +/ 945 void setArgs(T...)(T args) 946 if(T.length == 0 || !is(T[0] == Variant[])) 947 { 948 enforceNotReleased(); 949 enforceEx!MYX(args.length == _psParams, "Argument list supplied does not match the number of parameters."); 950 951 foreach (size_t i, arg; args) 952 setArg(i, arg); 953 } 954 955 /++ 956 Bind a Variant[] as the parameters of a prepared statement. 957 958 You can use this method to bind a set of variables in Variant form to 959 the parameters of a prepared statement. 960 961 Parameter specializations can be added if required. This method could be 962 used to add records from a data entry form along the lines of 963 ------------ 964 auto c = Command(con, "insert into table42 values(?, ?, ?)"); 965 c.prepare(); 966 Variant[] va; 967 va.length = 3; 968 DataRecord dr; // Some data input facility 969 ulong ra; 970 do 971 { 972 dr.get(); 973 va[0] = dr("Name"); 974 va[1] = dr("City"); 975 va[2] = dr("Whatever"); 976 c.bindParameters(va); 977 c.execPrepared(ra); 978 } while(tod < "17:30"); 979 ------------ 980 Params: va = External list of Variants to be used as parameters 981 psnList = any required specializations 982 +/ 983 void setArgs(Variant[] va, ParameterSpecialization[] psnList= null) 984 { 985 enforceNotReleased(); 986 enforceEx!MYX(va.length == _psParams, "Param count supplied does not match prepared statement"); 987 _inParams[] = va[]; 988 if (psnList !is null) 989 { 990 foreach (PSN psn; psnList) 991 _psa[psn.pIndex] = psn; 992 } 993 } 994 995 /++ 996 Prepared statement parameter getter. 997 998 Params: index = The zero based index 999 +/ 1000 Variant getArg(size_t index) 1001 { 1002 enforceNotReleased(); 1003 enforceEx!MYX(index < _psParams, "Parameter index out of range."); 1004 return _inParams[index]; 1005 } 1006 1007 /++ 1008 Sets a prepared statement parameter to NULL. 1009 1010 This is here mainly for legacy reasons. You can set a field to null 1011 simply by saying `prepared.setArg(index, null);` 1012 1013 Params: index = The zero based index 1014 +/ 1015 void setNullArg(size_t index) 1016 { 1017 enforceNotReleased(); 1018 setArg(index, null); 1019 } 1020 1021 /// Gets the SQL command for this prepared statement 1022 string sql() 1023 { 1024 return _sql; 1025 } 1026 1027 debug(MYSQL_INTEGRATION_TESTS) 1028 unittest 1029 { 1030 import mysql.prepared; 1031 import mysql.test.common; 1032 mixin(scopedCn); 1033 1034 cn.exec("DROP TABLE IF EXISTS `setNullArg`"); 1035 cn.exec("CREATE TABLE `setNullArg` ( 1036 `val` INTEGER 1037 ) ENGINE=InnoDB DEFAULT CHARSET=utf8"); 1038 1039 immutable insertSQL = "INSERT INTO `setNullArg` VALUES (?)"; 1040 immutable selectSQL = "SELECT * FROM `setNullArg`"; 1041 auto preparedInsert = cn.prepare(insertSQL); 1042 assert(preparedInsert.sql == insertSQL); 1043 ResultSet rs; 1044 1045 { 1046 Nullable!int nullableInt; 1047 nullableInt.nullify(); 1048 preparedInsert.setArg(0, nullableInt); 1049 assert(preparedInsert.getArg(0).type == typeid(typeof(null))); 1050 nullableInt = 7; 1051 preparedInsert.setArg(0, nullableInt); 1052 assert(preparedInsert.getArg(0) == 7); 1053 1054 nullableInt.nullify(); 1055 preparedInsert.setArgs(nullableInt); 1056 assert(preparedInsert.getArg(0).type == typeid(typeof(null))); 1057 nullableInt = 7; 1058 preparedInsert.setArgs(nullableInt); 1059 assert(preparedInsert.getArg(0) == 7); 1060 } 1061 1062 preparedInsert.setArg(0, 5); 1063 preparedInsert.exec(); 1064 rs = cn.querySet(selectSQL); 1065 assert(rs.length == 1); 1066 assert(rs[0][0] == 5); 1067 1068 preparedInsert.setArg(0, null); 1069 preparedInsert.exec(); 1070 rs = cn.querySet(selectSQL); 1071 assert(rs.length == 2); 1072 assert(rs[0][0] == 5); 1073 assert(rs[1].isNull(0)); 1074 assert(rs[1][0].type == typeid(typeof(null))); 1075 1076 preparedInsert.setArg(0, Variant(null)); 1077 preparedInsert.exec(); 1078 rs = cn.querySet(selectSQL); 1079 assert(rs.length == 3); 1080 assert(rs[0][0] == 5); 1081 assert(rs[1].isNull(0)); 1082 assert(rs[2].isNull(0)); 1083 assert(rs[1][0].type == typeid(typeof(null))); 1084 assert(rs[2][0].type == typeid(typeof(null))); 1085 } 1086 1087 /++ 1088 Release a prepared statement. 1089 1090 This method tells the server that it can dispose of the information it 1091 holds about the current prepared statement. 1092 +/ 1093 void release() 1094 { 1095 if(!_hStmt) 1096 return; 1097 1098 scope(failure) _conn.kill(); 1099 1100 ubyte[] packet; 1101 packet.length = 9; 1102 packet.setPacketHeader(0/*packet number*/); 1103 _conn.bumpPacket(); 1104 packet[4] = CommandType.STMT_CLOSE; 1105 _hStmt.packInto(packet[5..9]); 1106 _conn.purgeResult(); 1107 _conn.send(packet); 1108 // It seems that the server does not find it necessary to send a response 1109 // for this command. 1110 _hStmt = 0; 1111 } 1112 1113 /// Gets the number of arguments this prepared statement expects to be passed in. 1114 @property ushort numArgs() pure const nothrow 1115 { 1116 return _psParams; 1117 } 1118 1119 /// Gets the prepared header's field descriptions. 1120 @property FieldDescription[] preparedFieldDescriptions() pure { return _psh.fieldDescriptions; } 1121 1122 /// Gets the prepared header's param descriptions. 1123 @property ParamDescription[] preparedParamDescriptions() pure { return _psh.paramDescriptions; } 1124 }