5. Specialized SQL Structures

The Specialized SQL Structure (SSQLS) feature lets you easily define C++ structures that match the form of your SQL tables. At the most superficial level, an SSQLS has a member variable corresponding to each field in the SQL table. But, an SSQLS also has several methods, operators, and data members used by MySQL++’s internals to provide neat functionality, which we cover in this chapter.

You define SSQLSes using the macros defined in ssqls.h. This is the only MySQL++ header not automatically included for you by mysql++.h. You have to include it in code modules that use the SSQLS feature.

5.1. sql_create

Let’s say you have the following SQL table:

CREATE TABLE stock (
    item CHAR(30) NOT NULL,
    num BIGINT NOT NULL,
    weight DOUBLE NOT NULL,
    price DECIMAL(6,2) NOT NULL,
    sdate DATE NOT NULL,
    description MEDIUMTEXT NULL)

You can create a C++ structure corresponding to this table like so:

sql_create_6(stock, 1, 6,
    mysqlpp::sql_char, item,
    mysqlpp::sql_bigint, num,
    mysqlpp::sql_double, weight,
    mysqlpp::sql_decimal, price,
    mysqlpp::sql_date, sdate,
    mysqlpp::Null<mysqlpp::sql_mediumtext>, description)

This declares the stock structure, which has a data member for each SQL column, using the same names. The structure also has a number of member functions, operators and hidden data members, but we won’t go into that just now.

The parameter before each field name in the sql_create_# call is the C++ data type that will be used to hold that value in the SSQLS. While you could use plain old C++ data types for most of these columns (long int instead of mysqlpp::sql_bigint, for example) it’s best to use the MySQL++ typedefs.

Sometimes you have no choice but to use special MySQL++ data types to fully express the database schema. Consider the description field. MySQL++’s sql_mediumtext type is just an alias for std::string, since we don’t need anything fancier to hold a SQL MEDIUMTEXT value. It’s the SQL NULL attribute that causes trouble: it has no equivalent in the C++ type system. MySQL++ offers the Null template, which bridges this difference between the two type systems.

The general format of this macro is:

sql_create_#(NAME, COMPCOUNT, SETCOUNT, TYPE1, ITEM1, ... TYPE#, ITEM#)

where # is the number of member variables, NAME is the name of the structure you wish to create, TYPEx is the type of a member variable, and ITEMx is that variable’s name.

The COMPCOUNT and SETCOUNT arguments are described in the next section.

5.2. SSQLS Comparison and Initialization

The sql_create_# macro adds member functions and operators to each SSQLS that allow you to compare one SSQLS instance to another. These functions compare the first COMPCOUNT fields in the structure. In the example above, COMPCOUNT is 1, so only the item field will be checked when comparing two stock structures.

This feature works best when your table’s “key” fields are the first ones in the SSQLS and you set COMPCOUNT equal to the number of key fields. That way, a check for equality between two SSQLS structures in your C++ code will give the same results as a check for equality in SQL.

COMPCOUNT must be at least 1. The current implementation of sql_create_# cannot create an SSQLS without comparison member functions.

Because our stock structure is less-than-comparable, you can use it in STL algorithms and containers that require this, such as STL’s associative containers:

std::set<stock> result;   
query.storein(result);
cout << result.lower_bound(stock("Hamburger"))->item << endl;

This will print the first item in the result set that begins with “Hamburger.”

The third parameter to sql_create_# is SETCOUNT. If this is nonzero, it adds an initialization constructor and a set() member function taking the given number of arguments, for setting the first N fields of the structure. For example, you could change the above example like so:

sql_create_6(stock, 1, 2,
    mysqlpp::sql_char, item,
    mysqlpp::sql_bigint, num,         
    mysqlpp::sql_double, weight,  
    mysqlpp::sql_decimal, price,  
    mysqlpp::sql_date, sdate,
    mysqlpp::Null<mysqlpp::sql_mediumtext>, description)
    
stock foo("Hotdog", 52);

In addition to this 2-parameter constructor, this version of the stock SSQLS will have a similar 2-parameter set() member function.

The COMPCOUNT and SETCOUNT values cannot be equal. If they are, the macro will generate two initialization constructors with identical parameter lists, which is illegal in C++. You might be asking, why does there need to be a constructor for comparison to begin with? It’s often convenient to be able to say something like x == stock("Hotdog"). This requires that there be a constructor taking COMPCOUNT arguments to create the temporary stock instance used in the comparison.

This limitation is not a problem in practice. If you want the same number of parameters in the initialization constructor as the number of fields used in comparisons, pass 0 for SETCOUNT. This suppresses the duplicate constructor you’d get if you used the COMPCOUNT value instead. This is most useful in very small SSQLSes, since it’s easier for the number of key fields to equal the number of fields you want to compare on:

sql_create_1(stock_item, 1, 0, mysqlpp::sql_char, item)

5.3. Retrieving data

Let’s put SSQLS to use. This is examples/ssqls1.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <iostream>
#include <vector>

using namespace std;

int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    try {                       
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Retrieve a subset of the stock table's columns, and store
        // the data in a vector of 'stock' SSQLS structures.  See the
        // user manual for the consequences arising from this quiet
        // ability to store a subset of the table in the stock SSQLS.
        mysqlpp::Query query = con.query("select item,description from stock");
        vector<stock> res;
        query.storein(res);

        // Display the items
        cout << "We have:" << endl;
        vector<stock>::iterator it;
        for (it = res.begin(); it != res.end(); ++it) {
            cout << '\t' << it->item;
            if (it->description != mysqlpp::null) {
                cout << " (" << it->description << ")";
            }
            cout << endl;
        }
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {
        // Handle bad conversions; e.g. type mismatch populating 'stock'
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

Here is the stock.h header used by that example, and by several others below:

#include <mysql++.h>
#include <ssqls.h>

// The following is calling a very complex macro which will create
// "struct stock", which has the member variables:
//
//   sql_char item;
//   ...
//   sql_mediumtext_null description;
//
// plus methods to help populate the class from a MySQL row.  See the
// SSQLS sections in the user manual for further details.
sql_create_6(stock,
    1, 6, // The meaning of these values is covered in the user manual
    mysqlpp::sql_char, item,
    mysqlpp::sql_bigint, num,
    mysqlpp::sql_double, weight,
    mysqlpp::sql_double_null, price,
    mysqlpp::sql_date, sDate,           // SSQLS isn't case-sensitive!
    mysqlpp::sql_mediumtext_null, description)

This example produces the same output as simple1.cpp (see Section 3.2, “A Simple Example”), but it uses higher-level data structures paralleling the database schema instead of MySQL++’s lower-level generic data structures. It also uses MySQL++’s exceptions for error handling instead of doing everything inline. For small example programs like these, the overhead of SSQLS and exceptions doesn’t pay off very well, but in a real program, they end up working much better than hand-rolled code.

Notice that we are only pulling a single column from the stock table, but we are storing the rows in a std::vector<stock>. It may strike you as inefficient to have five unused fields per record. It’s easily remedied by defining a subset SSQLS:

sql_create_1(stock_subset,
  1, 0,
  string, item)
  
vector<stock_subset> res;
query.storein(res);
// ...etc...

MySQL++ is flexible about populating SSQLSes.[13] It works much like the Web, a design that’s enabled the development of the largest distributed system in the world. Just as a browser ignores tags and attributes it doesn’t understand, you can populate an SSQLS from a query result set containing columns that don’t exist in the SSQLS. And as a browser uses sensible defaults when the page doesn’t give explicit values, you can have an SSQLS with more fields defined than are in the query result set, and these SSQLS fields will get default values. (Zero for numeric types, false for bool, and a type-specific default for anything more complex, like mysqlpp::DateTime.)

In more concrete terms, the example above is able to populate the stock objects using as much information as it has, and leave the remaining fields at their defaults. Conversely, you could also stuff the results of SELECT * FROM stock into the stock_subset SSQLS declared above; the extra fields would just be ignored.

We’re trading run-time efficiency for flexibility here, usually the right thing in a distributed system. Since MySQL is a networked database server, many uses of it will qualify as distributed systems. You can’t count on being able to update both the server(s) and all the clients at the same time, so you have to make them flexible enough to cope with differences while the changes propagate. As long as the new database schema isn’t too grossly different from the old, your programs should continue to run until you get around to updating them to use the new schema.

There’s a danger that this quiet coping behavior may mask problems, but considering that the previous behavior was for the program to crash when the database schema got out of synch with the SSQLS definition, it’s likely to be taken as an improvement.

5.4. Adding data

MySQL++ offers several ways to insert data in SSQLS form into a database table.

Inserting a Single Row

The simplest option is to insert a single row at a time. This is examples/ssqls2.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <iostream>
#include <limits>

using namespace std;

int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    try {
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Create and populate a stock object.  We could also have used
        // the set() member, which takes the same parameters as this
        // constructor.
        stock row("Hot Dogs", 100, 1.5,
                numeric_limits<double>::infinity(), // "priceless," ha!
                mysqlpp::sql_date("1998-09-25"), mysqlpp::null);

        // Form the query to insert the row into the stock table.
        mysqlpp::Query query = con.query();
        query.insert(row);

        // Show the query about to be executed.
        cout << "Query: " << query << endl;

        // Execute the query.  We use execute() because INSERT doesn't
        // return a result set.
        query.execute();

        // Retrieve and print out the new table contents.
        print_stock_table(query);
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {  
        // Handle bad conversions
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

That’s all there is to it! MySQL++ even takes care of quoting and escaping the data when building queries from SSQLS structures. It’s efficient, too: MySQL++ is smart enough to quote and escape data only for those data types that actually require it.

Inserting Many Rows

Inserting a single row is useful, to be sure, but you might want to be able to insert many SSQLSes or Row objects at once. MySQL++ knows how to do that, too, sparing you the necessity of writing the loop. Plus, MySQL++ uses an optimized implementation of this algorithm, packing everything into a single SQL query, eliminating the overhead of multiple calls between the client and server. It’s just a different overload of insert(), which accepts a pair of iterators into an STL container, inserting every row in that range:

vector<stock> lots_of_stuff;
...populate the vector somehow...
query.insert(lots_of_stuff.begin(), lots_of_stuff.end()).execute();

By the way, notice that you can chain Query operations like in the last line above, because its methods return *this where that makes sense.

Working Around MySQL’s Packet Size Limit

The two-iterator form of insert() has an associated risk: MySQL has a limit on the size of the SQL query it will process. The default limit is 1 MB. You can raise the limit, but the reason the limit is configurable is not to allow huge numbers of inserts in a single query. They made the limit configurable because a single row might be bigger than 1 MB, so the default would prevent you from inserting anything at all. If you raise the limit simply to be able to insert more rows at once, you’re courting disaster with no compensating benefit: the more data you send at a time, the greater the chance and cost of something going wrong. Worse, this is pure risk, because by the time you hit 1 MB, the per-packet overhead is such a small fraction of the data being transferred that increasing the packet size buys you essentially nothing.

Let’s say you have a vector containing several megabytes of data; it will get even bigger when expressed in SQL form, so there’s no way you can insert it all in a single query without raising the MySQL packet limit. One way to cope would be to write your own naïve loop, inserting just one row at a time. This is slow, because you’re paying the per-query cost for every row in the container. Then you might realize that you could use the two iterator form of insert(), passing iterators expressing sub-ranges of the container instead of trying to insert the whole container in one go. Now you’ve just got to figure out how to calculate those sub-ranges to get efficient operation without exceeding the packet size limit.

MySQL++ already knows how to do that, too, with Query::insertfrom(). We gave it a different name instead of adding yet another insert() overload because it doesn’t merely build the INSERT query, which you then execute(). It’s more like storein(), in that it wraps the entire operation up in a single call. This feature is demonstrated in examples/ssqls6.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <fstream>

using namespace std;


// Breaks a given text line of tab-separated fields up into a list of
// strings.
static size_t
tokenize_line(const string& line, vector<mysqlpp::String>& strings)
{
    string field;
    strings.clear();

    istringstream iss(line);
    while (getline(iss, field, '\t')) {
        strings.push_back(mysqlpp::String(field));
    }

    return strings.size();
}


// Reads a tab-delimited text file, returning the data found therein
// as a vector of stock SSQLS objects.
static bool
read_stock_items(const char* filename, vector<stock>& stock_vector)
{
    ifstream input(filename);
    if (!input) {
        cerr << "Error opening input file '" << filename << "'" << endl;
        return false;
    }

    string line;
    vector<mysqlpp::String> strings;
    while (getline(input, line)) {
        if (tokenize_line(line, strings) == 6) {
            stock_vector.push_back(stock(string(strings[0]), strings[1],
                    strings[2], strings[3], strings[4], strings[5]));
        }
        else {
            cerr << "Error parsing input line (doesn't have 6 fields) " << 
                    "in file '" << filename << "'" << endl;
            cerr << "invalid line: '" << line << "'" << endl;
        }
    }

    return true;
}


int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    // Read in a tab-delimited file of stock data
    vector<stock> stock_vector;
    if (!read_stock_items("examples/stock.txt", stock_vector)) {
        return 1;
    }

    try {
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Clear all existing rows from stock table, as we're about to
        // insert a bunch of new ones, and we want a clean slate.
        mysqlpp::Query query = con.query();
        query.exec("DELETE FROM stock");

        // Insert data read from the CSV file, allowing up to 1000
        // characters per packet.  We're using a small size in this
        // example just to force multiple inserts.  In a real program,
        // you'd want to use larger packets, for greater efficiency.
        mysqlpp::Query::MaxPacketInsertPolicy<> insert_policy(1000);
        query.insertfrom(stock_vector.begin(), stock_vector.end(),
                insert_policy);

        // Retrieve and print out the new table contents.
        print_stock_table(query);
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {
        // Handle bad conversions
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::BadInsertPolicy& er) {
        // Handle bad conversions
        cerr << "InsertPolicy error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

Most of the complexity in this example goes to just reading in the data from a file; we have to get our test data from somewhere. There are only two key lines of code: create an insertion policy object, and pass it along with an STL container full of row data to Query::insertfrom().

This policy object is the main thing that differentiates insertfrom() from the two-iterator form of insert(). It controls how insertfrom() builds the query strings, primarily controlling how large each query gets before insertfrom() executes it and starts building a new query. We designed it to use policy objects because there is no single “right” choice for the decisions it makes.

MySQL++ ships with three different insertion policy classes, which should cover most situations.

MaxPacketInsertPolicy, demonstrated in the example above, does things the most obvious way: when you create it, you pass the maximum packet size, which it uses to prevent queries from going over the size limit. It builds up a query string row by row, checking each time through the loop whether adding another insert statement to the query string would make the packet size go over the limit. When that happens, or it gets to the end of the iteration range, it executes the query and starts over if it’s not yet at the end. This is robust, but it has a downside: it has to build each insert query in advance of knowing that it can append it to the larger query. Any time an insert query would push the packet over the limit, it has to throw it away, causing the library to do more work than is strictly necessary.

Imagine you’ve done some benchmarking and have found that the point of diminishing returns is at about 20 KB per query in your environment; beyond that point, the per-query overhead ceases to be an issue. Let’s also say you know for a fact that your largest row will always be less than 1 MB — less 20 KB — when expressed as a SQL insert statement. In that case, you can use the more efficient SizeThresholdInsertPolicy. It differs from MaxPacketInsertPolicy in that it allows insertfrom() to insert rows blindly into the query string until the built query exceeds the threshold, 20 KB in this example. Then it ships the packet off, and if successful, starts a new query. Thus, each query (except possibly the last) will be at least 20 KB, exceeding that only by as much as one row’s worth of data, minus one byte. This is quite appropriate behavior when your rows are relatively small, as is typical for tables not containing BLOB data. It is more efficient than MaxPacketInsertPolicy because it never has to throw away any SQL fragments.

The simplest policy object type is RowCountInsertPolicy. This lets you simply say how many rows at a time to insert into the database. This works well when you have a good handle on how big each row will be, so you can calculate in advance how many rows you can insert at once without exceeding some given limit. Say you know your rows can’t be any bigger than about 1 KB. If we stick with that 20 KB target, passing RowCountInsertPolicy<>(20) for the policy object would ensure we never exceed the size threshold. Or, say that maximum size value above is still true, but we also know the average row size is only 200 bytes. You could pass RowCountInsertPolicy<>(100) for the policy, knowing that the average packet size will be around 20 KB, and the worst case packet size 100 KB, still nowhere near the default 1 MB packet size limit. The code for this policy is very simple, so it makes your program a little smaller than if you used either of the above policies. Obviously it’s a bad choice if you aren’t able to predict the size of your rows accurately.

If one of the provided insert policy classes doesn’t suit your needs, you can easily create a custom one. Just study the implementation in lib/insertpolicy.*.

Interaction with Transactions

These policy classes are all templates, taking a parameter that defaults to Transaction. This means that, by default, insertfrom() wraps the entire operation in a SQL transaction, so that if any of the insertions fail, the database server rolls them all back. This prevents an error in the middle of the operation from leaving just part of the container’s data inserted in the database, which you usually don’t want any more than you’d want half a single row to be inserted.

There are good reasons why you might not want this. Perhaps the best reason is if the insertfrom() call is to be part of a larger transaction. MySQL doesn’t support nested transactions, so the insertfrom() call will fail if it tries to start one of its own. You can pass NoTransactions for the insert policy’s template parameter to make it suppress the transaction code.

5.5. Modifying data

It almost as easy to modify data with SSQLS as to add it. This is examples/ssqls3.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <iostream>

using namespace std;

int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    try {
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Build a query to retrieve the stock item that has Unicode
        // characters encoded in UTF-8 form.
        mysqlpp::Query query = con.query("select * from stock ");
        query << "where item = " << mysqlpp::quote << "Nürnberger Brats";

        // Retrieve the row, throwing an exception if it fails.
        mysqlpp::StoreQueryResult res = query.store();
        if (res.empty()) {
            throw mysqlpp::BadQuery("UTF-8 bratwurst item not found in "
                    "table, run resetdb");
        }

        // Because there should only be one row in the result set,
        // there's no point in storing the result in an STL container.
        // We can store the first row directly into a stock structure
        // because one of an SSQLS's constructors takes a Row object.
        stock row = res[0];

        // Create a copy so that the replace query knows what the
        // original values are.
        stock orig_row = row;

        // Change the stock object's item to use only 7-bit ASCII, and
        // to deliberately be wider than normal column widths printed
        // by print_stock_table().
        row.item = "Nuerenberger Bratwurst";

        // Form the query to replace the row in the stock table.
        query.update(orig_row, row);

        // Show the query about to be executed.
        cout << "Query: " << query << endl;

        // Run the query with execute(), since UPDATE doesn't return a
        // result set.
        query.execute();

        // Retrieve and print out the new table contents.
        print_stock_table(query);
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {
        // Handle bad conversions
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

Don’t forget to run resetdb after running the example.

5.6. Storing SSQLSes in Associative Containers

One of the requirements of STL’s associative containers on data stored in them is that the data type has to be less-than comparable. That is, it has to have an operator < defined. SSQLS does optionally give you this, as demonstrated in examples/ssqls4.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <iostream>

using namespace std;

int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    try {
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Retrieve all rows from the stock table and put them in an
        // STL set.  Notice that this works just as well as storing them
        // in a vector, which we did in ssqls1.cpp.  It works because
        // SSQLS objects are less-than comparable.
        mysqlpp::Query query = con.query("select * from stock");
        set<stock> res;
        query.storein(res);

        // Display the result set.  Since it is an STL set and we set up
        // the SSQLS to compare based on the item column, the rows will
        // be sorted by item.
        print_stock_header(res.size());
        set<stock>::iterator it;
        cout.precision(3);
        for (it = res.begin(); it != res.end(); ++it) {
            print_stock_row(it->item.c_str(), it->num, it->weight,
                    it->price, it->sDate);
        }

        // Use set's find method to look up a stock item by item name.
        // This also uses the SSQLS comparison setup.
        it = res.find(stock("Hotdog Buns"));
        if (it != res.end()) {
            cout << endl << "Currently " << it->num <<
                    " hotdog buns in stock." << endl;
        }
        else {
            cout << endl << "Sorry, no hotdog buns in stock." << endl;
        }
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {
        // Handle bad conversions
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

The find() call works because of the way the SSQLS was declared. It’s properly covered elsewhere, but suffice it to say, the “1” in the declaration of stock above tells it that only the first field needs to be checked in comparing two SSQLSes. In database terms, this makes it the primary key. Therefore, when searching for a match, our exemplar only had to have its first field populated.

5.7. Changing the Table Name

Another feature you might find a use for is changing the table name MySQL++ uses to build queries involving SSQLSes. By default, the database server table is assumed to have the same name as the SSQLS structure type. But if this is inconvenient, you can globally change the table name used in queries like this:

stock::table("MyStockData");

It’s also possible to change the name of a table on a per-instance basis:

stock s;
s.instance_table("AlternateTable");

This is useful when you have an SSQLS definition that is compatible with multiple tables, so the table name to use for each instance is different. This feature saves you from having to define a separate SSQLS for each table. It is also useful for mapping a class hierarchy onto a set of table definitions. The common SSQLS definition is the “superclass” for a given set of tables.

Strictly speaking, you only need to use this feature in multithreaded programs. Changing the static table name before using each instance is safe if all changes happen within a single thread. That said, it may still be convenient to change the name of the table for an SSQLS instance in a single-threaded program if it gets used for many operations over an extended span of code.

5.8. Using an SSQLS in Multiple Modules

It’s convenient to define an SSQLS in a header file so you can use it in multiple modules. You run into a bit of a problem, though, because each SSQLS includes a few static data members to hold information common to all structures of that type. (The table name and the list of field names.) When you #include that header in more than one module, you get a multiply-defined symbol error at link time.

The way around this is to define the preprocessor macro MYSQLPP_SSQLS_NO_STATICS in all but one of the modules that use the header definining the SSQLS. When this macro is defined, it suppresses the static data members in any SSQLS defined thereafter.

Imagine we have a file my_ssqls.h which includes a sql_create_N macro call to define an SSQLS, and that that SSQLS is used in at least two modules. One we’ll call foo.cpp, and we’ll say it’s just a user of the SSQLS; it doesn’t “own” it. Another of the modules, my_ssqls.cpp uses the SSQLS more heavily, so we’ve called it the owner of the SSQLS. If there aren’t very many modules, this works nicely:

// File foo.cpp, which just uses the SSQLS, but doesn’t "own" it:
#define MYSQLPP_SSQLS_NO_STATICS
#include "my_ssqls.h"
// File my_ssqls.cpp, which owns the SSQLS, so we just #include it directly
#include "my_ssqls.h"

If there are many modules that need the SSQLS, adding all those #defines can be a pain. In that case, it’s easier if you flip the above pattern on its head:

// File my_ssqls.h:
#if !defined(EXPAND_MY_SSQLS_STATICS)
#   define MYSQLPP_SSQLS_NO_STATICS
#endif
sql_create_X(Y, Z....) // the SSQLS definition
// File foo.cpp, a mere user of the SSQLS:
#include "my_ssqls.h"
// File my_ssqls.cpp, which owns the SSQLS:
#define EXPAND_MY_SSQLS_STATICS
#include "my_ssqls.h"

5.9. Harnessing SSQLS Internals

The sql_create macros define several methods for each SSQLS. These methods are mostly for use within the library, but some of them are useful enough that you might want to harness them for your own ends. Here is some pseudocode showing how the most useful of these methods would be defined for the stock structure used in all the ssqls*.cpp examples:

// Basic form
template <class Manip>   
stock_value_list<Manip> value_list(cchar *d = ",",
  Manip m = mysqlpp::quote) const;  

template <class Manip>   
stock_field_list<Manip> field_list(cchar *d = ",",   
  Manip m = mysqlpp::do_nothing) const;  

template <class Manip>   
stock_equal_list<Manip> equal_list(cchar *d = ",",
  cchar *e = " = ", Manip m = mysqlpp::quote) const;  


// Boolean argument form
template <class Manip>
stock_cus_value_list<Manip> value_list([cchar *d, [Manip m,] ]   
  bool i1, bool i2 = false, ... , bool i5 = false) const;  

// List form  
template <class Manip>
stock_cus_value_list<Manip> value_list([cchar *d, [Manip m,] ]  
  stock_enum i1, stock_enum i2 = stock_NULL, ...,
  stock_enum i5 = stock_NULL) const;  

// Vector form  
template <class Manip>
stock_cus_value_list<Manip> value_list([cchar *d, [Manip m,] ]  
  vector<bool> *i) const;  

...Plus the obvious equivalents for field_list() and equal_list()

Rather than try to learn what all of these methods do at once, let’s ease into the subject. Consider this code:

stock s("Dinner Rolls", 75, 0.95, 0.97, sql_date("1998-05-25"));   
cout << "Value list: " << s.value_list() << endl;  
cout << "Field list: " << s.field_list() << endl;  
cout << "Equal list: " << s.equal_list() << endl;

That would produce something like:

Value list: 'Dinner Rolls’,75,0.95,0.97,'1998-05-25'   
Field list: item,num,weight,price,sdate  
Equal list: item = 'Dinner Rolls’,num = 75,weight = 0.95, price = 0.97,sdate = '1998-05-25'

That is, a “value list” is a list of data member values within a particular SSQLS instance, a “field list” is a list of the fields (columns) within that SSQLS, and an “equal list” is a list in the form of an SQL equals clause.

Just knowing that much, it shouldn’t surprise you to learn that Query::insert() is implemented more or less like this:

*this << "INSERT INTO " << v.table() << " (" << v.field_list() <<
    ") VALUES (" << v.value_list() << ")";

where ‘v’ is the SSQLS you’re asking the Query object to insert into the database.

Now let’s look at a complete example, which uses one of the more complicated forms of equal_list(). This example builds a query with fewer hard-coded strings than the most obvious technique requires, which makes it more robust in the face of change. Here is examples/ssqls5.cpp:

#include "cmdline.h"
#include "printdata.h"
#include "stock.h"

#include <iostream>
#include <vector>

using namespace std;

int
main(int argc, char *argv[])
{
    // Get database access parameters from command line
    mysqlpp::examples::CommandLine cmdline(argc, argv);
    if (!cmdline) {
        return 1;
    }

    try {
        // Establish the connection to the database server.
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());

        // Get all the rows in the stock table.
        mysqlpp::Query query = con.query("select * from stock");
        vector<stock> res;
        query.storein(res);

        if (res.size() > 0) {
            // Build a select query using the data from the first row
            // returned by our previous query.
            query << "select * from stock where " <<
                    res[0].equal_list(" and ", stock_weight, stock_price);

            // Display the finished query.
            cout << "Custom query:\n" << query << endl;
        }
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        cerr << "Query error: " << er.what() << endl;
        return -1;
    }
    catch (const mysqlpp::BadConversion& er) {
        // Handle bad conversions
        cerr << "Conversion error: " << er.what() << endl <<
                "\tretrieved data size: " << er.retrieved <<
                ", actual size: " << er.actual_size << endl;
        return -1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        cerr << "Error: " << er.what() << endl;
        return -1;
    }

    return 0;
}

This example uses the list form of equal_list(). The arguments stock_weight and stock_price are enum values equal to the position of these columns within the stock table. sql_create_# generates this enum for you automatically.

The boolean argument form of that equal_list() call would look like this:

query << "select * from stock where " <<
    res[0].equal_list(" and ", false, false, true, true, false);

It’s a little more verbose, as you can see. And if you want to get really complicated, use the vector form:

vector<bool> v(5, false);
v[stock_weight] = true;
v[stock_price] = true;
query << "select * from stock where " <<
    res[0].equal_list(" and ", v);

This form makes the most sense if you are building many other queries, and so can re-use that vector object.

Many of these methods accept manipulators and custom delimiters. The defaults are suitable for building SQL queries, but if you’re using these methods in a different context, you may need to override these defaults. For instance, you could use these methods to dump data to a text file using different delimiters and quoting rules than SQL.

At this point, we’ve seen all the major aspects of the SSQLS feature. The final sections of this chapter look at some of the peripheral aspects.

5.10. Having Different Field Names in C++ and SQL

There’s a more advanced SSQLS creation macro, which all the others are built on top of. Currently, the only feature it adds over what’s described above is that it lets you name your SSQLS fields differently from the names used by the database server. Perhaps you want to use Hungarian notation in your C++ program without changing the SQL database schema:

sql_create_complete_5(stock, 1, 5,   
    mysqlpp::sql_char, m_sItem, "item",
    mysqlpp::sql_bigint, m_nNum, "num",
    mysqlpp::sql_double, m_fWeight, "weight",
    mysqlpp::sql_decimal, m_fPrice, "price",
    mysqlpp::sql_date, m_Date, "sdate")

Note that you don’t have to use this mechanism if the only difference in your SQL and C++ field names is case. SSQLS field name lookups are case-insensitive as of MySQL++ 3.1. You can see this in the examples: some parts of the code deliberately refer to the stock.sdate sample table field as stock.sDate to exercise this feature.

5.11. Expanding SSQLS Macros

If you ever need to see the code that a given SSQLS declaration expands out to, use the utility doc/ssqls-pretty, like so:

doc/ssqls-pretty < myprog.cpp | less

This Perl script locates the first SSQLS declaration in that file, then uses the C++ preprocessor to expand that macro. (The script assumes that your system’s preprocessor is called cpp, and that its command line interface follows Unix conventions.)

If you run it from the top MySQL++ directory, as shown above, it will use the header files in the distribution’s lib subdirectory. Otherwise, it assumes the MySQL++ headers are in their default location, /usr/include/mysql++. If you want to use headers in some other location, you’ll need to change the directory name in the -I flag at the top of the script.

5.12. Customizing the SSQLS Mechanism

The SSQLS header ssqls.h is automatically generated by the Perl script ssqls.pl. Although it is possible to change this script to get additional functionality, most of the time it’s better to just derive a custom class from the generated SSQLS to add functionality to it. (See the next section to see how to do this correctly.)

That said, ssqls.pl does have a few configurables you might want to tweak.

The first configurable value sets the maximum number of data members allowed in an SSQLS. This is discussed elsewhere, in Section 8.2, “The Maximum Number of Fields Allowed”. Beware the warnings there about increasing this value too much.

The second configurable is the default floating point precision used for comparison. As described above (Section 5.2, “SSQLS Comparison and Initialization”) SSQLSes can be compared for equality. The only place this is tricky is with floating-point numbers, since rounding errors can make two “equal” values compare as distinct. This property of floating-point numbers means we almost never want to do exact comparison. MySQL++ lets you specify the precision you want it to use. If the difference between two values is under a given threshold, MySQL++ considers the values equal. The default threshold is 0.00001. This threshold works well for “human” scale values, but because of the way floating-point numbers work, it can be wildly inappropriate for very large or very small quantities like those used in scientific applications.

There are actually two ways to change this threshold. If you need a different system-wide default, edit ssqls.pl and change the $fp_min_delta variable at the top of the file, then rebuild ssqls.h as described below. If you need different thresholds per file or per project, it’s better to set the C macro MYSQLPP_FP_MIN_DELTA instead. The Perl variable sets this macro’s default; if you give a different value before #including ssqls.h, it will use that instead.

To rebuild ssqls.h after changing ssqls.pl, you’ll need a Perl interpreter. The only modern Unixy system I’m aware of where Perl isn’t installed by default is Cygwin, and it’s just a setup.exe choice away there. You’ll probably only have to download and install a Perl interpreter if you’re on Windows and don’t want to use Cygwin.

If you’re on a system that uses autoconf, building MySQL++ automatically updates ssqls.h any time ssqls.pl changes. Otherwise, you’ll need to run the Perl interpreter by hand:

c:\mysql++> cd lib
c:\lib> perl ssqls.pl

5.13. Deriving from an SSQLS

Specialized SQL Structures make good base classes. They’re simple, and have few requirements on any class that derives from them. There are some gotchas to look out for, however.

Consider this:

sql_create_2(
  Base, 1, 2,
  mysqlpp::sql_varchar, a,
  mysqlpp::sql_int, b
);

class Derived : public Base
{
public:
  // constructor
  Derived(mysqlpp::sql_varchar _a, mysqlpp::sql_int _b) :
  Base(_a, _b)
  {
  }

  // functionality added to the SSQLS through inheritance
  bool do_something_interesting(int data);
};

We’ve derived a class from an SSQLS in order to add a method to it. Easy, right?

Sadly, too easy. The code has a rather large flaw which makes our derived class unusable as an SSQLS. In C++, if a derived class has a function of the same name as one in the base class, the base class versions of that function are all hidden by those in the derived class. This applies to constructors, too: an SSQLS defines several constructors, but our derived class defines only one, causing that one to hide all of the ones in the base class. Many of the MySQL++ mechanisms that use SSQLSes rely on having these contructors, so our Derived above is-not-a Base, and so it isn’t an SSQLS. If you try to use Derived as an SSQLS, you’ll get compiler errors wherever MySQL++ tries to access one of these other constructors.

There’s another minor flaw, as well. Our lone constructor above takes its parameters by value, but the corresponding constructor in the SSQLS takes them by const reference. Our derived class has technically hidden a fourth base class constructor this way, but this particular case is more a matter of efficiency than correctness. Code that needs the full-creation constructor will still work with our code above, but passing stringish types like sql_varchar by value instead of by const reference is inefficient.

This is the corrected version of the above code:

sql_create_2(
  Base, 1, 2,
  mysqlpp::sql_varchar, a,
  mysqlpp::sql_int, b
);

class Derived : public Base
{
public:
  // default constructor[14]
  Derived() :
  Base()
  {
  }

  // for-comparison constructor[15]
  Derived(const mysqlpp::sql_varchar& _a) :
  Base(_a)
  {
  }

  // full creation constructor
  Derived(const mysqlpp::sql_varchar& _a, const mysqlpp::sql_int& _b) :
  Base(_a, _b)
  {
  }

  // population constructor[16]
  Derived(const mysqlpp::Row& row) :
  Base(row)
  {
  }

  // functionality added to the SSQLS through inheritance
  bool do_something_interesting(int data);
};

Now Derived is-an SSQLS.

You might wonder if you can use protected inheritance above to redefine the SSQLS’s public interface. For instance, OO purists might object to the public data members in an SSQLS. You could encapsulate these public data members in the derived class by using protected inheritance, exposing access to the base class’s data members with public accessor methods. The problem with this is that each SSQLS has dozens of public member functions. These are needed by MySQL++ internals, so unless you re-exposed all of them as we did with the constructors above, you’d again have an SSQLS derivative that is-not-an SSQLS. Simply put, only public inheritance is practical with SSQLSes.

5.14. SSQLS and BLOB Columns

It takes special care to use SSQLS with BLOB columns. It’s safest to declare the SSQLS field as of type mysqlpp::sql_blob. This is currently a typedef alias for String, which is the form the data is in just before the SSQLS mechanism populates the structure. Thus, when the data is copied from the internal MySQL++ data structures into your SSQLS, you get a direct copy of the String object’s contents, without interference.

Because C++ strings handle binary data just fine, you might think you can use std::string instead of sql_blob, but the current design of String converts to std::string via a C string. As a result, the BLOB data is truncated at the first embedded null character during population of the SSQLS. There’s no way to fix that without completely redesigning either String or the SSQLS mechanism.

The sql_blob typedef may be changed to alias a different type in the future, so using it instead of String ensures that your code tracks these library changes automatically. Besides, String is only intended to be an internal mechanism within MySQL++. The only reason the layering is so thin here is because it’s the only way to prevent BLOB data from being corrupted while avoiding that looming redesign effort.

You can see this technique in action in the cgi_jpeg example:

#include "cmdline.h"
#include "images.h"

#define CRLF            "\r\n"
#define CRLF2           "\r\n\r\n"

int
main(int argc, char* argv[])
{
    // Get database access parameters from command line if present, else
    // use hard-coded values for true CGI case.
    mysqlpp::examples::CommandLine cmdline(argc, argv, "root",
            "nunyabinness");
    if (!cmdline) {
        return 1;
    }

    // Parse CGI query string environment variable to get image ID
    unsigned int img_id = 0;
    char* cgi_query = getenv("QUERY_STRING");
    if (cgi_query) {
        if ((strlen(cgi_query) < 4) || memcmp(cgi_query, "id=", 3)) {
            std::cout << "Content-type: text/plain" << std::endl << std::endl;
            std::cout << "ERROR: Bad query string" << std::endl;
            return 1;
        }
        else {
            img_id = atoi(cgi_query + 3);
        }
    }
    else {
        std::cerr << "Put this program into a web server's cgi-bin "
                "directory, then" << std::endl;
        std::cerr << "invoke it with a URL like this:" << std::endl;
        std::cerr << std::endl;
        std::cerr << "    http://server.name.com/cgi-bin/cgi_jpeg?id=2" <<
                std::endl;
        std::cerr << std::endl;
        std::cerr << "This will retrieve the image with ID 2." << std::endl;
        std::cerr << std::endl;
        std::cerr << "You will probably have to change some of the #defines "
                "at the top of" << std::endl;
        std::cerr << "examples/cgi_jpeg.cpp to allow the lookup to work." <<
                std::endl;
        return 1;
    }

    // Retrieve image from DB by ID
    try {
        mysqlpp::Connection con(mysqlpp::examples::db_name,
                cmdline.server(), cmdline.user(), cmdline.pass());
        mysqlpp::Query query = con.query();
        query << "SELECT * FROM images WHERE id = " << img_id;
        mysqlpp::StoreQueryResult res = query.store();
        if (res && res.num_rows()) {
            images img = res[0];
            if (img.data.is_null) {
                std::cout << "Content-type: text/plain" << CRLF2;
                std::cout << "No image content!" << CRLF;
            }
            else {
                std::cout << "X-Image-Id: " << img_id << CRLF; // for debugging
                std::cout << "Content-type: image/jpeg" << CRLF;
                std::cout << "Content-length: " <<
                        img.data.data.length() << CRLF2;
                std::cout << img.data;
            }
        }
        else {
            std::cout << "Content-type: text/plain" << CRLF2;
            std::cout << "ERROR: No image with ID " << img_id << CRLF;
        }
    }
    catch (const mysqlpp::BadQuery& er) {
        // Handle any query errors
        std::cout << "Content-type: text/plain" << CRLF2;
        std::cout << "QUERY ERROR: " << er.what() << CRLF;
        return 1;
    }
    catch (const mysqlpp::Exception& er) {
        // Catch-all for any other MySQL++ exceptions
        std::cout << "Content-type: text/plain" << CRLF2;
        std::cout << "GENERAL ERROR: " << er.what() << CRLF;
        return 1;
    }

    return 0;
}

5.15. SSQLS and Visual C++ 2003

SSQLS works on all platforms supported by MySQL++ except for Visual C++ 2003. (Because the rest of MySQL++ works just fine with Visual C++ 2003, we haven’t removed this platform from the supported list entirely.)

If you do need SSQLS and are currently on Visual C++ 2003, you have these options:

  1. The simplest option is to upgrade to a newer version of Visual C++. The compiler limitations that break SSQLS are all fixed in Visual C++ 2005 and newer. Visual C++ Express is free and is apparently here to stay; coupled with the free wxWidgets library, it lacks little compared to Visual C++ Professional. A bonus of using wxWidgets is that it’s cross-platform and better-supported than MFC.

  2. If you can’t upgrade your compiler, you may be able to downgrade to MySQL++ v2.x. The SSQLS feature in these older versions worked with Visual C++ 2003, but didn’t let you use a given SSQLS in more than one module in a program. If you can live with that limitation and have a Perl interpreter on your system, you can re-generate lib/ssqls.h to remove the multiple-module SSQLS support. To do this, you run the command perl ssqls.pl -v from within MySQL++’s lib subdirectory before you build and install the library.

  3. There’s a plan to replace the current SSQLS mechanism with an entirely new code base. Although this is being done primarily to get new features that are too difficult to add within the current design, it also means we’ll have the chance to test step-by-step along the way that we don’t reintroduce code that Visual C++ 2003 doesn’t support. This may happen without you doing anything, but if there’s someone on the team who cares about this, that will naturally increase the chances that it does happen.



[13] Programs built against versions of MySQL++ prior to 3.0 would crash at almost any mismatch between the database schema and the SSQLS definition. It’s no longer necessary to keep the data design in lock-step between the client and database server. A mismatch can result in data loss, but not a crash.

[14] needed by mechanisms like Query::storein(); anything using an STL container, which usually require default ctors for contained data structures

[15] takes the COMPCOUNT subset of the SSQLS’s data members, used for making comparison exemplars, used with Query::update() and similar mechanisms; see Section 5.1, “sql_create” for more on COMPCOUNT

[16] used in taking raw row data from a SQL result set and converting it to SSQLS form