656 lines
15 KiB
Lua
656 lines
15 KiB
Lua
local str = require("string")
|
|
local sqlite = {}
|
|
|
|
local Connection = {}
|
|
Connection.__index = Connection
|
|
|
|
function Connection:close()
|
|
if self._id then
|
|
local ok = moonshark.sql_close(self._id)
|
|
self._id = nil
|
|
return ok
|
|
end
|
|
return false
|
|
end
|
|
|
|
function Connection:ping()
|
|
if not self._id then
|
|
error("Connection is closed")
|
|
end
|
|
return moonshark.sql_ping(self._id)
|
|
end
|
|
|
|
function Connection:query(query_str, ...)
|
|
if not self._id then
|
|
error("Connection is closed")
|
|
end
|
|
query_str = str.normalize_whitespace(query_str)
|
|
return moonshark.sql_query(self._id, query_str, ...)
|
|
end
|
|
|
|
function Connection:exec(query_str, ...)
|
|
if not self._id then
|
|
error("Connection is closed")
|
|
end
|
|
query_str = str.normalize_whitespace(query_str)
|
|
return moonshark.sql_exec(self._id, query_str, ...)
|
|
end
|
|
|
|
function Connection:query_row(query_str, ...)
|
|
local results = self:query(query_str, ...)
|
|
if results and #results > 0 then
|
|
return results[1]
|
|
end
|
|
return nil
|
|
end
|
|
|
|
function Connection:query_value(query_str, ...)
|
|
local row = self:query_row(query_str, ...)
|
|
if row then
|
|
for _, value in pairs(row) do
|
|
return value
|
|
end
|
|
end
|
|
return nil
|
|
end
|
|
|
|
-- Enhanced transaction support
|
|
function Connection:begin()
|
|
local result = self:exec("BEGIN")
|
|
if result then
|
|
return {
|
|
conn = self,
|
|
active = true,
|
|
|
|
commit = function(tx)
|
|
if tx.active then
|
|
local result = tx.conn:exec("COMMIT")
|
|
tx.active = false
|
|
return result
|
|
end
|
|
return false
|
|
end,
|
|
|
|
rollback = function(tx)
|
|
if tx.active then
|
|
local result = tx.conn:exec("ROLLBACK")
|
|
tx.active = false
|
|
return result
|
|
end
|
|
return false
|
|
end,
|
|
|
|
query = function(tx, query_str, ...)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
return tx.conn:query(query_str, ...)
|
|
end,
|
|
|
|
exec = function(tx, query_str, ...)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
return tx.conn:exec(query_str, ...)
|
|
end,
|
|
|
|
query_row = function(tx, query_str, ...)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
return tx.conn:query_row(query_str, ...)
|
|
end,
|
|
|
|
query_value = function(tx, query_str, ...)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
return tx.conn:query_value(query_str, ...)
|
|
end
|
|
}
|
|
end
|
|
return nil
|
|
end
|
|
|
|
-- Enhanced query builder helpers with string utilities
|
|
function Connection:insert(table_name, data)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local keys = {}
|
|
local values = {}
|
|
local placeholders = {}
|
|
|
|
for key, value in pairs(data) do
|
|
table.insert(keys, key)
|
|
table.insert(values, value)
|
|
table.insert(placeholders, "?")
|
|
end
|
|
|
|
local query = str.template("INSERT INTO ${table} (${columns}) VALUES (${placeholders})", {
|
|
table = table_name,
|
|
columns = str.join(keys, ", "),
|
|
placeholders = str.join(placeholders, ", ")
|
|
})
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:upsert(table_name, data, conflict_columns)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local keys = {}
|
|
local values = {}
|
|
local placeholders = {}
|
|
local updates = {}
|
|
|
|
for key, value in pairs(data) do
|
|
table.insert(keys, key)
|
|
table.insert(values, value)
|
|
table.insert(placeholders, "?")
|
|
table.insert(updates, str.template("${key} = excluded.${key}", {key = key}))
|
|
end
|
|
|
|
local conflict_clause = ""
|
|
if conflict_columns then
|
|
if type(conflict_columns) == "string" then
|
|
conflict_clause = str.template("(${columns})", {columns = conflict_columns})
|
|
else
|
|
conflict_clause = str.template("(${columns})", {columns = str.join(conflict_columns, ", ")})
|
|
end
|
|
end
|
|
|
|
local query = str.template("INSERT INTO ${table} (${columns}) VALUES (${placeholders}) ON CONFLICT ${conflict} DO UPDATE SET ${updates}", {
|
|
table = table_name,
|
|
columns = str.join(keys, ", "),
|
|
placeholders = str.join(placeholders, ", "),
|
|
conflict = conflict_clause,
|
|
updates = str.join(updates, ", ")
|
|
})
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:update(table_name, data, where_clause, ...)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
if str.is_blank(where_clause) then
|
|
error("WHERE clause cannot be empty for UPDATE")
|
|
end
|
|
|
|
local sets = {}
|
|
local values = {}
|
|
|
|
for key, value in pairs(data) do
|
|
table.insert(sets, str.template("${key} = ?", {key = key}))
|
|
table.insert(values, value)
|
|
end
|
|
|
|
local query = str.template("UPDATE ${table} SET ${sets} WHERE ${where}", {
|
|
table = table_name,
|
|
sets = str.join(sets, ", "),
|
|
where = where_clause
|
|
})
|
|
|
|
-- Add WHERE clause parameters
|
|
local where_args = {...}
|
|
for i = 1, #where_args do
|
|
table.insert(values, where_args[i])
|
|
end
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:delete(table_name, where_clause, ...)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
if str.is_blank(where_clause) then
|
|
error("WHERE clause cannot be empty for DELETE")
|
|
end
|
|
|
|
local query = str.template("DELETE FROM ${table} WHERE ${where}", {
|
|
table = table_name,
|
|
where = where_clause
|
|
})
|
|
return self:exec(query, ...)
|
|
end
|
|
|
|
function Connection:select(table_name, columns, where_clause, ...)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
columns = columns or "*"
|
|
if type(columns) == "table" then
|
|
columns = str.join(columns, ", ")
|
|
end
|
|
|
|
local query
|
|
if where_clause and not str.is_blank(where_clause) then
|
|
query = str.template("SELECT ${columns} FROM ${table} WHERE ${where}", {
|
|
columns = columns,
|
|
table = table_name,
|
|
where = where_clause
|
|
})
|
|
return self:query(query, ...)
|
|
else
|
|
query = str.template("SELECT ${columns} FROM ${table}", {
|
|
columns = columns,
|
|
table = table_name
|
|
})
|
|
return self:query(query)
|
|
end
|
|
end
|
|
|
|
-- Enhanced schema helpers with validation
|
|
function Connection:table_exists(table_name)
|
|
if str.is_blank(table_name) then
|
|
return false
|
|
end
|
|
|
|
local result = self:query_value(
|
|
"SELECT name FROM sqlite_master WHERE type='table' AND name=?",
|
|
str.trim(table_name)
|
|
)
|
|
return result ~= nil
|
|
end
|
|
|
|
function Connection:column_exists(table_name, column_name)
|
|
if str.is_blank(table_name) or str.is_blank(column_name) then
|
|
return false
|
|
end
|
|
|
|
local result = self:query(str.template("PRAGMA table_info(${table})", {table = table_name}))
|
|
if result then
|
|
for _, row in ipairs(result) do
|
|
if str.iequals(row.name, str.trim(column_name)) then
|
|
return true
|
|
end
|
|
end
|
|
end
|
|
return false
|
|
end
|
|
|
|
function Connection:create_table(table_name, schema)
|
|
if str.is_blank(table_name) or str.is_blank(schema) then
|
|
error("Table name and schema cannot be empty")
|
|
end
|
|
|
|
local query = str.template("CREATE TABLE IF NOT EXISTS ${table} (${schema})", {
|
|
table = table_name,
|
|
schema = str.trim(schema)
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_table(table_name)
|
|
if str.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local query = str.template("DROP TABLE IF EXISTS ${table}", {table = table_name})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:add_column(table_name, column_def)
|
|
if str.is_blank(table_name) or str.is_blank(column_def) then
|
|
error("Table name and column definition cannot be empty")
|
|
end
|
|
|
|
local query = str.template("ALTER TABLE ${table} ADD COLUMN ${column}", {
|
|
table = table_name,
|
|
column = str.trim(column_def)
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:create_index(index_name, table_name, columns, unique)
|
|
if str.is_blank(index_name) or str.is_blank(table_name) then
|
|
error("Index name and table name cannot be empty")
|
|
end
|
|
|
|
local unique_clause = unique and "UNIQUE " or ""
|
|
local columns_str = type(columns) == "table" and str.join(columns, ", ") or tostring(columns)
|
|
|
|
local query = str.template("CREATE ${unique}INDEX IF NOT EXISTS ${index} ON ${table} (${columns})", {
|
|
unique = unique_clause,
|
|
index = index_name,
|
|
table = table_name,
|
|
columns = columns_str
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_index(index_name)
|
|
if str.is_blank(index_name) then
|
|
error("Index name cannot be empty")
|
|
end
|
|
|
|
local query = str.template("DROP INDEX IF EXISTS ${index}", {index = index_name})
|
|
return self:exec(query)
|
|
end
|
|
|
|
-- Enhanced SQLite-specific functions
|
|
function Connection:vacuum()
|
|
return self:exec("VACUUM")
|
|
end
|
|
|
|
function Connection:analyze()
|
|
return self:exec("ANALYZE")
|
|
end
|
|
|
|
function Connection:integrity_check()
|
|
return self:query("PRAGMA integrity_check")
|
|
end
|
|
|
|
function Connection:foreign_keys(enabled)
|
|
local value = enabled and "ON" or "OFF"
|
|
return self:exec(str.template("PRAGMA foreign_keys = ${value}", {value = value}))
|
|
end
|
|
|
|
function Connection:journal_mode(mode)
|
|
mode = mode or "WAL"
|
|
if not str.contains(str.upper(mode), "DELETE") and
|
|
not str.contains(str.upper(mode), "TRUNCATE") and
|
|
not str.contains(str.upper(mode), "PERSIST") and
|
|
not str.contains(str.upper(mode), "MEMORY") and
|
|
not str.contains(str.upper(mode), "WAL") and
|
|
not str.contains(str.upper(mode), "OFF") then
|
|
error("Invalid journal mode: " .. mode)
|
|
end
|
|
return self:query(str.template("PRAGMA journal_mode = ${mode}", {mode = str.upper(mode)}))
|
|
end
|
|
|
|
function Connection:synchronous(level)
|
|
level = level or "NORMAL"
|
|
local valid_levels = {"OFF", "NORMAL", "FULL", "EXTRA"}
|
|
local level_upper = str.upper(level)
|
|
|
|
local valid = false
|
|
for _, valid_level in ipairs(valid_levels) do
|
|
if level_upper == valid_level then
|
|
valid = true
|
|
break
|
|
end
|
|
end
|
|
|
|
if not valid then
|
|
error("Invalid synchronous level: " .. level)
|
|
end
|
|
|
|
return self:exec(str.template("PRAGMA synchronous = ${level}", {level = level_upper}))
|
|
end
|
|
|
|
function Connection:cache_size(size)
|
|
size = size or -64000
|
|
if type(size) ~= "number" then
|
|
error("Cache size must be a number")
|
|
end
|
|
return self:exec(str.template("PRAGMA cache_size = ${size}", {size = tostring(size)}))
|
|
end
|
|
|
|
function Connection:temp_store(mode)
|
|
mode = mode or "MEMORY"
|
|
local valid_modes = {"DEFAULT", "FILE", "MEMORY"}
|
|
local mode_upper = str.upper(mode)
|
|
|
|
local valid = false
|
|
for _, valid_mode in ipairs(valid_modes) do
|
|
if mode_upper == valid_mode then
|
|
valid = true
|
|
break
|
|
end
|
|
end
|
|
|
|
if not valid then
|
|
error("Invalid temp_store mode: " .. mode)
|
|
end
|
|
|
|
return self:exec(str.template("PRAGMA temp_store = ${mode}", {mode = mode_upper}))
|
|
end
|
|
|
|
-- Connection management with enhanced path handling
|
|
function sqlite.open(database_path)
|
|
database_path = database_path or ":memory:"
|
|
|
|
-- Clean up path
|
|
if database_path ~= ":memory:" then
|
|
database_path = str.trim(database_path)
|
|
if str.is_blank(database_path) then
|
|
database_path = ":memory:"
|
|
end
|
|
end
|
|
|
|
local conn_id = moonshark.sql_connect("sqlite", database_path)
|
|
if conn_id then
|
|
local conn = {_id = conn_id}
|
|
setmetatable(conn, Connection)
|
|
return conn
|
|
end
|
|
return nil
|
|
end
|
|
|
|
sqlite.connect = sqlite.open
|
|
|
|
-- Enhanced quick execution functions
|
|
function sqlite.query(database_path, query_str, ...)
|
|
local conn = sqlite.open(database_path)
|
|
if not conn then
|
|
error(str.template("Failed to open SQLite database: ${path}", {
|
|
path = database_path or ":memory:"
|
|
}))
|
|
end
|
|
|
|
local results = conn:query(query_str, ...)
|
|
conn:close()
|
|
return results
|
|
end
|
|
|
|
function sqlite.exec(database_path, query_str, ...)
|
|
local conn = sqlite.open(database_path)
|
|
if not conn then
|
|
error(str.template("Failed to open SQLite database: ${path}", {
|
|
path = database_path or ":memory:"
|
|
}))
|
|
end
|
|
|
|
local result = conn:exec(query_str, ...)
|
|
conn:close()
|
|
return result
|
|
end
|
|
|
|
function sqlite.query_row(database_path, query_str, ...)
|
|
local results = sqlite.query(database_path, query_str, ...)
|
|
if results and #results > 0 then
|
|
return results[1]
|
|
end
|
|
return nil
|
|
end
|
|
|
|
function sqlite.query_value(database_path, query_str, ...)
|
|
local row = sqlite.query_row(database_path, query_str, ...)
|
|
if row then
|
|
for _, value in pairs(row) do
|
|
return value
|
|
end
|
|
end
|
|
return nil
|
|
end
|
|
|
|
-- Enhanced migration helpers
|
|
function sqlite.migrate(database_path, migrations)
|
|
local conn = sqlite.open(database_path)
|
|
if not conn then
|
|
error("Failed to open SQLite database for migration")
|
|
end
|
|
|
|
-- Create migrations table
|
|
conn:create_table("_migrations",
|
|
"id INTEGER PRIMARY KEY, name TEXT UNIQUE, applied_at DATETIME DEFAULT CURRENT_TIMESTAMP")
|
|
|
|
local tx = conn:begin()
|
|
if not tx then
|
|
conn:close()
|
|
error("Failed to begin migration transaction")
|
|
end
|
|
|
|
local success = true
|
|
local error_msg = ""
|
|
|
|
for _, migration in ipairs(migrations) do
|
|
if not migration.name or str.is_blank(migration.name) then
|
|
error_msg = "Migration must have a non-empty name"
|
|
success = false
|
|
break
|
|
end
|
|
|
|
-- Check if migration already applied
|
|
local existing = conn:query_value("SELECT id FROM _migrations WHERE name = ?",
|
|
str.trim(migration.name))
|
|
if not existing then
|
|
local ok, err = pcall(function()
|
|
if type(migration.up) == "string" then
|
|
conn:exec(migration.up)
|
|
elseif type(migration.up) == "function" then
|
|
migration.up(conn)
|
|
else
|
|
error("Migration 'up' must be string or function")
|
|
end
|
|
end)
|
|
|
|
if ok then
|
|
conn:exec("INSERT INTO _migrations (name) VALUES (?)", str.trim(migration.name))
|
|
print(str.template("Applied migration: ${name}", {name = migration.name}))
|
|
else
|
|
success = false
|
|
error_msg = str.template("Migration '${name}' failed: ${error}", {
|
|
name = migration.name,
|
|
error = err or "unknown error"
|
|
})
|
|
break
|
|
end
|
|
end
|
|
end
|
|
|
|
if success then
|
|
tx:commit()
|
|
else
|
|
tx:rollback()
|
|
conn:close()
|
|
error(error_msg)
|
|
end
|
|
|
|
conn:close()
|
|
return true
|
|
end
|
|
|
|
-- Enhanced result processing utilities
|
|
function sqlite.to_array(results, column_name)
|
|
if not results or #results == 0 then
|
|
return {}
|
|
end
|
|
|
|
if str.is_blank(column_name) then
|
|
error("Column name cannot be empty")
|
|
end
|
|
|
|
local array = {}
|
|
for i, row in ipairs(results) do
|
|
array[i] = row[column_name]
|
|
end
|
|
return array
|
|
end
|
|
|
|
function sqlite.to_map(results, key_column, value_column)
|
|
if not results or #results == 0 then
|
|
return {}
|
|
end
|
|
|
|
if str.is_blank(key_column) then
|
|
error("Key column name cannot be empty")
|
|
end
|
|
|
|
local map = {}
|
|
for _, row in ipairs(results) do
|
|
local key = row[key_column]
|
|
map[key] = value_column and row[value_column] or row
|
|
end
|
|
return map
|
|
end
|
|
|
|
function sqlite.group_by(results, column_name)
|
|
if not results or #results == 0 then
|
|
return {}
|
|
end
|
|
|
|
if str.is_blank(column_name) then
|
|
error("Column name cannot be empty")
|
|
end
|
|
|
|
local groups = {}
|
|
for _, row in ipairs(results) do
|
|
local key = row[column_name]
|
|
if not groups[key] then
|
|
groups[key] = {}
|
|
end
|
|
table.insert(groups[key], row)
|
|
end
|
|
return groups
|
|
end
|
|
|
|
-- Enhanced debug helper
|
|
function sqlite.print_results(results)
|
|
if not results or #results == 0 then
|
|
print("No results")
|
|
return
|
|
end
|
|
|
|
-- Get column names from first row
|
|
local columns = {}
|
|
for col, _ in pairs(results[1]) do
|
|
table.insert(columns, col)
|
|
end
|
|
table.sort(columns)
|
|
|
|
-- Calculate column widths for better formatting
|
|
local widths = {}
|
|
for _, col in ipairs(columns) do
|
|
widths[col] = str.length(col)
|
|
end
|
|
|
|
for _, row in ipairs(results) do
|
|
for _, col in ipairs(columns) do
|
|
local value = tostring(row[col] or "")
|
|
widths[col] = math.max(widths[col], str.length(value))
|
|
end
|
|
end
|
|
|
|
-- Print header with proper spacing
|
|
local header_parts = {}
|
|
local separator_parts = {}
|
|
for _, col in ipairs(columns) do
|
|
table.insert(header_parts, str.pad_right(col, widths[col]))
|
|
table.insert(separator_parts, str.repeat_("-", widths[col]))
|
|
end
|
|
|
|
print(str.join(header_parts, " | "))
|
|
print(str.join(separator_parts, "-+-"))
|
|
|
|
-- Print rows with proper spacing
|
|
for _, row in ipairs(results) do
|
|
local value_parts = {}
|
|
for _, col in ipairs(columns) do
|
|
local value = tostring(row[col] or "")
|
|
table.insert(value_parts, str.pad_right(value, widths[col]))
|
|
end
|
|
print(str.join(value_parts, " | "))
|
|
end
|
|
end
|
|
|
|
return sqlite
|