Merge 0.10->trunk
[prosody.git] / plugins / mod_storage_sql2.lua
1
2 local json = require "util.json";
3 local sql = require "util.sql";
4 local xml_parse = require "util.xml".parse;
5 local uuid = require "util.uuid";
6 local resolve_relative_path = require "util.paths".resolve_relative_path;
7
8 local stanza_mt = require"util.stanza".stanza_mt;
9 local getmetatable = getmetatable;
10 local t_concat = table.concat;
11 local function is_stanza(x) return getmetatable(x) == stanza_mt; end
12
13 local noop = function() end
14 local unpack = unpack
15 local function iterator(result)
16         return function(result_)
17                 local row = result_();
18                 if row ~= nil then
19                         return unpack(row);
20                 end
21         end, result, nil;
22 end
23
24 local default_params = { driver = "SQLite3" };
25
26 local engine;
27
28 local function serialize(value)
29         local t = type(value);
30         if t == "string" or t == "boolean" or t == "number" then
31                 return t, tostring(value);
32         elseif is_stanza(value) then
33                 return "xml", tostring(value);
34         elseif t == "table" then
35                 local value,err = json.encode(value);
36                 if value then return "json", value; end
37                 return nil, err;
38         end
39         return nil, "Unhandled value type: "..t;
40 end
41 local function deserialize(t, value)
42         if t == "string" then return value;
43         elseif t == "boolean" then
44                 if value == "true" then return true;
45                 elseif value == "false" then return false; end
46         elseif t == "number" then return tonumber(value);
47         elseif t == "json" then
48                 return json.decode(value);
49         elseif t == "xml" then
50                 return xml_parse(value);
51         end
52 end
53
54 local host = module.host;
55 local user, store;
56
57 local function keyval_store_get()
58         local haveany;
59         local result = {};
60         for row in engine:select("SELECT `key`,`type`,`value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store) do
61                 haveany = true;
62                 local k = row[1];
63                 local v = deserialize(row[2], row[3]);
64                 if k and v then
65                         if k ~= "" then result[k] = v; elseif type(v) == "table" then
66                                 for a,b in pairs(v) do
67                                         result[a] = b;
68                                 end
69                         end
70                 end
71         end
72         if haveany then
73                 return result;
74         end
75 end
76 local function keyval_store_set(data)
77         engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store);
78
79         if data and next(data) ~= nil then
80                 local extradata = {};
81                 for key, value in pairs(data) do
82                         if type(key) == "string" and key ~= "" then
83                                 local t, value = serialize(value);
84                                 assert(t, value);
85                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, key, t, value);
86                         else
87                                 extradata[key] = value;
88                         end
89                 end
90                 if next(extradata) ~= nil then
91                         local t, extradata = serialize(extradata);
92                         assert(t, extradata);
93                         engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, "", t, extradata);
94                 end
95         end
96         return true;
97 end
98
99 --- Key/value store API (default store type)
100
101 local keyval_store = {};
102 keyval_store.__index = keyval_store;
103 function keyval_store:get(username)
104         user, store = username, self.store;
105         local ok, result = engine:transaction(keyval_store_get);
106         if not ok then
107                 module:log("error", "Unable to read from database %s store for %s: %s", store, username or "<host>", result);
108                 return nil, result;
109         end
110         return result;
111 end
112 function keyval_store:set(username, data)
113         user,store = username,self.store;
114         return engine:transaction(function()
115                 return keyval_store_set(data);
116         end);
117 end
118 function keyval_store:users()
119         local ok, result = engine:transaction(function()
120                 return engine:select("SELECT DISTINCT `user` FROM `prosody` WHERE `host`=? AND `store`=?", host, self.store);
121         end);
122         if not ok then return ok, result end
123         return iterator(result);
124 end
125
126 --- Archive store API
127
128 local map_store = {};
129 map_store.__index = map_store;
130 function map_store:get(username, key)
131         local ok, result = engine:transaction(function()
132                 if type(key) == "string" and key ~= "" then
133                         for row in engine:select("SELECT `type`, `value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?", host, username or "", self.store, key) do
134                                 return deserialize(row[1], row[2]);
135                         end
136                 else
137                         error("TODO: non-string keys");
138                 end
139         end);
140         if not ok then return nil, result; end
141         return result;
142 end
143 function map_store:set(username, key, data)
144         local ok, result = engine:transaction(function()
145                 if type(key) == "string" and key ~= "" then
146                         engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?",
147                                 host, username or "", self.store, key);
148                         if data ~= nil then
149                                 local t, value = assert(serialize(data));
150                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, username or "", self.store, key, t, value);
151                         end
152                 else
153                         error("TODO: non-string keys");
154                 end
155                 return true;
156         end);
157         if not ok then return nil, result; end
158         return result;
159 end
160
161 local archive_store = {}
162 archive_store.caps = {
163         total = true;
164 };
165 archive_store.__index = archive_store
166 function archive_store:append(username, key, value, when, with)
167         if type(when) ~= "number" then
168                 when, with, value = value, when, with;
169         end
170         local user,store = username,self.store;
171         return engine:transaction(function()
172                 if key then
173                         engine:delete("DELETE FROM `prosodyarchive` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?", host, user or "", store, key);
174                 else
175                         key = uuid.generate();
176                 end
177                 local t, value = serialize(value);
178                 engine:insert("INSERT INTO `prosodyarchive` (`host`, `user`, `store`, `when`, `with`, `key`, `type`, `value`) VALUES (?,?,?,?,?,?,?,?)", host, user or "", store, when, with, key, t, value);
179                 return key;
180         end);
181 end
182
183 -- Helpers for building the WHERE clause
184 local function archive_where(query, args, where)
185         -- Time range, inclusive
186         if query.start then
187                 args[#args+1] = query.start
188                 where[#where+1] = "`when` >= ?"
189         end
190
191         if query["end"] then
192                 args[#args+1] = query["end"];
193                 if query.start then
194                         where[#where] = "`when` BETWEEN ? AND ?" -- is this inclusive?
195                 else
196                         where[#where+1] = "`when` <= ?"
197                 end
198         end
199
200         -- Related name
201         if query.with then
202                 where[#where+1] = "`with` = ?";
203                 args[#args+1] = query.with
204         end
205
206         -- Unique id
207         if query.key then
208                 where[#where+1] = "`key` = ?";
209                 args[#args+1] = query.key
210         end
211 end
212 local function archive_where_id_range(query, args, where)
213         local args_len = #args
214         -- Before or after specific item, exclusive
215         if query.after then  -- keys better be unique!
216                 where[#where+1] = "`sort_id` > (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? AND `host` = ? AND `user` = ? AND `store` = ? LIMIT 1)"
217                 args[args_len+1], args[args_len+2], args[args_len+3], args[args_len+4] = query.after, args[1], args[2], args[3];
218                 args_len = args_len + 4
219         end
220         if query.before then
221                 where[#where+1] = "`sort_id` < (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? AND `host` = ? AND `user` = ? AND `store` = ? LIMIT 1)"
222                 args[args_len+1], args[args_len+2], args[args_len+3], args[args_len+4] = query.before, args[1], args[2], args[3];
223         end
224 end
225
226 function archive_store:find(username, query)
227         query = query or {};
228         local user,store = username,self.store;
229         local total;
230         local ok, result = engine:transaction(function()
231                 local sql_query = "SELECT `key`, `type`, `value`, `when`, `with` FROM `prosodyarchive` WHERE %s ORDER BY `sort_id` %s%s;";
232                 local args = { host, user or "", store, };
233                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
234
235                 archive_where(query, args, where);
236
237                 -- Total matching
238                 if query.total then
239                         local stats = engine:select("SELECT COUNT(*) FROM `prosodyarchive` WHERE " .. t_concat(where, " AND "), unpack(args));
240                         if stats then
241                                 local _total = stats()
242                                 total = _total and _total[1];
243                         end
244                         if query.limit == 0 then -- Skip the real query
245                                 return noop, total;
246                         end
247                 end
248
249                 archive_where_id_range(query, args, where);
250
251                 if query.limit then
252                         args[#args+1] = query.limit;
253                 end
254
255                 sql_query = sql_query:format(t_concat(where, " AND "), query.reverse and "DESC" or "ASC", query.limit and " LIMIT ?" or "");
256                 module:log("debug", sql_query);
257                 return engine:select(sql_query, unpack(args));
258         end);
259         if not ok then return ok, result end
260         return function()
261                 local row = result();
262                 if row ~= nil then
263                         return row[1], deserialize(row[2], row[3]), row[4], row[5];
264                 end
265         end, total;
266 end
267
268 function archive_store:delete(username, query)
269         query = query or {};
270         local user,store = username,self.store;
271         return engine:transaction(function()
272                 local sql_query = "DELETE FROM `prosodyarchive` WHERE %s;";
273                 local args = { host, user or "", store, };
274                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
275                 if user == true then
276                         table.remove(args, 2);
277                         table.remove(where, 2);
278                 end
279                 archive_where(query, args, where);
280                 archive_where_id_range(query, args, where);
281                 sql_query = sql_query:format(t_concat(where, " AND "));
282                 module:log("debug", sql_query);
283                 return engine:delete(sql_query, unpack(args));
284         end);
285 end
286
287 local stores = {
288         keyval = keyval_store;
289         map = map_store;
290         archive = archive_store;
291 };
292
293 --- Implement storage driver API
294
295 -- FIXME: Some of these operations need to operate on the archive store(s) too
296
297 local driver = {};
298
299 function driver:open(store, typ)
300         local store_mt = stores[typ or "keyval"];
301         if store_mt then
302                 return setmetatable({ store = store }, store_mt);
303         end
304         return nil, "unsupported-store";
305 end
306
307 function driver:stores(username)
308         local query = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
309                 (username == true and "!=?" or "=?");
310         if username == true or not username then
311                 username = "";
312         end
313         local ok, result = engine:transaction(function()
314                 return engine:select(query, host, username);
315         end);
316         if not ok then return ok, result end
317         return iterator(result);
318 end
319
320 function driver:purge(username)
321         return engine:transaction(function()
322                 local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
323                 return true, err;
324         end);
325 end
326
327 --- Initialization
328
329
330 local function create_table(name)
331         local Table, Column, Index = sql.Table, sql.Column, sql.Index;
332
333         local ProsodyTable = Table {
334                 name= name or "prosody";
335                 Column { name="host", type="TEXT", nullable=false };
336                 Column { name="user", type="TEXT", nullable=false };
337                 Column { name="store", type="TEXT", nullable=false };
338                 Column { name="key", type="TEXT", nullable=false };
339                 Column { name="type", type="TEXT", nullable=false };
340                 Column { name="value", type="MEDIUMTEXT", nullable=false };
341                 Index { name="prosody_index", "host", "user", "store", "key" };
342         };
343         engine:transaction(function()
344                 ProsodyTable:create(engine);
345         end);
346
347         local ProsodyArchiveTable = Table {
348                 name="prosodyarchive";
349                 Column { name="sort_id", type="INTEGER", primary_key=true, auto_increment=true };
350                 Column { name="host", type="TEXT", nullable=false };
351                 Column { name="user", type="TEXT", nullable=false };
352                 Column { name="store", type="TEXT", nullable=false };
353                 Column { name="key", type="TEXT", nullable=false }; -- item id
354                 Column { name="when", type="INTEGER", nullable=false }; -- timestamp
355                 Column { name="with", type="TEXT", nullable=false }; -- related id
356                 Column { name="type", type="TEXT", nullable=false };
357                 Column { name="value", type="MEDIUMTEXT", nullable=false };
358                 Index { name="prosodyarchive_index", unique = true, "host", "user", "store", "key" };
359         };
360         engine:transaction(function()
361                 ProsodyArchiveTable:create(engine);
362         end);
363 end
364
365 local function upgrade_table(params, apply_changes)
366         local changes = false;
367         if params.driver == "MySQL" then
368                 local success,err = engine:transaction(function()
369                         local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
370                         if result:rowcount() > 0 then
371                                 changes = true;
372                                 if apply_changes then
373                                         module:log("info", "Upgrading database schema...");
374                                         engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
375                                         module:log("info", "Database table automatically upgraded");
376                                 end
377                         end
378                         return true;
379                 end);
380                 if not success then
381                         module:log("error", "Failed to check/upgrade database schema (%s), please see "
382                                 .."http://prosody.im/doc/mysql for help",
383                                 err or "unknown error");
384                         return false;
385                 end
386
387                 -- COMPAT w/pre-0.10: Upgrade table to UTF-8 if not already
388                 local check_encoding_query = "SELECT `COLUMN_NAME`,`COLUMN_TYPE`,`TABLE_NAME` FROM `information_schema`.`columns` WHERE `TABLE_NAME` LIKE 'prosody%%' AND ( `CHARACTER_SET_NAME`!='%s' OR `COLLATION_NAME`!='%s_bin' );";
389                 check_encoding_query = check_encoding_query:format(engine.charset, engine.charset);
390                 success,err = engine:transaction(function()
391                         local result = engine:execute(check_encoding_query);
392                         local n_bad_columns = result:rowcount();
393                         if n_bad_columns > 0 then
394                                 changes = true;
395                                 if apply_changes then
396                                         module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
397                                         local fix_column_query1 = "ALTER TABLE `%s` CHANGE `%s` `%s` BLOB;";
398                                         local fix_column_query2 = "ALTER TABLE `%s` CHANGE `%s` `%s` %s CHARACTER SET '%s' COLLATE '%s_bin';";
399                                         for row in result:rows() do
400                                                 local column_name, column_type, table_name  = unpack(row);
401                                                 module:log("debug", "Fixing column %s in table %s", column_name, table_name);
402                                                 engine:execute(fix_column_query1:format(table_name, column_name, column_name));
403                                                 engine:execute(fix_column_query2:format(table_name, column_name, column_name, column_type, engine.charset, engine.charset));
404                                         end
405                                         module:log("info", "Database encoding upgrade complete!");
406                                 end
407                         end
408                 end);
409                 success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
410                 if not success then
411                         module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
412                         return false;
413                 end
414         end
415         return changes;
416 end
417
418 local function normalize_params(params)
419         if params.driver == "SQLite3" then
420                 params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
421         end
422         assert(params.driver and params.database, "Configuration error: Both the SQL driver and the database need to be specified");
423         return params;
424 end
425
426 function module.load()
427         if prosody.prosodyctl then return; end
428         local params = normalize_params(module:get_option("sql", default_params));
429         engine = sql:create_engine(params, function (engine)
430                 if module:get_option("sql_manage_tables", true) then
431                         -- Automatically create table, ignore failure (table probably already exists)
432                         -- FIXME: we should check in information_schema, etc.
433                         create_table();
434                         -- Check whether the table needs upgrading
435                         if upgrade_table(params, false) then
436                                 module:log("error", "Old database format detected. Please run: prosodyctl mod_%s upgrade", module.name);
437                                 return false, "database upgrade needed";
438                         end
439                 end
440         end);
441
442         module:provides("storage", driver);
443 end
444
445 function module.command(arg)
446         local config = require "core.configmanager";
447         local prosodyctl = require "util.prosodyctl";
448         local command = table.remove(arg, 1);
449         if command == "upgrade" then
450                 -- We need to find every unique dburi in the config
451                 local uris = {};
452                 for host in pairs(prosody.hosts) do
453                         local params = config.get(host, "sql") or default_params;
454                         uris[sql.db2uri(params)] = params;
455                 end
456                 print("We will check and upgrade the following databases:\n");
457                 for _, params in pairs(uris) do
458                         print("", "["..params.driver.."] "..params.database..(params.host and " on "..params.host or ""));
459                 end
460                 print("");
461                 print("Ensure you have working backups of the above databases before continuing! ");
462                 if not prosodyctl.show_yesno("Continue with the database upgrade? [yN]") then
463                         print("Ok, no upgrade. But you do have backups, don't you? ...don't you?? :-)");
464                         return;
465                 end
466                 -- Upgrade each one
467                 for _, params in pairs(uris) do
468                         print("Checking "..params.database.."...");
469                         engine = sql:create_engine(params);
470                         upgrade_table(params, true);
471                 end
472                 print("All done!");
473         else
474                 print("Unknown command: "..command);
475         end
476 end