mod_storage_sql2 (temporary name), sql.lib, util.sql: New SQL API supporting cross...
authorMatthew Wild <mwild1@gmail.com>
Thu, 18 Apr 2013 10:13:40 +0000 (11:13 +0100)
committerMatthew Wild <mwild1@gmail.com>
Thu, 18 Apr 2013 10:13:40 +0000 (11:13 +0100)
plugins/mod_storage_sql2.lua [new file with mode: 0644]
plugins/sql.lib.lua [new file with mode: 0644]
util/sql.lua [new file with mode: 0644]

diff --git a/plugins/mod_storage_sql2.lua b/plugins/mod_storage_sql2.lua
new file mode 100644 (file)
index 0000000..7d705b0
--- /dev/null
@@ -0,0 +1,237 @@
+
+local json = require "util.json";
+local resolve_relative_path = require "core.configmanager".resolve_relative_path;
+
+local mod_sql = module:require("sql");
+local params = module:get_option("sql");
+
+local engine; -- TODO create engine
+
+local function create_table()
+       --[[local Table,Column,Index = mod_sql.Table,mod_sql.Column,mod_sql.Index;
+       local ProsodyTable = Table {
+               name="prosody";
+               Column { name="host", type="TEXT", nullable=false };
+               Column { name="user", type="TEXT", nullable=false };
+               Column { name="store", type="TEXT", nullable=false };
+               Column { name="key", type="TEXT", nullable=false };
+               Column { name="type", type="TEXT", nullable=false };
+               Column { name="value", type="TEXT", nullable=false };
+               Index { name="prosody_index", "host", "user", "store", "key" };
+       };
+       engine:transaction(function()
+               ProsodyTable:create(engine);
+       end);]]
+       if not module:get_option("sql_manage_tables", true) then
+               return;
+       end
+
+       local create_sql = "CREATE TABLE `prosody` (`host` TEXT, `user` TEXT, `store` TEXT, `key` TEXT, `type` TEXT, `value` TEXT);";
+       if params.driver == "PostgreSQL" then
+               create_sql = create_sql:gsub("`", "\"");
+       elseif params.driver == "MySQL" then
+               create_sql = create_sql:gsub("`value` TEXT", "`value` MEDIUMTEXT")
+                       :gsub(";$", " CHARACTER SET 'utf8' COLLATE 'utf8_bin';");
+       end
+
+       local index_sql = "CREATE INDEX `prosody_index` ON `prosody` (`host`, `user`, `store`, `key`)";
+       if params.driver == "PostgreSQL" then
+               index_sql = index_sql:gsub("`", "\"");
+       elseif params.driver == "MySQL" then
+               index_sql = index_sql:gsub("`([,)])", "`(20)%1");
+       end
+
+       local success,err = engine:transaction(function()
+               engine:execute(create_sql);
+               engine:execute(index_sql);
+       end);
+       if not success then -- so we failed to create
+               if params.driver == "MySQL" then
+                       success,err = engine:transaction(function()
+                               local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
+                               if result:rowcount() > 0 then
+                                       module:log("info", "Upgrading database schema...");
+                                       engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
+                                       module:log("info", "Database table automatically upgraded");
+                               end
+                               return true;
+                       end);
+                       if not success then
+                               module:log("error", "Failed to check/upgrade database schema (%s), please see "
+                                       .."http://prosody.im/doc/mysql for help",
+                                       err or "unknown error");
+                       end
+               end
+       end
+end
+local function set_encoding()
+       if params.driver ~= "SQLite3" then
+               local set_names_query = "SET NAMES 'utf8';";
+               if params.driver == "MySQL" then
+                       set_names_query = set_names_query:gsub(";$", " COLLATE 'utf8_bin';");
+               end
+               local success,err = engine:transaction(function() return engine:execute(set_names_query); end);
+               if not success then
+                       module:log("error", "Failed to set database connection encoding to UTF8: %s", err);
+                       return;
+               end
+               if params.driver == "MySQL" then
+                       -- COMPAT w/pre-0.9: Upgrade tables to UTF-8 if not already
+                       local check_encoding_query = "SELECT `COLUMN_NAME`,`COLUMN_TYPE` FROM `information_schema`.`columns` WHERE `TABLE_NAME`='prosody' AND ( `CHARACTER_SET_NAME`!='utf8' OR `COLLATION_NAME`!='utf8_bin' );";
+                       local success,err = engine:transaction(function()
+                               local result = engine:execute(check_encoding_query);
+                               local n_bad_columns = result:rowcount();
+                               if n_bad_columns > 0 then
+                                       module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
+                                       local fix_column_query1 = "ALTER TABLE `prosody` CHANGE `%s` `%s` BLOB;";
+                                       local fix_column_query2 = "ALTER TABLE `prosody` CHANGE `%s` `%s` %s CHARACTER SET 'utf8' COLLATE 'utf8_bin';";
+                                       for row in success:rows() do
+                                               local column_name, column_type = unpack(row);
+                                               engine:execute(fix_column_query1:format(column_name, column_name));
+                                               engine:execute(fix_column_query2:format(column_name, column_name, column_type));
+                                       end
+                                       module:log("info", "Database encoding upgrade complete!");
+                               end
+                       end);
+                       local success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
+                       if not success then
+                               module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
+                       end
+               end
+       end
+end
+
+do -- process options to get a db connection
+       params = params or { driver = "SQLite3" };
+       
+       if params.driver == "SQLite3" then
+               params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
+       end
+       
+       assert(params.driver and params.database, "Both the SQL driver and the database need to be specified");
+
+       --local dburi = db2uri(params);
+       engine = mod_sql:create_engine(params);
+       
+       -- Encoding mess
+       set_encoding();
+
+       -- Automatically create table, ignore failure (table probably already exists)
+       create_table();
+end
+
+local function serialize(value)
+       local t = type(value);
+       if t == "string" or t == "boolean" or t == "number" then
+               return t, tostring(value);
+       elseif t == "table" then
+               local value,err = json.encode(value);
+               if value then return "json", value; end
+               return nil, err;
+       end
+       return nil, "Unhandled value type: "..t;
+end
+local function deserialize(t, value)
+       if t == "string" then return value;
+       elseif t == "boolean" then
+               if value == "true" then return true;
+               elseif value == "false" then return false; end
+       elseif t == "number" then return tonumber(value);
+       elseif t == "json" then
+               return json.decode(value);
+       end
+end
+
+local host = module.host;
+local user, store;
+
+local function keyval_store_get()
+       local haveany;
+       local result = {};
+       for row in engine:select("SELECT `key`,`type`,`value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user, store) do
+               haveany = true;
+               local k = row[1];
+               local v = deserialize(row[2], row[3]);
+               if k and v then
+                       if k ~= "" then result[k] = v; elseif type(v) == "table" then
+                               for a,b in pairs(v) do
+                                       result[a] = b;
+                               end
+                       end
+               end
+       end
+       if haveany then
+               return result;
+       end
+end
+local function keyval_store_set(data)
+       engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user, store);
+       
+       if data and next(data) ~= nil then
+               local extradata = {};
+               for key, value in pairs(data) do
+                       if type(key) == "string" and key ~= "" then
+                               local t, value = serialize(value);
+                               assert(t, value);
+                               engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user, store, key, t, value);
+                       else
+                               extradata[key] = value;
+                       end
+               end
+               if next(extradata) ~= nil then
+                       local t, extradata = serialize(extradata);
+                       assert(t, extradata);
+                       engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user, store, "", t, extradata);
+               end
+       end
+       return true;
+end
+
+local keyval_store = {};
+keyval_store.__index = keyval_store;
+function keyval_store:get(username)
+       user,store = username,self.store;
+       return select(2, engine:transaction(keyval_store_get));
+end
+function keyval_store:set(username, data)
+       user,store = username,self.store;
+       return engine:transaction(function()
+               return keyval_store_set(data);
+       end);
+end
+function keyval_store:users()
+       return engine:transaction(function()
+               return engine:select("SELECT DISTINCT `user` FROM `prosody` WHERE `host`=? AND `store`=?", host, self.store);
+       end);
+end
+
+local driver = {};
+
+function driver:open(store, typ)
+       if not typ then -- default key-value store
+               return setmetatable({ store = store }, keyval_store);
+       end
+       return nil, "unsupported-store";
+end
+
+function driver:stores(username)
+       local sql = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
+               (username == true and "!=?" or "=?");
+       if username == true or not username then
+               username = "";
+       end
+       return engine:transaction(function()
+               return engine:select(sql, host, username);
+       end);
+end
+
+function driver:purge(username)
+       return engine:transaction(function()
+               local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
+               return true,err;
+       end);
+end
+
+module:provides("storage", driver);
+
+
diff --git a/plugins/sql.lib.lua b/plugins/sql.lib.lua
new file mode 100644 (file)
index 0000000..005ee45
--- /dev/null
@@ -0,0 +1,9 @@
+local cache = module:shared("/*/sql.lib/util.sql");
+
+if not cache._M then
+       prosody.unlock_globals();
+       cache._M = require "util.sql";
+       prosody.lock_globals();
+end
+
+return cache._M;
diff --git a/util/sql.lua b/util/sql.lua
new file mode 100644 (file)
index 0000000..f360d6d
--- /dev/null
@@ -0,0 +1,340 @@
+
+local setmetatable, getmetatable = setmetatable, getmetatable;
+local ipairs, unpack, select = ipairs, unpack, select;
+local tonumber, tostring = tonumber, tostring;
+local assert, xpcall, debug_traceback = assert, xpcall, debug.traceback;
+local t_concat = table.concat;
+local s_char = string.char;
+local log = require "util.logger".init("sql");
+
+local DBI = require "DBI";
+-- This loads all available drivers while globals are unlocked
+-- LuaDBI should be fixed to not set globals.
+DBI.Drivers();
+local build_url = require "socket.url".build;
+
+module("sql")
+
+local column_mt = {};
+local table_mt = {};
+local query_mt = {};
+--local op_mt = {};
+local index_mt = {};
+
+function is_column(x) return getmetatable(x)==column_mt; end
+function is_index(x) return getmetatable(x)==index_mt; end
+function is_table(x) return getmetatable(x)==table_mt; end
+function is_query(x) return getmetatable(x)==query_mt; end
+--function is_op(x) return getmetatable(x)==op_mt; end
+--function expr(...) return setmetatable({...}, op_mt); end
+function Integer(n) return "Integer()" end
+function String(n) return "String()" end
+
+--[[local ops = {
+       __add = function(a, b) return "("..a.."+"..b..")" end;
+       __sub = function(a, b) return "("..a.."-"..b..")" end;
+       __mul = function(a, b) return "("..a.."*"..b..")" end;
+       __div = function(a, b) return "("..a.."/"..b..")" end;
+       __mod = function(a, b) return "("..a.."%"..b..")" end;
+       __pow = function(a, b) return "POW("..a..","..b..")" end;
+       __unm = function(a) return "NOT("..a..")" end;
+       __len = function(a) return "COUNT("..a..")" end;
+       __eq = function(a, b) return "("..a.."=="..b..")" end;
+       __lt = function(a, b) return "("..a.."<"..b..")" end;
+       __le = function(a, b) return "("..a.."<="..b..")" end;
+};
+
+local functions = {
+       
+};
+
+local cmap = {
+       [Integer] = Integer();
+       [String] = String();
+};]]
+
+function Column(definition)
+       return setmetatable(definition, column_mt);
+end
+function Table(definition)
+       local c = {}
+       for i,col in ipairs(definition) do
+               if is_column(col) then
+                       c[i], c[col.name] = col, col;
+               elseif is_index(col) then
+                       col.table = definition.name;
+               end
+       end
+       return setmetatable({ __table__ = definition, c = c, name = definition.name }, table_mt);
+end
+function Index(definition)
+       return setmetatable(definition, index_mt);
+end
+
+function table_mt:__tostring()
+       local s = { 'name="'..self.__table__.name..'"' }
+       for i,col in ipairs(self.__table__) do
+               s[#s+1] = tostring(col);
+       end
+       return 'Table{ '..t_concat(s, ", ")..' }'
+end
+table_mt.__index = {};
+function table_mt.__index:create(engine)
+       return engine:_create_table(self);
+end
+function table_mt:__call(...)
+       -- TODO
+end
+function column_mt:__tostring()
+       return 'Column{ name="'..self.name..'", type="'..self.type..'" }'
+end
+function index_mt:__tostring()
+       local s = 'Index{ name="'..self.name..'"';
+       for i=1,#self do s = s..', "'..self[i]:gsub("[\\\"]", "\\%1")..'"'; end
+       return s..' }';
+--     return 'Index{ name="'..self.name..'", type="'..self.type..'" }'
+end
+--
+
+local function urldecode(s) return s and (s:gsub("%%(%x%x)", function (c) return s_char(tonumber(c,16)); end)); end
+local function parse_url(url)
+       local scheme, secondpart, database = url:match("^([%w%+]+)://([^/]*)/?(.*)");
+       assert(scheme, "Invalid URL format");
+       local username, password, host, port;
+       local authpart, hostpart = secondpart:match("([^@]+)@([^@+])");
+       if not authpart then hostpart = secondpart; end
+       if authpart then
+               username, password = authpart:match("([^:]*):(.*)");
+               username = username or authpart;
+               password = password and urldecode(password);
+       end
+       if hostpart then
+               host, port = hostpart:match("([^:]*):(.*)");
+               host = host or hostpart;
+               port = port and assert(tonumber(port), "Invalid URL format");
+       end
+       return {
+               scheme = scheme:lower();
+               username = username; password = password;
+               host = host; port = port;
+               database = #database > 0 and database or nil;
+       };
+end
+
+--[[local session = {};
+
+function session.query(...)
+       local rets = {...};
+       local query = setmetatable({ __rets = rets, __filters }, query_mt);
+       return query;
+end
+--
+
+local function db2uri(params)
+       return build_url{
+               scheme = params.driver,
+               user = params.username,
+               password = params.password,
+               host = params.host,
+               port = params.port,
+               path = params.database,
+       };
+end]]
+
+local engine = {};
+function engine:connect()
+       if self.conn then return true; end
+
+       local params = self.params;
+       assert(params.driver, "no driver")
+       local dbh, err = DBI.Connect(
+               params.driver, params.database,
+               params.username, params.password,
+               params.host, params.port
+       );
+       if not dbh then return nil, err; end
+       dbh:autocommit(false); -- don't commit automatically
+       self.conn = dbh;
+       self.prepared = {};
+       return true;
+end
+function engine:execute(sql, ...)
+       local success, err = self:connect();
+       if not success then return success, err; end
+       local prepared = self.prepared;
+
+       local stmt = prepared[sql];
+       if not stmt then
+               local err;
+               stmt, err = self.conn:prepare(sql);
+               if not stmt then return stmt, err; end
+               prepared[sql] = stmt;
+       end
+
+       local success, err = stmt:execute(...);
+       if not success then return success, err; end
+       return stmt;
+end
+
+local result_mt = { __index = {
+       affected = function(self) return self.__affected; end;
+       rowcount = function(self) return self.__rowcount; end;
+} };
+
+function engine:execute_query(sql, ...)
+       if self.params.driver == "PostgreSQL" then
+               sql = sql:gsub("`", "\"");
+       end
+       local stmt = assert(self.conn:prepare(sql));
+       assert(stmt:execute(...));
+       return stmt:rows();
+end
+function engine:execute_update(sql, ...)
+       if self.params.driver == "PostgreSQL" then
+               sql = sql:gsub("`", "\"");
+       end
+       local prepared = self.prepared;
+       local stmt = prepared[sql];
+       if not stmt then
+               stmt = assert(self.conn:prepare(sql));
+               prepared[sql] = stmt;
+       end
+       assert(stmt:execute(...));
+       return setmetatable({ __affected = stmt:affected(), __rowcount = stmt:rowcount() }, result_mt);
+end
+engine.insert = engine.execute_update;
+engine.select = engine.execute_query;
+engine.delete = engine.execute_update;
+engine.update = engine.execute_update;
+function engine:_transaction(func, ...)
+       if not self.conn then
+               local a,b = self:connect();
+               if not a then return a,b; end
+       end
+       --assert(not self.__transaction, "Recursive transactions not allowed");
+       local args, n_args = {...}, select("#", ...);
+       local function f() return func(unpack(args, 1, n_args)); end
+       self.__transaction = true;
+       local success, a, b, c = xpcall(f, debug_traceback);
+       self.__transaction = nil;
+       if success then
+               log("debug", "SQL transaction success [%s]", tostring(func));
+               local ok, err = self.conn:commit();
+               if not ok then return ok, err; end -- commit failed
+               return success, a, b, c;
+       else
+               log("debug", "SQL transaction failure [%s]: %s", tostring(func), a);
+               if self.conn then self.conn:rollback(); end
+               return success, a;
+       end
+end
+function engine:transaction(...)
+       local a,b = self:_transaction(...);
+       if not a then
+               local conn = self.conn;
+               if not conn or not conn:ping() then
+                       self.conn = nil;
+                       a,b = self:_transaction(...);
+               end
+       end
+       return a,b;
+end
+function engine:_create_index(index)
+       local sql = "CREATE INDEX `"..index.name.."` ON `"..index.table.."` (";
+       for i=1,#index do
+               sql = sql.."`"..index[i].."`";
+               if i ~= #index then sql = sql..", "; end
+       end
+       sql = sql..");"
+       if self.params.driver == "PostgreSQL" then
+               sql = sql:gsub("`", "\"");
+       elseif self.params.driver == "MySQL" then
+               sql = sql:gsub("`([,)])", "`(20)%1");
+       end
+       --print(sql);
+       return self:execute(sql);
+end
+function engine:_create_table(table)
+       local sql = "CREATE TABLE `"..table.name.."` (";
+       for i,col in ipairs(table.c) do
+               sql = sql.."`"..col.name.."` "..col.type;
+               if col.nullable == false then sql = sql.." NOT NULL"; end
+               if i ~= #table.c then sql = sql..", "; end
+       end
+       sql = sql.. ");"
+       if self.params.driver == "PostgreSQL" then
+               sql = sql:gsub("`", "\"");
+       end
+       local success,err = self:execute(sql);
+       if not success then return success,err; end
+       for i,v in ipairs(table.__table__) do
+               if is_index(v) then
+                       self:_create_index(v);
+               end
+       end
+       return success;
+end
+local engine_mt = { __index = engine };
+
+local function db2uri(params)
+       return build_url{
+               scheme = params.driver,
+               user = params.username,
+               password = params.password,
+               host = params.host,
+               port = params.port,
+               path = params.database,
+       };
+end
+local engine_cache = {}; -- TODO make weak valued
+function create_engine(self, params)
+       local url = db2uri(params);
+       if not engine_cache[url] then
+               local engine = setmetatable({ url = url, params = params }, engine_mt);
+               engine_cache[url] = engine;
+       end
+       return engine_cache[url];
+end
+
+
+--[[Users = Table {
+       name="users";
+       Column { name="user_id", type=String(), primary_key=true };
+};
+print(Users)
+print(Users.c.user_id)]]
+
+--local engine = create_engine('postgresql://scott:tiger@localhost:5432/mydatabase');
+--[[local engine = create_engine{ driver = "SQLite3", database = "./alchemy.sqlite" };
+
+local i = 0;
+for row in assert(engine:execute("select * from sqlite_master")):rows(true) do
+       i = i+1;
+       print(i);
+       for k,v in pairs(row) do
+               print("",k,v);
+       end
+end
+print("---")
+
+Prosody = Table {
+       name="prosody";
+       Column { name="host", type="TEXT", nullable=false };
+       Column { name="user", type="TEXT", nullable=false };
+       Column { name="store", type="TEXT", nullable=false };
+       Column { name="key", type="TEXT", nullable=false };
+       Column { name="type", type="TEXT", nullable=false };
+       Column { name="value", type="TEXT", nullable=false };
+       Index { name="prosody_index", "host", "user", "store", "key" };
+};
+--print(Prosody);
+assert(engine:transaction(function()
+       assert(Prosody:create(engine));
+end));
+
+for row in assert(engine:execute("select user from prosody")):rows(true) do
+       print("username:", row['username'])
+end
+--result.close();]]
+
+return _M;