Often, you are faced with a situation requiring you
to use a function that the SQL engine does not implement. SQLite
provides a mechanism for extending the C API and allows for
user-defined functions. The user can define new custom functions for
use in SQL statements for a specific database connection. Such
functions are transient in that they are only available during the life
of a database connection. They are not stored in the database.
In this section, we demonstrate the use of user-defined functions by adding the function Palindrome() to a database connection. The function Palindrome(t) takes a text-based parameter, t, and checks to see if t is the same whether it is read from the right or from the left. Listing 1 shows the main() function demonstrating the installation of a user-defined function for an opened database connection.
Example 1. The main() function demonstrating the installation of a user-defined function for an opened database connection.
int main(int argc, char* argv[]) { char *sqlStatement; sqlite3 *database; int returnCode; char *databaseName; sqlite3_stmt *statement;
databaseName = "financial.db"; returnCode = sqlite3_open(databaseName, &database); if(returnCode!=SQLITE_OK) { fprintf(stderr, "Error in opening the database. Error: %s", sqlite3_errmsg(database)); sqlite3_close(database); return −1; } sqlite3_create_function(database, "Palindrome", 1, SQLITE_UTF8, NULL, palindrome, NULL, NULL); sqlStatement = sqlite3_mprintf( "SELECT S.symbol, S.unitsPurchased, S.purchasePrice " "FROM stocks AS S WHERE " "Palindrome(S.symbol) = 1 AND S.purchasePrice >= %f", 30.0);
returnCode = sqlite3_prepare_v2( database, sqlStatement, strlen(sqlStatement), &statement, NULL); if(returnCode!=SQLITE_OK) { fprintf(stderr, "Error in preparation of query. Error: %s", sqlite3_errmsg(database)); sqlite3_close(database); return −1; } returnCode = sqlite3_step(statement); while(returnCode == SQLITE_ROW){ char * symbol; int units; double price;
symbol = sqlite3_column_text(statement, 0); units = sqlite3_column_int(statement, 1); price = sqlite3_column_double(statement, 2); printf("We bought %d from %s at a price equal to %.4f\n", units, symbol, price); returnCode = sqlite3_step(statement); } sqlite3_finalize(statement); sqlite3_free(sqlStatement); return 0; }
|
The user-defined function is installed for a given connection by calling sqlite3_create_function(). The function is declared as:
int sqlite3_create_function(
sqlite3 *connectionHandle,
const char* zFunctionName,
int nArg,
int eTextRep,
void*,
void (*xFunc)(sqlite3_context*,int,sqlite3_value**),
void (*xStep)(sqlite3_context*,int,sqlite3_value**),
void (*xFinal)(sqlite3_context*)
)
The first parameter of this function is the
connection (database) handle. The second parameter is the function name
as it is used in SQL statements. This name can be different from the C
function name that actually implements the function. The third
parameter is used to specify the number of parameters for the custom
function being created. The fourth parameter is used to specify the
encoding of the parameters. You can install different versions of the
same function that use different encodings. The SQLite engine will be
able to route the calls to the appropriate function. The fifth
parameter is an arbitrary pointer. Inside your user-defined function,
you can access this pointer using sqlite3_user_data(). The seventh parameter is a pointer to the C function implementing the behaviour whose logical name is the second parameter, zFunctionName.
More on this in a moment. The eighth and ninth parameters are aggregate
step and finalize functions, respectively. These two functions are used
in executing aggregate SQL statements.
All user-defined functions have the same signature:
void (sqlite3_context *context, int nargs,sqlite3_value **values)
The function returns void and all its three
parameters are input parameters. The first parameter is the SQL
function context. Think of it as a channel ID for the function and the
SQL engine to communicate on. The second parameter is the number of
arguments used when the logical function was called from within the SQL
statement. The third parameter is the array of parameter values passed
to the function.
Since all user-defined functions are void,
the results/errors are signaled back using SQLite3 routines. To signal
back an error message to the caller, you use the function sqlite3_result_error().
The first parameter in this function is the context (so that the engine
knows which SQL statement this error is related to). The second
parameter is a C-string providing the error message in text. Finally,
the last parameter is the length of the error message.
The SELECT statement that we use here is
similar to the one in the previous section, except that we require the
stock transaction to have a palindrome symbol. The SELECT statement is as follows:
SELECT
S.symbol, S.unitsPurchased, S.purchasePrice
FROM stocks AS S
WHERE Palindrome(S.symbol) = 1 AND S.purchasePrice >= 30.0
For the SQLite engine to execute this query, the Palindrome() needs to be defined for this connection. We define the function by the following statement:
sqlite3_create_function(database, "Palindrome", 1,SQLITE_UTF8, NULL,
palindrome, NULL, NULL);
Listing 2 shows the implementation of the palindrome() function.
Example 2. The user-defined function palindrome() and its implementation.
#import "/usr/include/sqlite3.h" int isPalindrome(char* text){ unsigned char* p1, *p2; p1 = text; p2 = p1+strlen(text)−1; while (*p1==*p2 && (p1<=p2)){ p1++;p2--; } if(p1>= p2) return 1; return 0; }
void palindrome(sqlite3_context *context,int nargs,sqlite3_value **values){ char *errorMessage; if(nargs != 1){ errorMessage = "Incorrect no of arguments. palindrome(string)"; sqlite3_result_error(context, errorMessage, strlen(errorMessage)); return; } if((sqlite3_value_type(values[0]) != SQLITE_TEXT)){ errorMessage = "Argument must be of type text."; sqlite3_result_error(context, errorMessage, strlen(errorMessage)); return;
} unsigned char* text; text = sqlite3_value_text(values[0]); sqlite3_result_int(context, isPalindrome(text)); }
|
The palindrome() function first checks to
see that the number of parameters is equal to 1. If not, an error
message is signaled back and the function returns. The function also
checks the type of the parameter passed as we are expecting a TEXT
value. The function sqlite3_value_type() returns the type of the parameter. The function is declared as:
int sqlite3_value_type(sqlite3_value*)
It takes a pointer to a value of type sqlite3_value and returns one of the following types: SQLITE_INTEGER, SQLITE_FLOAT, SQLITE_BLOB, SQLITE_NULL, or SQLITE3_TEXT.
After making sure that the type of the parameter is TEXT, we need to obtain the actual text value. The SQLite function sqlite3_value_text() is used for that purpose. There are other similar functions (e.g., sqlite3_value_int()) for the other types. Once we have the string passed to us, we check if it is a palindrome using the function isPalindrome(). You should be familiar with this function from introductory computer science classes.
To send the result back to the SQLite engine, you use a function of the form sqlite3_result_XXX(), which takes the context as the first parameter and the result value as the second parameter. For example, we use the function sqlite3_result_int() to return an integer as follows:
sqlite3_result_int(context, isPalindrome(text))