951 lines
25 KiB
Lua
951 lines
25 KiB
Lua
local tbl = require("table")
|
|
local mysql = {}
|
|
|
|
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 = string.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 = string.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 with savepoints
|
|
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,
|
|
|
|
savepoint = function(tx, name)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
if string.is_blank(name) then
|
|
error("Savepoint name cannot be empty")
|
|
end
|
|
return tx.conn:exec(string.template("SAVEPOINT ${name}", {name = name}))
|
|
end,
|
|
|
|
rollback_to = function(tx, name)
|
|
if not tx.active then
|
|
error("Transaction is not active")
|
|
end
|
|
if string.is_blank(name) then
|
|
error("Savepoint name cannot be empty")
|
|
end
|
|
return tx.conn:exec(string.template("ROLLBACK TO SAVEPOINT ${name}", {name = name}))
|
|
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
|
|
|
|
-- Simplified MySQL-specific query builder helpers
|
|
function Connection:insert(table_name, data)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local keys = tbl.keys(data)
|
|
local values = tbl.values(data)
|
|
local placeholders = tbl.map(keys, function() return "?" end)
|
|
|
|
local query = string.template("INSERT INTO ${table} (${columns}) VALUES (${placeholders})", {
|
|
table = table_name,
|
|
columns = tbl.concat(keys, ", "),
|
|
placeholders = tbl.concat(placeholders, ", ")
|
|
})
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:upsert(table_name, data, update_data)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local keys = tbl.keys(data)
|
|
local values = tbl.values(data)
|
|
local placeholders = tbl.map(keys, function() return "?" end)
|
|
|
|
-- Use update_data if provided, otherwise update with same data
|
|
local update_source = update_data or data
|
|
local updates = tbl.map(tbl.keys(update_source), function(key)
|
|
return string.template("${key} = VALUES(${key})", {key = key})
|
|
end)
|
|
|
|
local query = string.template("INSERT INTO ${table} (${columns}) VALUES (${placeholders}) ON DUPLICATE KEY UPDATE ${updates}", {
|
|
table = table_name,
|
|
columns = tbl.concat(keys, ", "),
|
|
placeholders = tbl.concat(placeholders, ", "),
|
|
updates = tbl.concat(updates, ", ")
|
|
})
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:replace(table_name, data)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local keys = tbl.keys(data)
|
|
local values = tbl.values(data)
|
|
local placeholders = tbl.map(keys, function() return "?" end)
|
|
|
|
local query = string.template("REPLACE INTO ${table} (${columns}) VALUES (${placeholders})", {
|
|
table = table_name,
|
|
columns = tbl.concat(keys, ", "),
|
|
placeholders = tbl.concat(placeholders, ", ")
|
|
})
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:update(table_name, data, where_clause, ...)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
if string.is_blank(where_clause) then
|
|
error("WHERE clause cannot be empty for UPDATE")
|
|
end
|
|
|
|
local keys = tbl.keys(data)
|
|
local values = tbl.values(data)
|
|
local sets = tbl.map(keys, function(key)
|
|
return string.template("${key} = ?", {key = key})
|
|
end)
|
|
|
|
local query = string.template("UPDATE ${table} SET ${sets} WHERE ${where}", {
|
|
table = table_name,
|
|
sets = tbl.concat(sets, ", "),
|
|
where = where_clause
|
|
})
|
|
|
|
-- Add WHERE clause parameters
|
|
local where_args = {...}
|
|
tbl.extend(values, where_args)
|
|
|
|
return self:exec(query, unpack(values))
|
|
end
|
|
|
|
function Connection:delete(table_name, where_clause, ...)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
if string.is_blank(where_clause) then
|
|
error("WHERE clause cannot be empty for DELETE")
|
|
end
|
|
|
|
local query = string.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 string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
columns = columns or "*"
|
|
if type(columns) == "table" then
|
|
columns = tbl.concat(columns, ", ")
|
|
end
|
|
|
|
local query
|
|
if where_clause and not string.is_blank(where_clause) then
|
|
query = string.template("SELECT ${columns} FROM ${table} WHERE ${where}", {
|
|
columns = columns,
|
|
table = table_name,
|
|
where = where_clause
|
|
})
|
|
return self:query(query, ...)
|
|
else
|
|
query = string.template("SELECT ${columns} FROM ${table}", {
|
|
columns = columns,
|
|
table = table_name
|
|
})
|
|
return self:query(query)
|
|
end
|
|
end
|
|
|
|
-- MySQL schema helpers
|
|
function Connection:database_exists(database_name)
|
|
if string.is_blank(database_name) then
|
|
return false
|
|
end
|
|
|
|
local result = self:query_value(
|
|
"SELECT SCHEMA_NAME FROM information_schema.SCHEMATA WHERE SCHEMA_NAME = ?",
|
|
string.trim(database_name)
|
|
)
|
|
return result ~= nil
|
|
end
|
|
|
|
function Connection:table_exists(table_name, database_name)
|
|
if string.is_blank(table_name) then
|
|
return false
|
|
end
|
|
|
|
database_name = database_name or self:current_database()
|
|
if not database_name then
|
|
return false
|
|
end
|
|
|
|
local result = self:query_value(
|
|
"SELECT TABLE_NAME FROM information_schema.TABLES WHERE TABLE_SCHEMA = ? AND TABLE_NAME = ?",
|
|
string.trim(database_name), string.trim(table_name)
|
|
)
|
|
return result ~= nil
|
|
end
|
|
|
|
function Connection:column_exists(table_name, column_name, database_name)
|
|
if string.is_blank(table_name) or string.is_blank(column_name) then
|
|
return false
|
|
end
|
|
|
|
database_name = database_name or self:current_database()
|
|
if not database_name then
|
|
return false
|
|
end
|
|
|
|
local result = self:query_value([[
|
|
SELECT COLUMN_NAME FROM information_schema.COLUMNS
|
|
WHERE TABLE_SCHEMA = ? AND TABLE_NAME = ? AND COLUMN_NAME = ?
|
|
]], string.trim(database_name), string.trim(table_name), string.trim(column_name))
|
|
return result ~= nil
|
|
end
|
|
|
|
function Connection:create_database(database_name, charset, collation)
|
|
if string.is_blank(database_name) then
|
|
error("Database name cannot be empty")
|
|
end
|
|
|
|
local charset_clause = charset and string.template(" CHARACTER SET ${charset}", {charset = charset}) or ""
|
|
local collation_clause = collation and string.template(" COLLATE ${collation}", {collation = collation}) or ""
|
|
|
|
local query = string.template("CREATE DATABASE IF NOT EXISTS ${database}${charset}${collation}", {
|
|
database = database_name,
|
|
charset = charset_clause,
|
|
collation = collation_clause
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_database(database_name)
|
|
if string.is_blank(database_name) then
|
|
error("Database name cannot be empty")
|
|
end
|
|
|
|
local query = string.template("DROP DATABASE IF EXISTS ${database}", {database = database_name})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:create_table(table_name, schema, engine, charset)
|
|
if string.is_blank(table_name) or string.is_blank(schema) then
|
|
error("Table name and schema cannot be empty")
|
|
end
|
|
|
|
local engine_clause = engine and string.template(" ENGINE=${engine}", {engine = string.upper(engine)}) or ""
|
|
local charset_clause = charset and string.template(" CHARACTER SET ${charset}", {charset = charset}) or ""
|
|
|
|
local query = string.template("CREATE TABLE IF NOT EXISTS ${table} (${schema})${engine}${charset}", {
|
|
table = table_name,
|
|
schema = string.trim(schema),
|
|
engine = engine_clause,
|
|
charset = charset_clause
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_table(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
|
|
local query = string.template("DROP TABLE IF EXISTS ${table}", {table = table_name})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:add_column(table_name, column_def, position)
|
|
if string.is_blank(table_name) or string.is_blank(column_def) then
|
|
error("Table name and column definition cannot be empty")
|
|
end
|
|
|
|
local position_clause = position and string.template(" ${position}", {position = position}) or ""
|
|
local query = string.template("ALTER TABLE ${table} ADD COLUMN ${column}${position}", {
|
|
table = table_name,
|
|
column = string.trim(column_def),
|
|
position = position_clause
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_column(table_name, column_name)
|
|
if string.is_blank(table_name) or string.is_blank(column_name) then
|
|
error("Table name and column name cannot be empty")
|
|
end
|
|
|
|
local query = string.template("ALTER TABLE ${table} DROP COLUMN ${column}", {
|
|
table = table_name,
|
|
column = column_name
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:modify_column(table_name, column_def)
|
|
if string.is_blank(table_name) or string.is_blank(column_def) then
|
|
error("Table name and column definition cannot be empty")
|
|
end
|
|
|
|
local query = string.template("ALTER TABLE ${table} MODIFY COLUMN ${column}", {
|
|
table = table_name,
|
|
column = string.trim(column_def)
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:rename_table(old_name, new_name)
|
|
if string.is_blank(old_name) or string.is_blank(new_name) then
|
|
error("Old and new table names cannot be empty")
|
|
end
|
|
|
|
local query = string.template("RENAME TABLE ${old} TO ${new}", {
|
|
old = old_name,
|
|
new = new_name
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:create_index(index_name, table_name, columns, unique, type)
|
|
if string.is_blank(index_name) or string.is_blank(table_name) then
|
|
error("Index name and table name cannot be empty")
|
|
end
|
|
|
|
local unique_clause = unique and "UNIQUE " or ""
|
|
local type_clause = type and string.template(" USING ${type}", {type = string.upper(type)}) or ""
|
|
local columns_str = type(columns) == "table" and tbl.concat(columns, ", ") or tostring(columns)
|
|
|
|
local query = string.template("CREATE ${unique}INDEX ${index} ON ${table} (${columns})${type}", {
|
|
unique = unique_clause,
|
|
index = index_name,
|
|
table = table_name,
|
|
columns = columns_str,
|
|
type = type_clause
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:drop_index(index_name, table_name)
|
|
if string.is_blank(index_name) or string.is_blank(table_name) then
|
|
error("Index name and table name cannot be empty")
|
|
end
|
|
|
|
local query = string.template("DROP INDEX ${index} ON ${table}", {
|
|
index = index_name,
|
|
table = table_name
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
-- MySQL maintenance functions
|
|
function Connection:optimize(table_name)
|
|
local table_clause = table_name and string.template(" ${table}", {table = table_name}) or ""
|
|
return self:query(string.template("OPTIMIZE TABLE${table}", {table = table_clause}))
|
|
end
|
|
|
|
function Connection:repair(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty for REPAIR")
|
|
end
|
|
return self:query(string.template("REPAIR TABLE ${table}", {table = table_name}))
|
|
end
|
|
|
|
function Connection:check_table(table_name, options)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty for CHECK")
|
|
end
|
|
|
|
local options_clause = ""
|
|
if options then
|
|
local valid_options = {"QUICK", "FAST", "MEDIUM", "EXTENDED", "CHANGED"}
|
|
local options_upper = string.upper(options)
|
|
|
|
if tbl.contains(valid_options, options_upper) then
|
|
options_clause = string.template(" ${options}", {options = options_upper})
|
|
end
|
|
end
|
|
|
|
return self:query(string.template("CHECK TABLE ${table}${options}", {
|
|
table = table_name,
|
|
options = options_clause
|
|
}))
|
|
end
|
|
|
|
function Connection:analyze_table(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty for ANALYZE")
|
|
end
|
|
return self:query(string.template("ANALYZE TABLE ${table}", {table = table_name}))
|
|
end
|
|
|
|
-- MySQL settings and introspection
|
|
function Connection:show(what)
|
|
if string.is_blank(what) then
|
|
error("SHOW parameter cannot be empty")
|
|
end
|
|
return self:query(string.template("SHOW ${what}", {what = string.upper(what)}))
|
|
end
|
|
|
|
function Connection:current_database()
|
|
return self:query_value("SELECT DATABASE() AS db")
|
|
end
|
|
|
|
function Connection:version()
|
|
return self:query_value("SELECT VERSION() AS version")
|
|
end
|
|
|
|
function Connection:connection_id()
|
|
return self:query_value("SELECT CONNECTION_ID()")
|
|
end
|
|
|
|
function Connection:list_databases()
|
|
return self:query("SHOW DATABASES")
|
|
end
|
|
|
|
function Connection:list_tables(database_name)
|
|
if database_name and not string.is_blank(database_name) then
|
|
return self:query(string.template("SHOW TABLES FROM ${database}", {database = database_name}))
|
|
else
|
|
return self:query("SHOW TABLES")
|
|
end
|
|
end
|
|
|
|
function Connection:describe_table(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
return self:query(string.template("DESCRIBE ${table}", {table = table_name}))
|
|
end
|
|
|
|
function Connection:show_create_table(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
return self:query(string.template("SHOW CREATE TABLE ${table}", {table = table_name}))
|
|
end
|
|
|
|
function Connection:show_indexes(table_name)
|
|
if string.is_blank(table_name) then
|
|
error("Table name cannot be empty")
|
|
end
|
|
return self:query(string.template("SHOW INDEXES FROM ${table}", {table = table_name}))
|
|
end
|
|
|
|
function Connection:show_table_status(table_name)
|
|
if table_name and not string.is_blank(table_name) then
|
|
return self:query("SHOW TABLE STATUS LIKE ?", table_name)
|
|
else
|
|
return self:query("SHOW TABLE STATUS")
|
|
end
|
|
end
|
|
|
|
-- MySQL user and privilege management
|
|
function Connection:create_user(username, password, host)
|
|
if string.is_blank(username) or string.is_blank(password) then
|
|
error("Username and password cannot be empty")
|
|
end
|
|
|
|
host = host or "%"
|
|
local query = string.template("CREATE USER '${username}'@'${host}' IDENTIFIED BY ?", {
|
|
username = username,
|
|
host = host
|
|
})
|
|
return self:exec(query, password)
|
|
end
|
|
|
|
function Connection:drop_user(username, host)
|
|
if string.is_blank(username) then
|
|
error("Username cannot be empty")
|
|
end
|
|
|
|
host = host or "%"
|
|
local query = string.template("DROP USER IF EXISTS '${username}'@'${host}'", {
|
|
username = username,
|
|
host = host
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:grant(privileges, database, table_name, username, host)
|
|
if string.is_blank(privileges) or string.is_blank(database) or string.is_blank(username) then
|
|
error("Privileges, database, and username cannot be empty")
|
|
end
|
|
|
|
host = host or "%"
|
|
table_name = table_name or "*"
|
|
local object = string.template("${database}.${table}", {database = database, table = table_name})
|
|
|
|
local query = string.template("GRANT ${privileges} ON ${object} TO '${username}'@'${host}'", {
|
|
privileges = string.upper(privileges),
|
|
object = object,
|
|
username = username,
|
|
host = host
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:revoke(privileges, database, table_name, username, host)
|
|
if string.is_blank(privileges) or string.is_blank(database) or string.is_blank(username) then
|
|
error("Privileges, database, and username cannot be empty")
|
|
end
|
|
|
|
host = host or "%"
|
|
table_name = table_name or "*"
|
|
local object = string.template("${database}.${table}", {database = database, table = table_name})
|
|
|
|
local query = string.template("REVOKE ${privileges} ON ${object} FROM '${username}'@'${host}'", {
|
|
privileges = string.upper(privileges),
|
|
object = object,
|
|
username = username,
|
|
host = host
|
|
})
|
|
return self:exec(query)
|
|
end
|
|
|
|
function Connection:flush_privileges()
|
|
return self:exec("FLUSH PRIVILEGES")
|
|
end
|
|
|
|
-- MySQL variables and configuration
|
|
function Connection:set_variable(name, value, global)
|
|
if string.is_blank(name) then
|
|
error("Variable name cannot be empty")
|
|
end
|
|
|
|
local scope = global and "GLOBAL " or "SESSION "
|
|
return self:exec(string.template("SET ${scope}${name} = ?", {
|
|
scope = scope,
|
|
name = name
|
|
}), value)
|
|
end
|
|
|
|
function Connection:get_variable(name, global)
|
|
if string.is_blank(name) then
|
|
error("Variable name cannot be empty")
|
|
end
|
|
|
|
local scope = global and "global." or "session."
|
|
return self:query_value(string.template("SELECT @@${scope}${name}", {
|
|
scope = scope,
|
|
name = name
|
|
}))
|
|
end
|
|
|
|
function Connection:show_variables(pattern)
|
|
if pattern and not string.is_blank(pattern) then
|
|
return self:query("SHOW VARIABLES LIKE ?", pattern)
|
|
else
|
|
return self:query("SHOW VARIABLES")
|
|
end
|
|
end
|
|
|
|
function Connection:show_status(pattern)
|
|
if pattern and not string.is_blank(pattern) then
|
|
return self:query("SHOW STATUS LIKE ?", pattern)
|
|
else
|
|
return self:query("SHOW STATUS")
|
|
end
|
|
end
|
|
|
|
-- Connection management
|
|
function mysql.connect(dsn)
|
|
if string.is_blank(dsn) then
|
|
error("DSN cannot be empty")
|
|
end
|
|
|
|
local conn_id = moonshark.sql_connect("mysql", string.trim(dsn))
|
|
if conn_id then
|
|
local conn = {_id = conn_id}
|
|
setmetatable(conn, Connection)
|
|
return conn
|
|
end
|
|
return nil
|
|
end
|
|
|
|
mysql.open = mysql.connect
|
|
|
|
-- Quick execution functions
|
|
function mysql.query(dsn, query_str, ...)
|
|
local conn = mysql.connect(dsn)
|
|
if not conn then
|
|
error("Failed to connect to MySQL database")
|
|
end
|
|
|
|
local results = conn:query(query_str, ...)
|
|
conn:close()
|
|
return results
|
|
end
|
|
|
|
function mysql.exec(dsn, query_str, ...)
|
|
local conn = mysql.connect(dsn)
|
|
if not conn then
|
|
error("Failed to connect to MySQL database")
|
|
end
|
|
|
|
local result = conn:exec(query_str, ...)
|
|
conn:close()
|
|
return result
|
|
end
|
|
|
|
function mysql.query_row(dsn, query_str, ...)
|
|
local results = mysql.query(dsn, query_str, ...)
|
|
if results and #results > 0 then
|
|
return results[1]
|
|
end
|
|
return nil
|
|
end
|
|
|
|
function mysql.query_value(dsn, query_str, ...)
|
|
local row = mysql.query_row(dsn, query_str, ...)
|
|
if row then
|
|
for _, value in pairs(row) do
|
|
return value
|
|
end
|
|
end
|
|
return nil
|
|
end
|
|
|
|
-- Migration helpers
|
|
function mysql.migrate(dsn, migrations, database_name)
|
|
local conn = mysql.connect(dsn)
|
|
if not conn then
|
|
error("Failed to connect to MySQL database for migration")
|
|
end
|
|
|
|
-- Use specified database if provided
|
|
if database_name and not string.is_blank(database_name) then
|
|
conn:exec(string.template("USE ${database}", {database = database_name}))
|
|
end
|
|
|
|
-- Create migrations table
|
|
conn:create_table("_migrations",
|
|
"id INT AUTO_INCREMENT PRIMARY KEY, name VARCHAR(255) UNIQUE NOT NULL, applied_at TIMESTAMP 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 string.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 = ?",
|
|
string.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 (?)", string.trim(migration.name))
|
|
print(string.template("Applied migration: ${name}", {name = migration.name}))
|
|
else
|
|
success = false
|
|
error_msg = string.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
|
|
|
|
-- Simplified result processing utilities
|
|
function mysql.to_array(results, column_name)
|
|
if not results or tbl.is_empty(results) then
|
|
return {}
|
|
end
|
|
|
|
if string.is_blank(column_name) then
|
|
error("Column name cannot be empty")
|
|
end
|
|
|
|
return tbl.map(results, function(row) return row[column_name] end)
|
|
end
|
|
|
|
function mysql.to_map(results, key_column, value_column)
|
|
if not results or tbl.is_empty(results) then
|
|
return {}
|
|
end
|
|
|
|
if string.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 mysql.group_by(results, column_name)
|
|
if not results or tbl.is_empty(results) then
|
|
return {}
|
|
end
|
|
|
|
if string.is_blank(column_name) then
|
|
error("Column name cannot be empty")
|
|
end
|
|
|
|
return tbl.group_by(results, function(row) return row[column_name] end)
|
|
end
|
|
|
|
-- Simplified debug helper
|
|
function mysql.print_results(results)
|
|
if not results or tbl.is_empty(results) then
|
|
print("No results")
|
|
return
|
|
end
|
|
|
|
local columns = tbl.keys(results[1])
|
|
tbl.sort(columns)
|
|
|
|
-- Calculate column widths
|
|
local widths = {}
|
|
for _, col in ipairs(columns) do
|
|
widths[col] = string.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], string.length(value))
|
|
end
|
|
end
|
|
|
|
-- Print header
|
|
local header_parts = tbl.map(columns, function(col) return string.pad_right(col, widths[col]) end)
|
|
local separator_parts = tbl.map(columns, function(col) return string.repeat_("-", widths[col]) end)
|
|
|
|
print(tbl.concat(header_parts, " | "))
|
|
print(tbl.concat(separator_parts, "-+-"))
|
|
|
|
-- Print rows
|
|
for _, row in ipairs(results) do
|
|
local value_parts = tbl.map(columns, function(col)
|
|
local value = tostring(row[col] or "")
|
|
return string.pad_right(value, widths[col])
|
|
end)
|
|
print(tbl.concat(value_parts, " | "))
|
|
end
|
|
end
|
|
|
|
-- MySQL-specific utilities
|
|
function mysql.escape_string(str_val)
|
|
if type(str_val) ~= "string" then
|
|
return tostring(str_val)
|
|
end
|
|
return string.replace(str_val, "'", "\\'")
|
|
end
|
|
|
|
function mysql.escape_identifier(name)
|
|
if string.is_blank(name) then
|
|
error("Identifier name cannot be empty")
|
|
end
|
|
return string.template("`${name}`", {name = string.replace(name, "`", "``")})
|
|
end
|
|
|
|
-- DSN builder helper
|
|
function mysql.build_dsn(options)
|
|
if type(options) ~= "table" then
|
|
error("Options must be a table")
|
|
end
|
|
|
|
local parts = {}
|
|
|
|
if options.username and not string.is_blank(options.username) then
|
|
tbl.insert(parts, options.username)
|
|
if options.password and not string.is_blank(options.password) then
|
|
parts[#parts] = string.template("${user}:${pass}", {
|
|
user = parts[#parts],
|
|
pass = options.password
|
|
})
|
|
end
|
|
parts[#parts] = parts[#parts] .. "@"
|
|
end
|
|
|
|
if options.protocol and not string.is_blank(options.protocol) then
|
|
tbl.insert(parts, string.template("${protocol}(", {protocol = options.protocol}))
|
|
if options.host and not string.is_blank(options.host) then
|
|
tbl.insert(parts, options.host)
|
|
if options.port then
|
|
parts[#parts] = string.template("${host}:${port}", {
|
|
host = parts[#parts],
|
|
port = tostring(options.port)
|
|
})
|
|
end
|
|
end
|
|
parts[#parts] = parts[#parts] .. ")"
|
|
elseif options.host and not string.is_blank(options.host) then
|
|
local host_part = string.template("tcp(${host}", {host = options.host})
|
|
if options.port then
|
|
host_part = string.template("${host}:${port}", {
|
|
host = host_part,
|
|
port = tostring(options.port)
|
|
})
|
|
end
|
|
tbl.insert(parts, host_part .. ")")
|
|
end
|
|
|
|
if options.database and not string.is_blank(options.database) then
|
|
tbl.insert(parts, string.template("/${database}", {database = options.database}))
|
|
end
|
|
|
|
-- Add parameters
|
|
local params = {}
|
|
if options.charset and not string.is_blank(options.charset) then
|
|
tbl.insert(params, string.template("charset=${charset}", {charset = options.charset}))
|
|
end
|
|
if options.parseTime ~= nil then
|
|
tbl.insert(params, string.template("parseTime=${parse}", {parse = tostring(options.parseTime)}))
|
|
end
|
|
if options.timeout and not string.is_blank(options.timeout) then
|
|
tbl.insert(params, string.template("timeout=${timeout}", {timeout = options.timeout}))
|
|
end
|
|
if options.tls and not string.is_blank(options.tls) then
|
|
tbl.insert(params, string.template("tls=${tls}", {tls = options.tls}))
|
|
end
|
|
|
|
if #params > 0 then
|
|
tbl.insert(parts, string.template("?${params}", {params = tbl.concat(params, "&")}))
|
|
end
|
|
|
|
return tbl.concat(parts, "")
|
|
end
|
|
|
|
return mysql
|