MySQL PHP Transaction
My students liked the MySQL Transaction post but wanted one that showed how an external web application would interact with MySQL in the scope of a transaction. So, I put a little PHP function together that write across two related tables in the context of a transaction. It uses mysqli (MySQL Improved Extension) to connect PHP to the MySQL database.
The function is barebones and uses the oldest approach of hidden inputs to maintain context between rendered forms using an HTML POST method. The hidden inputs are preceded with “h_” and snake case is used for variable names.
The function only writes to two tables. It writes to the member table and when that completes successfully to the contact table. The function:
- Submits credentials from a file and raises an error when they don’t work.
- Initializes a SQL statement.
- Disables auto commit.
- Starts a transaction.
- Defines a first SQL statement with placeholders.
- Binds local variables to the first SQL statement’s placeholders.
- Rolls back the transaction when the first statement fails and continues to the next SQL statement when first statement succeeds.
- Defines a second SQL statement with placeholders.
- Binds local variables to the second SQL statement’s placeholders.
- Rolls back the transaction when the second statement fails and commits the work when the second statement succeeds.
- Closes a SQL statement.
The code for the PHP function is:
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 | /* || Function Name: update_membership || ---------------------------------------------------------------------- || No return, treated as a procedure, or method returning a void. || ---------------------------------------------------------------------- */ function update_membership( $h_account_number , $h_member_type , $h_credit_card_number , $h_credit_card_type , $account_number , $member_type , $credit_card_number , $credit_card_type , $h_first_name , $h_middle_name , $h_last_name , $h_contact_type , $first_name , $middle_name , $last_name , $contact_type) { // Include the credentials file if omitted. include_once("MySQLCredentials.inc"); // Assign credentials to connection. $mysqli = new mysqli(HOSTNAME, USERNAME, PASSWORD, DATABASE); // Check for connection error and print message. if ($mysqli->connect_errno) { print $mysqli->connect_error."<br />"; print "Connection not established ...<br />"; } else { // Initial statement. $stmt = $mysqli->stmt_init(); // Disable auto commit when you want two plus statements run. $mysqli->autocommit(FALSE); // Set the transaction guarantee. $mysqli->begin_transaction(MYSQLI_TRANS_START_READ_WRITE); // Declare a static query. $sql = "UPDATE member\n" . "SET member_type = ?\n" . ", credit_card_number = ?\n" . ", credit_card_type = ?\n" . "WHERE account_number = ?\n" . "AND member_type = ?\n" . "AND credit_card_number = ?\n" . "AND credit_card_type = ?\n"; // Prepare statement. if ($stmt->prepare($sql)) { $stmt->bind_param( "sssssss" , $member_type , $credit_card_number , $credit_card_type , $account_number , $h_member_type , $h_credit_card_number , $h_credit_card_type); } // Attempt query and exit with failure before processing. if (!$stmt->execute()) { // Rollback or undo the transaction. $mysqli->rollback(); // Print failure to resolve query message. print $mysqli->error."<br />\n"; print "Failed to resolve query ...<br />\n"; } // Declare a static query. $sql = "UPDATE contact\n" . "SET first_name = ?\n" . ", middle_name = ?\n" . ", last_name = ?\n" . ", contact_type = ?\n" . "WHERE first_name = ?\n" . "AND middle_name = ?\n" . "AND last_name = ?\n" . "AND contact_type = ?\n"; // Prepare statement. if ($stmt->prepare($sql)) { $stmt->bind_param( "ssssssss" , $first_name , $middle_name , $last_name , $contact_type , $h_first_name , $h_middle_name , $h_last_name , $h_contact_type); } // Attempt query and exit with failure before processing. if (!$stmt->execute()) { // Rollback or undo the transaction. $mysqli->rollback(); // Print failure to resolve query message. print $mysqli->error."<br />"; print "Failed to resolve query ...<br />"; } else { /* Manually commiting writes when you have disabled the || default auto commit setting, explained above. || ------------------------------------------------------------ || You would add the following command to commit the || transaction. || ------------------------------ || $mysqli->commit(); || ------------------------------------------------------------ */ $mysqli->commit(); // Close the transaction. $mysqli->close(); } } } |
Line 41 disables auto commit and line 44 starts the transaction. Each statement is managed with the subsequent statement nested inside a block of code that is only reachable when the prior statement succeeds. While this only uses the member and contact table, it could use any number of tables. The natural alternative is building an updatable view.
As always, I hope this helps anybody looking for a code complete example.