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