mirror of
https://github.com/cuberite/SQLiteCpp.git
synced 2025-08-05 10:16:01 -04:00
Add Database::tryExec()
Similar to Statement::tryExecuteStep(), allows calls to sqlite3_exec() with the caller assuming responsibility for checking and handling the returned status.
This commit is contained in:
parent
adb7e7c489
commit
1d0d8fe446
@ -197,6 +197,7 @@ public:
|
||||
* - Data Definition Language (DDL) statements "CREATE", "ALTER" and "DROP"
|
||||
* - Data Control Language (DCL) statements "GRANT", "REVOKE", "COMMIT" and "ROLLBACK"
|
||||
*
|
||||
* @see Database::tryExec() to execute, returning the sqlite result code
|
||||
* @see Statement::exec() to handle precompiled statements (for better performances) without results
|
||||
* @see Statement::executeStep() to handle "SELECT" queries with results
|
||||
*
|
||||
@ -217,6 +218,7 @@ public:
|
||||
* - Data Definition Language (DDL) statements "CREATE", "ALTER" and "DROP"
|
||||
* - Data Control Language (DCL) statements "GRANT", "REVOKE", "COMMIT" and "ROLLBACK"
|
||||
*
|
||||
* @see Database::tryExec() to execute, returning the sqlite result code
|
||||
* @see Statement::exec() to handle precompiled statements (for better performances) without results
|
||||
* @see Statement::executeStep() to handle "SELECT" queries with results
|
||||
*
|
||||
@ -232,6 +234,41 @@ public:
|
||||
return exec(aQueries.c_str());
|
||||
}
|
||||
|
||||
/**
|
||||
* @brief Try to execute one or multiple statements, returning the sqlite result code.
|
||||
*
|
||||
* This is useful for any kind of statements other than the Data Query Language (DQL) "SELECT" :
|
||||
* - Data Manipulation Language (DML) statements "INSERT", "UPDATE" and "DELETE"
|
||||
* - Data Definition Language (DDL) statements "CREATE", "ALTER" and "DROP"
|
||||
* - Data Control Language (DCL) statements "GRANT", "REVOKE", "COMMIT" and "ROLLBACK"
|
||||
*
|
||||
* @see exec() to execute, returning number of rows modified
|
||||
*
|
||||
* @param[in] aQueries one or multiple UTF-8 encoded, semicolon-separate SQL statements
|
||||
*
|
||||
* @return the sqlite result code.
|
||||
*/
|
||||
int tryExec(const char* apQueries) noexcept;
|
||||
|
||||
/**
|
||||
* @brief Try to execute one or multiple statements, returning the sqlite result code.
|
||||
*
|
||||
* This is useful for any kind of statements other than the Data Query Language (DQL) "SELECT" :
|
||||
* - Data Manipulation Language (DML) statements "INSERT", "UPDATE" and "DELETE"
|
||||
* - Data Definition Language (DDL) statements "CREATE", "ALTER" and "DROP"
|
||||
* - Data Control Language (DCL) statements "GRANT", "REVOKE", "COMMIT" and "ROLLBACK"
|
||||
*
|
||||
* @see exec() to execute, returning number of rows modified
|
||||
*
|
||||
* @param[in] aQueries one or multiple UTF-8 encoded, semicolon-separate SQL statements
|
||||
*
|
||||
* @return the sqlite result code.
|
||||
*/
|
||||
int tryExec(const std::string aQueries) noexcept
|
||||
{
|
||||
return tryExec(aQueries.c_str());
|
||||
}
|
||||
|
||||
/**
|
||||
* @brief Shortcut to execute a one step query and fetch the first column of the result.
|
||||
*
|
||||
|
@ -106,13 +106,18 @@ void Database::setBusyTimeout(const int aBusyTimeoutMs)
|
||||
// Shortcut to execute one or multiple SQL statements without results (UPDATE, INSERT, ALTER, COMMIT, CREATE...).
|
||||
int Database::exec(const char* apQueries)
|
||||
{
|
||||
const int ret = sqlite3_exec(getHandle(), apQueries, nullptr, nullptr, nullptr);
|
||||
const int ret = tryExec(apQueries);
|
||||
check(ret);
|
||||
|
||||
// Return the number of rows modified by those SQL statements (INSERT, UPDATE or DELETE only)
|
||||
return sqlite3_changes(getHandle());
|
||||
}
|
||||
|
||||
int Database::tryExec(const char* apQueries) noexcept
|
||||
{
|
||||
return sqlite3_exec(getHandle(), apQueries, nullptr, nullptr, nullptr);
|
||||
}
|
||||
|
||||
// Shortcut to execute a one step query and fetch the first column of the result.
|
||||
// WARNING: Be very careful with this dangerous method: you have to
|
||||
// make a COPY OF THE result, else it will be destroy before the next line
|
||||
|
@ -255,6 +255,64 @@ TEST(Database, exec)
|
||||
#endif
|
||||
}
|
||||
|
||||
TEST(Database, tryExec)
|
||||
{
|
||||
// Create a new database
|
||||
SQLite::Database db(":memory:", SQLite::OPEN_READWRITE);
|
||||
|
||||
// Create a new table with an explicit "id" column aliasing the underlying rowid
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("CREATE TABLE test (id INTEGER PRIMARY KEY, value TEXT)"));
|
||||
EXPECT_EQ(0, db.getLastInsertRowid());
|
||||
EXPECT_EQ(0, db.getTotalChanges());
|
||||
|
||||
// first row : insert the "first" text value into new row of id 1
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("INSERT INTO test VALUES (NULL, \"first\")"));
|
||||
EXPECT_EQ(1, db.getLastInsertRowid());
|
||||
EXPECT_EQ(1, db.getTotalChanges());
|
||||
|
||||
// second row : insert the "second" text value into new row of id 2
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("INSERT INTO test VALUES (NULL, \"second\")"));
|
||||
EXPECT_EQ(2, db.getLastInsertRowid());
|
||||
EXPECT_EQ(2, db.getTotalChanges());
|
||||
|
||||
// third row : insert the "third" text value into new row of id 3
|
||||
const std::string insert("INSERT INTO test VALUES (NULL, \"third\")");
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec(insert));
|
||||
EXPECT_EQ(3, db.getLastInsertRowid());
|
||||
EXPECT_EQ(3, db.getTotalChanges());
|
||||
|
||||
// update the second row : update text value to "second_updated"
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("UPDATE test SET value=\"second-updated\" WHERE id='2'"));
|
||||
EXPECT_EQ(3, db.getLastInsertRowid()); // last inserted row ID is still 3
|
||||
EXPECT_EQ(4, db.getTotalChanges());
|
||||
|
||||
// delete the third row
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("DELETE FROM test WHERE id='3'"));
|
||||
EXPECT_EQ(3, db.getLastInsertRowid());
|
||||
EXPECT_EQ(5, db.getTotalChanges());
|
||||
|
||||
// drop the whole table, ie the two remaining columns
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("DROP TABLE IF EXISTS test"));
|
||||
EXPECT_FALSE(db.tableExists("test"));
|
||||
EXPECT_EQ(5, db.getTotalChanges());
|
||||
|
||||
// Re-Create the same table
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("CREATE TABLE test (id INTEGER PRIMARY KEY, value TEXT)"));
|
||||
EXPECT_EQ(5, db.getTotalChanges());
|
||||
|
||||
// insert two rows with two *different* statements => returns only 1, ie. for the second INSERT statement
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("INSERT INTO test VALUES (NULL, \"first\");INSERT INTO test VALUES (NULL, \"second\");"));
|
||||
EXPECT_EQ(2, db.getLastInsertRowid());
|
||||
EXPECT_EQ(7, db.getTotalChanges());
|
||||
|
||||
#if (SQLITE_VERSION_NUMBER >= 3007011)
|
||||
// insert two rows with only one statement (starting with SQLite 3.7.11)
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("INSERT INTO test VALUES (NULL, \"third\"), (NULL, \"fourth\");"));
|
||||
EXPECT_EQ(4, db.getLastInsertRowid());
|
||||
EXPECT_EQ(9, db.getTotalChanges());
|
||||
#endif
|
||||
}
|
||||
|
||||
TEST(Database, execAndGet)
|
||||
{
|
||||
// Create a new database
|
||||
@ -314,6 +372,48 @@ TEST(Database, execException)
|
||||
EXPECT_STREQ("table test has 3 columns but 4 values were supplied", db.getErrorMsg());
|
||||
}
|
||||
|
||||
TEST(Database, tryExecError)
|
||||
{
|
||||
// Create a new database
|
||||
SQLite::Database db(":memory:", SQLite::OPEN_READWRITE);
|
||||
EXPECT_EQ(SQLite::OK, db.getErrorCode());
|
||||
EXPECT_EQ(SQLite::OK, db.getExtendedErrorCode());
|
||||
|
||||
// Insert into nonexistent table: "no such table"
|
||||
EXPECT_EQ(SQLITE_ERROR, db.tryExec("INSERT INTO test VALUES (NULL, \"first\", 3)"));
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getErrorCode());
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getExtendedErrorCode());
|
||||
EXPECT_STREQ("no such table: test", db.getErrorMsg());
|
||||
|
||||
// Create a new table
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("CREATE TABLE test (id INTEGER PRIMARY KEY, value TEXT, weight INTEGER)"));
|
||||
EXPECT_EQ(SQLite::OK, db.getErrorCode());
|
||||
EXPECT_EQ(SQLite::OK, db.getExtendedErrorCode());
|
||||
EXPECT_STREQ("not an error", db.getErrorMsg());
|
||||
|
||||
// Add a row with fewer values than columns in the table: "table test has 3 columns but 2 values were supplied"
|
||||
EXPECT_EQ(SQLITE_ERROR, db.tryExec("INSERT INTO test VALUES (NULL, 3)"));
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getErrorCode());
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getExtendedErrorCode());
|
||||
EXPECT_STREQ("table test has 3 columns but 2 values were supplied", db.getErrorMsg());
|
||||
|
||||
// Add a row with more values than columns in the table: "table test has 3 columns but 4 values were supplied"
|
||||
EXPECT_EQ(SQLITE_ERROR, db.tryExec("INSERT INTO test VALUES (NULL, \"first\", 123, 0.123)"));
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getErrorCode());
|
||||
EXPECT_EQ(SQLITE_ERROR, db.getExtendedErrorCode());
|
||||
EXPECT_STREQ("table test has 3 columns but 4 values were supplied", db.getErrorMsg());
|
||||
|
||||
// Create a first row
|
||||
EXPECT_EQ(SQLite::OK, db.tryExec("INSERT INTO test VALUES (NULL, \"first\", 3)"));
|
||||
EXPECT_EQ(1, db.getLastInsertRowid());
|
||||
|
||||
// Try to insert a new row with the same PRIMARY KEY: "UNIQUE constraint failed: test.id"
|
||||
EXPECT_EQ(SQLITE_CONSTRAINT, db.tryExec("INSERT INTO test VALUES (1, \"impossible\", 456)"));
|
||||
EXPECT_EQ(SQLITE_CONSTRAINT, db.getErrorCode());
|
||||
EXPECT_EQ(SQLITE_CONSTRAINT_PRIMARYKEY, db.getExtendedErrorCode());
|
||||
EXPECT_STREQ("UNIQUE constraint failed: test.id", db.getErrorMsg());
|
||||
}
|
||||
|
||||
// From https://stackoverflow.com/a/8283265/1163698 How can I create a user-defined function in SQLite?
|
||||
static void firstchar(sqlite3_context *context, int argc, sqlite3_value **argv)
|
||||
{
|
||||
|
Loading…
x
Reference in New Issue
Block a user