mod_storage_sql2: Split up setting of encoding and table upgrade code
[prosody.git] / plugins / mod_storage_sql2.lua
1
2 local json = require "util.json";
3 local xml_parse = require "util.xml".parse;
4 local uuid = require "util.uuid";
5 local resolve_relative_path = require "core.configmanager".resolve_relative_path;
6
7 local stanza_mt = require"util.stanza".stanza_mt;
8 local getmetatable = getmetatable;
9 local t_concat = table.concat;
10 local function is_stanza(x) return getmetatable(x) == stanza_mt; end
11
12 local noop = function() end
13 local unpack = unpack
14 local function iterator(result)
15         return function(result)
16                 local row = result();
17                 if row ~= nil then
18                         return unpack(row);
19                 end
20         end, result, nil;
21 end
22
23 local mod_sql = module:require("sql");
24 local params = module:get_option("sql");
25
26 local engine; -- TODO create engine
27
28 local function create_table()
29         local Table,Column,Index = mod_sql.Table,mod_sql.Column,mod_sql.Index;
30         --[[
31         local ProsodyTable = Table {
32                 name="prosody";
33                 Column { name="host", type="TEXT", nullable=false };
34                 Column { name="user", type="TEXT", nullable=false };
35                 Column { name="store", type="TEXT", nullable=false };
36                 Column { name="key", type="TEXT", nullable=false };
37                 Column { name="type", type="TEXT", nullable=false };
38                 Column { name="value", type="TEXT", nullable=false };
39                 Index { name="prosody_index", "host", "user", "store", "key" };
40         };
41         engine:transaction(function()
42                 ProsodyTable:create(engine);
43         end);]]
44         if not module:get_option("sql_manage_tables", true) then
45                 return;
46         end
47
48         local create_sql = "CREATE TABLE `prosody` (`host` TEXT, `user` TEXT, `store` TEXT, `key` TEXT, `type` TEXT, `value` TEXT);";
49         if params.driver == "PostgreSQL" then
50                 create_sql = create_sql:gsub("`", "\"");
51         elseif params.driver == "MySQL" then
52                 create_sql = create_sql:gsub("`value` TEXT", "`value` MEDIUMTEXT")
53                         :gsub(";$", " CHARACTER SET 'utf8' COLLATE 'utf8_bin';");
54         end
55
56         local index_sql = "CREATE INDEX `prosody_index` ON `prosody` (`host`, `user`, `store`, `key`)";
57         if params.driver == "PostgreSQL" then
58                 index_sql = index_sql:gsub("`", "\"");
59         elseif params.driver == "MySQL" then
60                 index_sql = index_sql:gsub("`([,)])", "`(20)%1");
61         end
62
63         local success,err = engine:transaction(function()
64                 engine:execute(create_sql);
65                 engine:execute(index_sql);
66         end);
67         if not success then -- so we failed to create
68                 if params.driver == "MySQL" then
69                         success,err = engine:transaction(function()
70                                 local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
71                                 if result:rowcount() > 0 then
72                                         module:log("info", "Upgrading database schema...");
73                                         engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
74                                         module:log("info", "Database table automatically upgraded");
75                                 end
76                                 return true;
77                         end);
78                         if not success then
79                                 module:log("error", "Failed to check/upgrade database schema (%s), please see "
80                                         .."http://prosody.im/doc/mysql for help",
81                                         err or "unknown error");
82                         end
83                 end
84         end
85         local ProsodyArchiveTable = Table {
86                 name="prosodyarchive";
87                 Column { name="sort_id", type="INTEGER PRIMARY KEY AUTOINCREMENT", nullable=false };
88                 Column { name="host", type="TEXT", nullable=false };
89                 Column { name="user", type="TEXT", nullable=false };
90                 Column { name="store", type="TEXT", nullable=false };
91                 Column { name="key", type="TEXT", nullable=false }; -- item id
92                 Column { name="when", type="INTEGER", nullable=false }; -- timestamp
93                 Column { name="with", type="TEXT", nullable=false }; -- related id
94                 Column { name="type", type="TEXT", nullable=false };
95                 Column { name="value", type=params.driver == "MySQL" and "MEDIUMTEXT" or "TEXT", nullable=false };
96                 Index { name="prosodyarchive_index", "host", "user", "store", "key" };
97         };
98         engine:transaction(function()
99                 ProsodyArchiveTable:create(engine);
100         end);
101 end
102 local function set_encoding()
103         if params.driver == "SQLite3" then return end
104         local set_names_query = "SET NAMES 'utf8';";
105         if params.driver == "MySQL" then
106                 set_names_query = set_names_query:gsub(";$", " COLLATE 'utf8_bin';");
107         end
108         local success,err = engine:transaction(function() return engine:execute(set_names_query); end);
109         if not success then
110                 module:log("error", "Failed to set database connection encoding to UTF8: %s", err);
111         end
112 end
113 local function upgrade_table()
114         if params.driver == "MySQL" then
115                 -- COMPAT w/pre-0.9: Upgrade tables to UTF-8 if not already
116                 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' );";
117                 local success,err = engine:transaction(function()
118                         local result = engine:execute(check_encoding_query);
119                         local n_bad_columns = result:rowcount();
120                         if n_bad_columns > 0 then
121                                 module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
122                                 local fix_column_query1 = "ALTER TABLE `prosody` CHANGE `%s` `%s` BLOB;";
123                                 local fix_column_query2 = "ALTER TABLE `prosody` CHANGE `%s` `%s` %s CHARACTER SET 'utf8' COLLATE 'utf8_bin';";
124                                 for row in result:rows() do
125                                         local column_name, column_type = unpack(row);
126                                         engine:execute(fix_column_query1:format(column_name, column_name));
127                                         engine:execute(fix_column_query2:format(column_name, column_name, column_type));
128                                 end
129                                 module:log("info", "Database encoding upgrade complete!");
130                         end
131                 end);
132                 local success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
133                 if not success then
134                         module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
135                 end
136         end
137 end
138
139 do -- process options to get a db connection
140         params = params or { driver = "SQLite3" };
141
142         if params.driver == "SQLite3" then
143                 params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
144         end
145
146         assert(params.driver and params.database, "Both the SQL driver and the database need to be specified");
147
148         --local dburi = db2uri(params);
149         engine = mod_sql:create_engine(params);
150
151         -- Encoding mess
152         set_encoding();
153         upgrade_table();
154
155         -- Automatically create table, ignore failure (table probably already exists)
156         create_table();
157 end
158
159 local function serialize(value)
160         local t = type(value);
161         if t == "string" or t == "boolean" or t == "number" then
162                 return t, tostring(value);
163         elseif is_stanza(value) then
164                 return "xml", tostring(value);
165         elseif t == "table" then
166                 local value,err = json.encode(value);
167                 if value then return "json", value; end
168                 return nil, err;
169         end
170         return nil, "Unhandled value type: "..t;
171 end
172 local function deserialize(t, value)
173         if t == "string" then return value;
174         elseif t == "boolean" then
175                 if value == "true" then return true;
176                 elseif value == "false" then return false; end
177         elseif t == "number" then return tonumber(value);
178         elseif t == "json" then
179                 return json.decode(value);
180         elseif t == "xml" then
181                 return xml_parse(value);
182         end
183 end
184
185 local host = module.host;
186 local user, store;
187
188 local function keyval_store_get()
189         local haveany;
190         local result = {};
191         for row in engine:select("SELECT `key`,`type`,`value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store) do
192                 haveany = true;
193                 local k = row[1];
194                 local v = deserialize(row[2], row[3]);
195                 if k and v then
196                         if k ~= "" then result[k] = v; elseif type(v) == "table" then
197                                 for a,b in pairs(v) do
198                                         result[a] = b;
199                                 end
200                         end
201                 end
202         end
203         if haveany then
204                 return result;
205         end
206 end
207 local function keyval_store_set(data)
208         engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store);
209
210         if data and next(data) ~= nil then
211                 local extradata = {};
212                 for key, value in pairs(data) do
213                         if type(key) == "string" and key ~= "" then
214                                 local t, value = serialize(value);
215                                 assert(t, value);
216                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, key, t, value);
217                         else
218                                 extradata[key] = value;
219                         end
220                 end
221                 if next(extradata) ~= nil then
222                         local t, extradata = serialize(extradata);
223                         assert(t, extradata);
224                         engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, "", t, extradata);
225                 end
226         end
227         return true;
228 end
229
230 local keyval_store = {};
231 keyval_store.__index = keyval_store;
232 function keyval_store:get(username)
233         user,store = username,self.store;
234         return select(2, engine:transaction(keyval_store_get));
235 end
236 function keyval_store:set(username, data)
237         user,store = username,self.store;
238         return engine:transaction(function()
239                 return keyval_store_set(data);
240         end);
241 end
242 function keyval_store:users()
243         local ok, result = engine:transaction(function()
244                 return engine:select("SELECT DISTINCT `user` FROM `prosody` WHERE `host`=? AND `store`=?", host, self.store);
245         end);
246         if not ok then return ok, result end
247         return iterator(result);
248 end
249
250 local archive_store = {}
251 archive_store.__index = archive_store
252 function archive_store:append(username, when, with, value)
253         local user,store = username,self.store;
254         return engine:transaction(function()
255                 local key = uuid.generate();
256                 local t, value = serialize(value);
257                 engine:insert("INSERT INTO `prosodyarchive` (`host`, `user`, `store`, `when`, `with`, `key`, `type`, `value`) VALUES (?,?,?,?,?,?,?,?)", host, user or "", store, when, with, key, t, value);
258                 return key;
259         end);
260 end
261
262 -- Helpers for building the WHERE clause
263 local function archive_where(query, args, where)
264         -- Time range, inclusive
265         if query.start then
266                 args[#args+1] = query.start
267                 where[#where+1] = "`when` >= ?"
268         end
269
270         if query["end"] then
271                 args[#args+1] = query["end"];
272                 if query.start then
273                         where[#where] = "`when` BETWEEN ? AND ?" -- is this inclusive?
274                 else
275                         where[#where+1] = "`when` >= ?"
276                 end
277         end
278
279         -- Related name
280         if query.with then
281                 where[#where+1] = "`with` = ?";
282                 args[#args+1] = query.with
283         end
284
285         -- Unique id
286         if query.key then
287                 where[#where+1] = "`key` = ?";
288                 args[#args+1] = query.key
289         end
290 end
291 local function archive_where_id_range(query, args, where)
292         -- Before or after specific item, exclusive
293         if query.after then  -- keys better be unique!
294                 where[#where+1] = "`sort_id` > (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? LIMIT 1)"
295                 args[#args+1] = query.after
296         end
297         if query.before then
298                 where[#where+1] = "`sort_id` < (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? LIMIT 1)"
299                 args[#args+1] = query.before
300         end
301 end
302
303 function archive_store:find(username, query)
304         query = query or {};
305         local user,store = username,self.store;
306         local total;
307         local ok, result = engine:transaction(function()
308                 local sql_query = "SELECT `key`, `type`, `value`, `when` FROM `prosodyarchive` WHERE %s ORDER BY `sort_id` %s%s;";
309                 local args = { host, user or "", store, };
310                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
311
312                 archive_where(query, args, where);
313
314                 -- Total matching
315                 if query.total then
316                         local stats = engine:select(sql_query:gsub("^(SELECT).-(FROM)", "%1 COUNT(*) %2"):format(t_concat(where, " AND "), "DESC", ""), unpack(args));
317                         if stats then
318                                 local _total = stats()
319                                 total = _total and _total[1];
320                         end
321                         if query.limit == 0 then -- Skip the real query
322                                 return noop, total;
323                         end
324                 end
325
326                 archive_where_id_range(query, args, where);
327
328                 if query.limit then
329                         args[#args+1] = query.limit;
330                 end
331
332                 sql_query = sql_query:format(t_concat(where, " AND "), query.reverse and "DESC" or "ASC", query.limit and " LIMIT ?" or "");
333                 module:log("debug", sql_query);
334                 return engine:select(sql_query, unpack(args));
335         end);
336         if not ok then return ok, result end
337         return function()
338                 local row = result();
339                 if row ~= nil then
340                         return row[1], deserialize(row[2], row[3]), row[4];
341                 end
342         end, total;
343 end
344
345 function archive_store:delete(username, query)
346         query = query or {};
347         local user,store = username,self.store;
348         return engine:transaction(function()
349                 local sql_query = "DELETE FROM `prosodyarchive` WHERE %s;";
350                 local args = { host, user or "", store, };
351                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
352                 archive_where(query, args, where);
353                 archive_where_id_range(query, args, where);
354                 sql_query = sql_query:format(t_concat(where, " AND "));
355                 module:log("debug", sql_query);
356                 return engine:delete(sql_query, unpack(args));
357         end);
358 end
359
360 local stores = {
361         keyval = keyval_store;
362         archive = archive_store;
363 };
364
365 local driver = {};
366
367 function driver:open(store, typ)
368         local store_mt = stores[typ or "keyval"];
369         if store_mt then
370                 return setmetatable({ store = store }, store_mt);
371         end
372         return nil, "unsupported-store";
373 end
374
375 function driver:stores(username)
376         local sql = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
377                 (username == true and "!=?" or "=?");
378         if username == true or not username then
379                 username = "";
380         end
381         local ok, result = engine:transaction(function()
382                 return engine:select(sql, host, username);
383         end);
384         if not ok then return ok, result end
385         return iterator(result);
386 end
387
388 function driver:purge(username)
389         return engine:transaction(function()
390                 local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
391                 return true,err;
392         end);
393 end
394
395 module:provides("storage", driver);
396
397