File: prepared_statement.cpp

package info (click to toggle)
mysql-connector-c%2B%2B 1.1.12-4
  • links: PTS, VCS
  • area: main
  • in suites: bookworm, bullseye
  • size: 4,904 kB
  • sloc: cpp: 44,895; ansic: 2,114; php: 528; sql: 403; xml: 109; sh: 33; makefile: 11
file content (342 lines) | stat: -rw-r--r-- 13,237 bytes parent folder | download | duplicates (2)
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
/*
 * Copyright (c) 2008, 2018, Oracle and/or its affiliates. All rights reserved.
 *
 * This program is free software; you can redistribute it and/or modify
 * it under the terms of the GNU General Public License, version 2.0, as
 * published by the Free Software Foundation.
 *
 * This program is also distributed with certain software (including
 * but not limited to OpenSSL) that is licensed under separate terms,
 * as designated in a particular file or component or in included license
 * documentation.  The authors of MySQL hereby grant you an
 * additional permission to link the program and your derivative works
 * with the separately licensed software that they have included with
 * MySQL.
 *
 * Without limiting anything contained in the foregoing, this file,
 * which is part of MySQL Connector/C++, is also subject to the
 * Universal FOSS Exception, version 1.0, a copy of which can be found at
 * http://oss.oracle.com/licenses/universal-foss-exception.
 *
 * This program is distributed in the hope that it will be useful, but
 * WITHOUT ANY WARRANTY; without even the implied warranty of
 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE.
 * See the GNU General Public License, version 2.0, for more details.
 *
 * You should have received a copy of the GNU General Public License
 * along with this program; if not, write to the Free Software Foundation, Inc.,
 * 51 Franklin St, Fifth Floor, Boston, MA 02110-1301  USA
 */



/**
* Example of statements - not to be confused with prepared statements
*
* NOTE: The MySQL Server does not support each and every SQL statement
* to be prepared. The list of statements which can be prepared is available
* in the MySQL Server documentation and the C API documentation:
* http://dev.mysql.com/doc/refman/5.1/en/c-api-prepared-statements.html
* (Link to the MySQL Server 5.1 documentation!)
*
* Connector/C++ is based on the C API and C library "libmysql". Therefore
* it inherits all limitations from the MySQL Server and the MySQL C API.
*
* MySQL 5.1.12 can prepare the following statements:
*
* - CREATE TABLE, DELETE, DO, INSERT, REPLACE, SELECT, SET, UPDATE
* - most SHOW commands
* - ANALYZE TABLE, OPTIMIZE TABLE, REPAIR TABLE
* - CACHE INDEX, CHANGE MASTER, CHECKSUM {TABLE | TABLES},
* - {CREATE | RENAME | DROP} DATABASE, {CREATE | RENAME | DROP} USER
* - FLUSH {TABLE | TABLES | TABLES WITH READ LOCK | HOSTS | PRIVILEGES | LOGS | STATUS | MASTER | SLAVE | DES_KEY_FILE | USER_RESOURCES}
* - GRANT, REVOKE, KILL, LOAD INDEX INTO CACHE, RESET {MASTER | SLAVE | QUERY CACHE}
* - SHOW BINLOG EVENTS, SHOW CREATE {PROCEDURE | FUNCTION | EVENT | TABLE | VIEW}
* - SHOW {AUTHORS | CONTRIBUTORS | WARNINGS | ERRORS}
* - SHOW {MASTER | BINARY} LOGS, SHOW {MASTER | SLAVE} STATUS
* - SLAVE {START | STOP}, INSTALL PLUGIN, UNINSTALL PLUGIN
*
*  ... that's pretty much every *core* SQL statement - but not USE as you'll see below.
*
* Connector/C++ does not include a prepared statement emulation
*
* @link http://dev.mysql.com/doc/refman/5.1/en/c-api-prepared-statements.html
*/

/* Standard C++ includes */
#include <stdlib.h>
#include <iostream>
#include <sstream>
#include <stdexcept>

#include <boost/scoped_ptr.hpp>

/*
  Public interface of the MySQL Connector/C++.
  You might not use it but directly include directly the different
  headers from cppconn/ and mysql_driver.h + mysql_util.h
  (and mysql_connection.h). This will reduce your build time!
*/
#include <driver/mysql_public_iface.h>
/* Connection parameter and sample data */
#include "examples.h"

bool prepare_execute(boost::scoped_ptr< sql::Connection > & con, const char *sql);
sql::Statement* emulate_prepare_execute(boost::scoped_ptr< sql::Connection > & con, const char *sql);

using namespace std;

int main(int argc, const char **argv)
{
  static const string url(argc >= 2 ? argv[1] : EXAMPLE_HOST);
  static const string user(argc >= 3 ? argv[2] : EXAMPLE_USER);
  static const string pass(argc >= 4 ? argv[3] : EXAMPLE_PASS);
  static const string database(argc >= 5 ? argv[4] : EXAMPLE_DB);

  /* Driver Manager */
  sql::Driver *driver;
  /* sql::ResultSet.rowsCount() returns size_t */
  size_t row;
  stringstream sql;
  stringstream msg;
  int i, num_rows;

  cout << boolalpha;
  cout << "1..1" << endl;;
  cout << "# Connector/C++ prepared statement example.." << endl;

  try {
    /* Using the Driver to create a connection */
    driver = sql::mysql::get_driver_instance();
    boost::scoped_ptr< sql::Connection > con(driver->connect(url, user, pass));

    /* The usage of USE is not supported by the prepared statement protocol */
    boost::scoped_ptr< sql::Statement > stmt(con->createStatement());
    stmt->execute("USE " + database);

    /*
    Prepared statement are unhandy for queries which you execute only once!

    prepare() will send your SQL statement to the server. The server
    will do a SQL syntax check, perform some static rewriting like eliminating
    dead expressions such as "WHERE 1=1" and simplify expressions
    like "WHERE a > 1 AND a > 2" to "WHERE a > 2". Then control gets back
    to the client and the server waits for execute() (or close()).
    On execute() another round trip to the server is done.

    In case you execute your prepared statement only once - like shown below -
    you get two round trips. But using "simple" statements - like above - means
    only one round trip.

    Therefore, the below is *bad* style. WARNING: Although its *bad* style,
    the example program will continue to do it to demonstrate the (ab)use of
    prepared statements (and to prove that you really can do more than SELECT with PS).
    */
    boost::scoped_ptr< sql::PreparedStatement > prep_stmt(con->prepareStatement("DROP TABLE IF EXISTS test"));
    prep_stmt->execute();

    prepare_execute(con, "CREATE TABLE test(id INT NOT NULL AUTO_INCREMENT PRIMARY KEY, label CHAR(1))");
    cout << "#\t Test table created" << endl;

    /*
    The first useful example - prepare() once, execute() n + 1 times
    NOTE: The MySQL Server does not support named parameters. You have to use
    the placeholder syntax shown below. There is no emulation which would you
    allow to use named parameter like ':param1'. Use '?'. Parameters are 1-based.
    */
    num_rows = 0;
    prep_stmt.reset(con->prepareStatement("INSERT INTO test(id, label) VALUES (?, ?)"));
    for (i = 0; i < EXAMPLE_NUM_TEST_ROWS; i++) {
      prep_stmt->setInt(1, test_data[i].id);
      prep_stmt->setString(2, test_data[i].label);
      /* executeUpdate() returns the number of affected = inserted rows */
      num_rows += prep_stmt->executeUpdate();
    }

    if (EXAMPLE_NUM_TEST_ROWS != num_rows) {
      msg.str("");
      msg << "Expecting " << EXAMPLE_NUM_TEST_ROWS << "rows, reported " << num_rows;
      throw runtime_error(msg.str());
    }
    cout << "#\t Test table populated" << endl;

    /* We will reuse the SELECT a bit later... */
    boost::scoped_ptr< sql::PreparedStatement > prep_select(con->prepareStatement("SELECT id, label FROM test ORDER BY id ASC"));
    cout << "#\t Running 'SELECT id, label FROM test ORDER BY id ASC'" << endl;
    boost::scoped_ptr< sql::ResultSet > res(prep_select->executeQuery());
    row = 0;
    while (res->next()) {
      cout << "#\t\t Row " << row << " - id = " << res->getInt("id");
      cout << ", label = '" << res->getString("label") << "'" << endl;
      row++;
    }
    res.reset(NULL);

    if (EXAMPLE_NUM_TEST_ROWS != row) {
      msg.str("");
      msg << "Expecting " << EXAMPLE_NUM_TEST_ROWS << "rows, reported " << row;
      throw runtime_error(msg.str());
    }

    cout << "#\t Simple PS 'emulation' for USE and another SELECT" << endl;
    stmt.reset(emulate_prepare_execute(con, string("USE " + database).c_str()));
    stmt.reset(emulate_prepare_execute(con, string("USE " + database).c_str()));

    stmt.reset(emulate_prepare_execute(con, "SELECT id FROM test ORDER BY id ASC"));
    res.reset(stmt->getResultSet());
    if (res.get() != NULL) {
      row = 0;
      while (res->next()) {
        cout << "#\t\t Row " << row << " - id = " << res->getInt("id") << endl;
        row++;
      }
      res.reset(NULL);
    }
    stmt.reset(NULL);

    /* Running the SELECT again but fetching in reverse order */
    cout << "#\t SELECT and fetching in reverse order" << endl;

    res.reset(prep_select->executeQuery());
    row = res->rowsCount();
    cout << "#\t\t res->getRowsCount() = " << res->rowsCount() << endl;
    if (res->rowsCount() != EXAMPLE_NUM_TEST_ROWS) {
      msg.str("");
      msg << "Expecting " << EXAMPLE_NUM_TEST_ROWS << "rows, found " << res->rowsCount();
      throw runtime_error(msg.str());
    }

    /* Position the cursor after the last row */
    cout << "#\t\t Position the cursor after the last row\n";
    res->afterLast();
    cout << "#\t\t res->isafterLast()\t= " << res->isAfterLast() << endl;
    cout << "#\t\t res->isLast()\t\t= " << res->isLast() << endl;
    if (!res->isAfterLast() || res->isLast())
      throw runtime_error("Moving the cursor after the last row failed");

    while (res->previous()) {
      cout << "#\t\t res->previous()\n";
      cout << "#\t\t Row " << row << " - id = " << res->getInt("id");
      cout << ", label = '" << res->getString("label") << "'" << endl;
      row--;
    }
    cout << "#\t\t Should be before the first\n";
    cout << "#\t\t res->isFirst()\t\t= " << res->isFirst() << endl;
    cout << "#\t\t res->isBeforeFirst()\t= " << res->isBeforeFirst() << endl;
    if (res->isFirst() || !res->isBeforeFirst())
      throw runtime_error("Cursor should be before first row");

    /* Now that the cursor is before the first, fetch the first */
    cout << "#\t\t Now that the cursor is before the first, fetch the first\n";
    cout << "#\t\t calling next() to fetch first row" << endl;
    row++;
    res->next();
    cout << "#\t\t res->isFirst()\t\t= " << res->isFirst() << endl;
    cout << "#\t\t Row " << row << " - id = " << res->getInt("id");
    cout << ", label = '" << res->getString("label") << "'" << endl;
    row--;

    /* For more on cursors see resultset.cpp example */

    /* Clean up */
    res.reset(NULL);
    stmt.reset(con->createStatement());
    stmt->execute("DROP TABLE IF EXISTS test");
    cout << "#done!" << endl;

  } catch (sql::SQLException &e) {
    /*
    The MySQL Connector/C++ throws three different exceptions:

    - sql::MethodNotImplementedException (derived from sql::SQLException)
    - sql::InvalidArgumentException (derived from sql::SQLException)
    - sql::SQLException (derived from std::runtime_error)
    */
    cout << endl;
    cout << "# ERR: DbcException in " << __FILE__;
    cout << "(" << EXAMPLE_FUNCTION << ") on line " << __LINE__ << endl;
    /* Use what(), getErrorCode() and getSQLState() */
    cout << "# ERR: " << e.what();
    cout << " (MySQL error code: " << e.getErrorCode();
    cout << ", SQLState: " << e.getSQLState() << " )" << endl;

    if (e.getErrorCode() == 1047) {
      /*
      Error: 1047 SQLSTATE: 08S01 (ER_UNKNOWN_COM_ERROR)
      Message: Unknown command
      */
      cout << "# ERR: Your server seems not to support PS at all because its MYSQL <4.1" << endl;
    }
    cout << "not ok 1 - examples/prepared_statement.cpp" << endl;

    return EXIT_FAILURE;
  } catch (std::runtime_error &e) {

    cout << endl;
    cout << "# ERR: runtime_error in " << __FILE__;
    cout << "(" << EXAMPLE_FUNCTION << ") on line " << __LINE__ << endl;
    cout << "# ERR: " << e.what() << endl;
    cout << "not ok 1 - examples/prepared_statement.cpp" << endl;

    return EXIT_FAILURE;
  }

  cout << "ok 1 - examples/prepared_statement.cpp" << endl;
  return EXIT_SUCCESS;
}


bool prepare_execute(boost::scoped_ptr< sql::Connection > & con, const char *sql)
{
  sql::PreparedStatement * prep_stmt;

  prep_stmt = con->prepareStatement(sql);
  prep_stmt->execute();
  delete prep_stmt;

  return true;
}


sql::Statement* emulate_prepare_execute(boost::scoped_ptr< sql::Connection > & con, const char *sql)
{
  sql::PreparedStatement *prep_stmt;
  sql::Statement *stmt = NULL;

  cout << "#\t\t 'emulation': " << sql << endl;

  try {

    prep_stmt = con->prepareStatement(sql);
    prep_stmt->execute();
    cout << "#\t\t 'emulation': use of sql::PreparedStatement possible" << endl;
    /* safe upcast - PreparedStatement is derived from Statement */
    stmt = prep_stmt;

  } catch (sql::SQLException &e) {
    /*
    Maybe the command is not supported by the MySQL Server?

    http://dev.mysql.com/doc/refman/5.1/en/error-messages-server.html
    Error: 1295 SQLSTATE: HY000 (ER_UNSUPPORTED_PS)

    Message: This command is not supported in the prepared statement protocol yet
    */

    if (e.getErrorCode() != 1295) {
      // The MySQL Server should be able to prepare the statement
      // but something went wrong. Let the caller handle the error.
      throw ;
    }
    cout << "#\t\t 'emulation': ER_UNSUPPORTED_PS and fallback to sql::Statement" << endl;
    cout << "#\t\t ERR: " << e.what();
    cout << " (MySQL error code: " << e.getErrorCode();
    cout << ", SQLState: " << e.getSQLState() << " )" << endl;

    stmt = con->createStatement();
    stmt->execute(sql);
  }

  return stmt;
}