2022-12-16 12:29:58 (UTC-03:00)
Marcel Rodrigues <marcelgmr@gmail.com>
sqlite: switch to more flexible query execution
Formerly we're using SQlite's One-Step Query Execution Interface.
The main limitation of that interface is that we cannot safely pass
parameters to queries.
SQlite has sqlite3_bind_*() functions that allows safe interpolation
of parameters into queries, but this requires the multi-step query
execution interface implemented in this change.
Now we can run parametized queries like this:
local user = db:execute("SELECT * FROM User WHERE User.nick = ?", nick)[1]
diff --git a/src/sqlite.lua b/src/sqlite.lua index a2c104b..8daa160 100644 --- a/src/sqlite.lua +++ b/src/sqlite.lua @@ -2,42 +2,88 @@ local ffi = require "ffi" ffi.cdef[[ typedef struct sqlite3 sqlite3; +typedef struct sqlite3_stmt sqlite3_stmt; int sqlite3_open( const char *filename, /* Database filename (UTF-8) */ sqlite3 **ppDb /* OUT: SQLite db handle */ ); int sqlite3_close(sqlite3*); -int sqlite3_exec( - sqlite3*, /* An open database */ - const char *sql, /* SQL to be evaluated */ - int (*callback)(void*,int,char**,char**), /* Callback function */ - void *, /* 1st argument to callback */ - char **errmsg /* Error msg written here */ -); +int sqlite3_prepare_v2(sqlite3 *conn, const char *zSql, int nByte, + sqlite3_stmt **ppStmt, const char **pzTail); +int sqlite3_bind_null(sqlite3_stmt*, int); +int sqlite3_bind_double(sqlite3_stmt*, int, double); +int sqlite3_bind_text(sqlite3_stmt*,int,const char*,int,void(*)(void*)); +int sqlite3_step(sqlite3_stmt*); +int sqlite3_column_count(sqlite3_stmt *pStmt); +const char *sqlite3_column_name(sqlite3_stmt*, int N); +int sqlite3_column_type(sqlite3_stmt*, int iCol); +int sqlite3_column_int(sqlite3_stmt*, int iCol); +double sqlite3_column_double(sqlite3_stmt*, int iCol); +const unsigned char *sqlite3_column_text(sqlite3_stmt*, int iCol); +const void *sqlite3_column_blob(sqlite3_stmt*, int iCol); +int sqlite3_reset(sqlite3_stmt *pStmt); +int sqlite3_finalize(sqlite3_stmt *pStmt); ]] local C = ffi.load("sqlite3") +local CODE = { + [0] = "OK", "ERROR", "INTERNAL", "PERM", "ABORT", "BUSY", "LOCKED", "NOMEM", + "READONLY", "INTERRUPT", "IOERR", "CORRUPT", "NOTFOUND", "FULL", "CANTOPEN", + "PROTOCOL", "EMPTY", "SCHEMA", "TOOBIG", "CONSTRAINT", "MISMATCH", "MISUSE", + "NOLFS", "AUTH", "FORMAT", "RANGE", "NOTADB", "NOTICE", "WARNING", + [100] = "ROW", [101] = "DONE" +} + +local TYPE = {"INTEGER", "FLOAT", "TEXT", "BLOB", "NULL"} + local DB = {} DB.__index = DB -function DB:execute(sql, cb, arg) - if C.sqlite3_exec(self.db, sql, cb, arg, self.err) ~= 0 then - print(ffi.string(self.err[0])) +function DB:execute(sql, ...) + local pstmt = ffi.new("sqlite3_stmt *[1]") + local res = CODE[C.sqlite3_prepare_v2(self.db, sql, #sql, pstmt, nil)] + if res ~= "OK" then error(sql) end + local stmt = pstmt[0] + local arg = {...} + for i, v in ipairs(arg) do + if type(v) == "nil" then + C.sqlite3_bind_null(stmt, i) + elseif type(v) == "number" then + C.sqlite3_bind_double(stmt, i, v) + elseif type(v) == "string" then + C.sqlite3_bind_text(stmt, i, v, #v, ffi.cast("void(*)(void*)", 0)) + else + error(("invalid type for query parameter: %s"):format(type(v))) + end end -end - -function DB:get_rows(sql) local rows = {} - self:execute(sql, function (obj, argc, argv, col) - local row = {} - for i = 0, argc-1 do - local col_name = ffi.string(col[i]) - local col_value = ffi.string(argv[i]) - row[col_name] = col_value + repeat + local done = true + local res = CODE[C.sqlite3_step(stmt)] + -- TODO: handle res == "BUSY" + if res == "ROW" then + local row = {} + local ncols = C.sqlite3_column_count(stmt) + for i = 0, ncols-1 do + local col_name = ffi.string(C.sqlite3_column_name(stmt, i)) + local col_type = TYPE[C.sqlite3_column_type(stmt, i)] + local value + if col_type == "INTEGER" then + value = C.sqlite3_column_int(stmt, i) + elseif col_type == "FLOAT" then + value = C.sqlite3_column_double(stmt, i) + elseif col_type == "TEXT" then + value = ffi.string(C.sqlite3_column_text(stmt, i)) + elseif col_type == "BLOB" then + value = C.sqlite3_column_blob(stmt, i) + end + row[col_name] = value + end + table.insert(rows, row) + done = false end - table.insert(rows, row) - return 0 - end) + until done + C.sqlite3_finalize(stmt) return rows end