Warning, /sdk/codevis/thirdparty/soci/docs/statements.md is written in an unsupported language. File is not indexed.

0001 # Statements
0002 
0003 ## Prepared statement
0004 
0005 Consider the following examples:
0006 
0007 ```cpp
0008 // Example 1.
0009 for (int i = 0; i != 100; ++i)
0010 {
0011     sql << "insert into numbers(value) values(" << i << ")";
0012 }
0013 
0014 // Example 2.
0015 for (int i = 0; i != 100; ++i)
0016 {
0017     sql << "insert into numbers(value) values(:val)", use(i);
0018 }
0019 ```
0020 
0021 Both examples will populate the table `numbers` with the values from `0` to `99`.
0022 
0023 The problem is that in both examples, not only the statement execution is repeated 100 times, but also the statement parsing and preparation.
0024 This means unnecessary overhead, even if some of the database servers are likely to optimize the second case.
0025 In fact, more complicated queries are likely to suffer in terms of lower performance, because finding the optimal execution plan is quite expensive and here it would be needlessly repeated.
0026 
0027 ### Statement preparation
0028 
0029 The following example uses the class `statement` explicitly, by preparing the statement only once and repeating its execution with changing data (note the use of `prepare` member of `session` class):
0030 
0031 ```cpp
0032 int i;
0033 statement st = (sql.prepare <<
0034                 "insert into numbers(value) values(:val)",
0035                 use(i));
0036 for (i = 0; i != 100; ++i)
0037 {
0038     st.execute(true);
0039 }
0040 ```
0041 
0042 The `true` parameter given to the `execute` method indicates that the actual data exchange is wanted, so that the meaning of the whole example is
0043 
0044 > "prepare the statement and exchange the data for each value of variable `i`".
0045 
0046 ### Portability note:
0047 
0048 The above syntax is supported for all backends, even if some database server does not actually provide this functionality - in which case the library will internally execute the query in a single phase, without really separating the statement preparation from execution.
0049 
0050 ## Rowset and iterator
0051 
0052 The `rowset` class provides an alternative means of executing queries and accessing results using STL-like iterator interface.
0053 
0054 The `rowset_iterator` type is compatible with requirements defined for input iterator category and is available via `iterator` and `const_iterator` definitions in the `rowset` class.
0055 
0056 The `rowset` itself can be used only with select queries.
0057 
0058 The following example creates an instance of the `rowset` class and binds query results into elements of `int` type - in this query only one result column is expected.
0059 After executing the query the code iterates through the query result using `rowset_iterator`:
0060 
0061 ```cpp
0062 rowset<int> rs = (sql.prepare << "select values from numbers");
0063 
0064 for (rowset<int>::const_iterator it = rs.begin(); it != rs.end(); ++it)
0065 {
0066         cout << *it << '\n';
0067 }
0068 ```
0069 
0070 Another example shows how to retrieve more complex results, where `rowset` elements are of type `row` and therefore use [dynamic bindings](types.md#dynamic-binding):
0071 
0072 ```cpp
0073 // person table has 4 columns
0074 
0075 rowset<row> rs = (sql.prepare << "select id, firstname, lastname, gender from person");
0076 
0077 // iteration through the resultset:
0078 for (rowset<row>::const_iterator it = rs.begin(); it != rs.end(); ++it)
0079 {
0080     row const& row = *it;
0081 
0082     // dynamic data extraction from each row:
0083     cout << "Id: " << row.get<int>(0) << '\n'
0084             << "Name: " << row.get<string>(1) << " " << row.get<string>(2) << '\n'
0085             << "Gender: " << row.get<string>(3) << endl;
0086 }
0087 ```
0088 
0089 The `rowset_iterator` can be used with standard algorithms as well:
0090 
0091 ```cpp
0092 rowset<string> rs = (sql.prepare << "select firstname from person");
0093 
0094 std::copy(rs.begin(), rs.end(), std::ostream_iterator<std::string>(std::cout, "\n"));
0095 ```
0096 
0097 Above, the query result contains a single column which is bound to `rowset` element of type of `std::string`.
0098 All records are sent to standard output using the `std::copy` algorithm.
0099 
0100 If you need to use the Core interface with `rowset`, the following example shows how:
0101 
0102 ```cpp
0103 row r;
0104 
0105 statement st(sql);
0106 st.alloc();
0107 st.prepare("select values from numbers");
0108 st.define_and_bind();
0109 
0110 // after define_and_bind and before execute
0111 st.exchange_for_rowset(into(r));
0112 
0113 st.execute(false);
0114 
0115 rowset_iterator<row> it(st, r);
0116 rowset_iterator<row> end;
0117 for (; it != end; ++it) {
0118     // ... access *it
0119 }
0120 ```
0121 
0122 ## Bulk operations
0123 
0124 When using some databases, further performance improvements may be possible by having the underlying database API group operations together to reduce network roundtrips.
0125 SOCI makes such bulk operations possible by supporting `std::vector` based types.
0126 
0127 The following example presents how to insert 100 records in 4 batches.
0128 It is also important to note, that size of vector remains equal in every batch interaction.
0129 This ensures vector is not reallocated and, what's crucial for the bulk trick, new data should be pushed to the vector before every call to `statement::execute`:
0130 
0131 ```cpp
0132 // Example 3.
0133 void fill_ids(std::vector<int>& ids)
0134 {
0135     for (std::size_t i = 0; i < ids.size(); ++i)
0136         ids[i] = i; // mimics source of a new ID
0137 }
0138 
0139 const int BATCH_SIZE = 25;
0140 std::vector<int> ids(BATCH_SIZE);
0141 
0142 statement st = (sql.prepare << "insert into numbers(value) values(:val)", use(ids));
0143 for (int i = 0; i != 4; ++i)
0144 {
0145     fill_ids(ids);
0146     st.execute(true);
0147 }
0148 ```
0149 
0150 Given batch size is 25, this example should insert 4 x 25 = 100 records.
0151 
0152 (Of course, the size of the vector that will achieve optimum performance will vary, depending on many environmental factors, such as network speed.)
0153 
0154 It is also possible to read all the numbers written in the above examples:
0155 
0156 ```cpp
0157 int i;
0158 statement st = (sql.prepare << "select value from numbers order by value", into(i));
0159 st.execute();
0160 while (st.fetch())
0161 {
0162     cout << i << '\n';
0163 }
0164 ```
0165 
0166 In the above example, the `execute` method is called with the default parameter `false`.
0167 This means that the statement should be executed, but the actual data exchange will be performed later.
0168 
0169 Further `fetch` calls perform the actual data retrieval and cursor traversal.
0170 The *end-of-cursor* condition is indicated by the `fetch` function returning `false`.
0171 
0172 The above code example should be treated as an idiomatic way of reading many rows of data, *one at a time*.
0173 
0174 It is further possible to select records in batches into `std::vector` based types, with the size of the vector specifying the number of records to retrieve in each round trip:
0175 
0176 ```cpp
0177 std::vector<int> valsOut(100);
0178 sql << "select val from numbers", into(valsOut);
0179 ```
0180 
0181 Above, the value `100` indicates that no more values should be retrieved, even if it would be otherwise possible.
0182 If there are less rows than asked for, the vector will be appropriately down-sized.
0183 
0184 The `statement::execute()` and `statement::fetch()` functions can also be used to repeatedly select all rows returned by a query into a vector based type:
0185 
0186 ```cpp
0187 const int BATCH_SIZE = 30;
0188 std::vector<int> valsOut(BATCH_SIZE);
0189 statement st = (sql.prepare <<
0190                 "select value from numbers",
0191                 into(valsOut));
0192 st.execute();
0193 while (st.fetch())
0194 {
0195     std::vector<int>::iterator pos;
0196     for(pos = valsOut.begin(); pos != valsOut.end(); ++pos)
0197     {
0198         cout << *pos << '\n';
0199     }
0200 
0201     valsOut.resize(BATCH_SIZE);
0202 }
0203 ```
0204 
0205 Assuming there are 100 rows returned by the query, the above code will retrieve and print all of them.
0206 Since the output vector was created with size 30, it will take (at least) 4 calls to `fetch()` to retrieve all 100 values.
0207 Each call to `fetch()` can potentially resize the vector to a size less than its initial size - how often this happens depends on the underlying database implementation.
0208 This explains why the `resize(BATCH_SIZE)` operation is needed - it is there to ensure that each time the `fetch()` is called, the vector is ready to accept the next bunch of values.
0209 Without this operation, the vector *might* be getting smaller with subsequent iterations of the loop, forcing more iterations to be performed (because *all* rows will be read anyway), than really needed.
0210 
0211 Note the following details about the above examples:
0212 
0213 * After performing `fetch()`, the vector's size might be *less* than requested, but `fetch()` returning true means that there was *at least one* row retrieved.
0214 * It is forbidden to manually resize the vector to the size *higher* than it was initially (this can cause the vector to reallocate its internal buffer and the library can lose track of it).
0215 
0216 Taking these points under consideration, the above code example should be treated as an idiomatic way of reading many rows by bunches of requested size.
0217 
0218 ### Portability note
0219 
0220 Actually, all supported backends guarantee that the requested number of rows will be read with each fetch and that the vector will never be down-sized, unless for the last fetch, when the end of rowset condition is met.
0221 This means that the manual vector resizing is in practice not needed - the vector will keep its size until the end of rowset.
0222 The above idiom, however, is provided with future backends in mind, where the constant size of the vector might be too expensive to guarantee and where allowing `fetch` to down-size the vector even before reaching the end of rowset might buy some performance gains.
0223 
0224 ## Statement caching
0225 
0226 Some backends have some facilities to improve statement parsing and compilation to limit overhead when creating commonly used query.
0227 But for backends that does not support this kind optimization you can keep prepared statement and use it later with new references.
0228 To do such, prepare a statement as usual, you have to use `exchange` to bind new variables to statement object, then `execute` statement and finish by cleaning bound references with `bind_clean_up`.
0229 
0230 ```cpp
0231 sql << "CREATE TABLE test(a INTEGER)";
0232 
0233 {
0234     // prepare statement
0235     soci::statement stmt = (sql.prepare << "INSERT INTO numbers(value) VALUES(:val)");
0236 
0237     {
0238         // first insert
0239         int a0 = 0;
0240 
0241         // update reference
0242         stmt.exchange(soci::use(a0));
0243 
0244         stmt.define_and_bind();
0245         stmt.execute(true);
0246         stmt.bind_clean_up();
0247     }
0248 
0249     {
0250         // come later, second insert
0251         int a1 = 1;
0252 
0253         // update reference
0254         stmt.exchange(soci::use(a1));
0255 
0256         stmt.define_and_bind();
0257         stmt.execute(true);
0258         stmt.bind_clean_up();
0259     }
0260 }
0261 
0262 {
0263     std::vector<int> v(10);
0264     sql << "SELECT value FROM numbers", soci::into(v);
0265     for (int i = 0; i < v.size(); ++i)
0266         std::cout << "value " << i << ": " << v[i] << std::endl;
0267 }
0268 ```