mod_storage_sql: Implement map:set_keys, allowing multiple keys to be set in the...
[prosody.git] / plugins / mod_storage_sql.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 map_store.remove = {};
131 function map_store:get(username, key)
132         local ok, result = engine:transaction(function()
133                 if type(key) == "string" and key ~= "" then
134                         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
135                                 return deserialize(row[1], row[2]);
136                         end
137                 else
138                         for row in engine:select("SELECT `type`, `value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?", host, username or "", self.store, "") do
139                                 local data = deserialize(row[1], row[2]);
140                                 return data and data[key] or nil;
141                         end
142                 end
143         end);
144         if not ok then return nil, result; end
145         return result;
146 end
147 function map_store:set(username, key, data)
148         return self:set_keys(username, { [key] = data or self.remove });
149 end
150 function map_store:set_keys(username, keydatas)
151         local ok, result = engine:transaction(function()
152                 for key, data in pairs(keydatas) do
153                         if type(key) == "string" and key ~= "" then
154                                 engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?",
155                                         host, username or "", self.store, key);
156                                 if data ~= self.remove then
157                                         local t, value = assert(serialize(data));
158                                         engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, username or "", self.store, key, t, value);
159                                 end
160                         else
161                                 local extradata = {};
162                                 for row in engine:select("SELECT `type`, `value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?", host, username or "", self.store, "") do
163                                         extradata = deserialize(row[1], row[2]);
164                                         break;
165                                 end
166                                 engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?",
167                                         host, username or "", self.store, "");
168                                 extradata[key] = data;
169                                 local t, value = assert(serialize(extradata));
170                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, username or "", self.store, "", t, value);
171                         end
172                 end
173                 return true;
174         end);
175         if not ok then return nil, result; end
176         return result;
177 end
178
179 local archive_store = {}
180 archive_store.caps = {
181         total = true;
182 };
183 archive_store.__index = archive_store
184 function archive_store:append(username, key, value, when, with)
185         if type(when) ~= "number" then
186                 when, with, value = value, when, with;
187         end
188         local user,store = username,self.store;
189         return engine:transaction(function()
190                 if key then
191                         engine:delete("DELETE FROM `prosodyarchive` WHERE `host`=? AND `user`=? AND `store`=? AND `key`=?", host, user or "", store, key);
192                 else
193                         key = uuid.generate();
194                 end
195                 local t, value = serialize(value);
196                 engine:insert("INSERT INTO `prosodyarchive` (`host`, `user`, `store`, `when`, `with`, `key`, `type`, `value`) VALUES (?,?,?,?,?,?,?,?)", host, user or "", store, when, with, key, t, value);
197                 return key;
198         end);
199 end
200
201 -- Helpers for building the WHERE clause
202 local function archive_where(query, args, where)
203         -- Time range, inclusive
204         if query.start then
205                 args[#args+1] = query.start
206                 where[#where+1] = "`when` >= ?"
207         end
208
209         if query["end"] then
210                 args[#args+1] = query["end"];
211                 if query.start then
212                         where[#where] = "`when` BETWEEN ? AND ?" -- is this inclusive?
213                 else
214                         where[#where+1] = "`when` <= ?"
215                 end
216         end
217
218         -- Related name
219         if query.with then
220                 where[#where+1] = "`with` = ?";
221                 args[#args+1] = query.with
222         end
223
224         -- Unique id
225         if query.key then
226                 where[#where+1] = "`key` = ?";
227                 args[#args+1] = query.key
228         end
229 end
230 local function archive_where_id_range(query, args, where)
231         local args_len = #args
232         -- Before or after specific item, exclusive
233         if query.after then  -- keys better be unique!
234                 where[#where+1] = "`sort_id` > (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? AND `host` = ? AND `user` = ? AND `store` = ? LIMIT 1)"
235                 args[args_len+1], args[args_len+2], args[args_len+3], args[args_len+4] = query.after, args[1], args[2], args[3];
236                 args_len = args_len + 4
237         end
238         if query.before then
239                 where[#where+1] = "`sort_id` < (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? AND `host` = ? AND `user` = ? AND `store` = ? LIMIT 1)"
240                 args[args_len+1], args[args_len+2], args[args_len+3], args[args_len+4] = query.before, args[1], args[2], args[3];
241         end
242 end
243
244 function archive_store:find(username, query)
245         query = query or {};
246         local user,store = username,self.store;
247         local total;
248         local ok, result = engine:transaction(function()
249                 local sql_query = "SELECT `key`, `type`, `value`, `when`, `with` FROM `prosodyarchive` WHERE %s ORDER BY `sort_id` %s%s;";
250                 local args = { host, user or "", store, };
251                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
252
253                 archive_where(query, args, where);
254
255                 -- Total matching
256                 if query.total then
257                         local stats = engine:select("SELECT COUNT(*) FROM `prosodyarchive` WHERE " .. t_concat(where, " AND "), unpack(args));
258                         if stats then
259                                 local _total = stats()
260                                 total = _total and _total[1];
261                         end
262                         if query.limit == 0 then -- Skip the real query
263                                 return noop, total;
264                         end
265                 end
266
267                 archive_where_id_range(query, args, where);
268
269                 if query.limit then
270                         args[#args+1] = query.limit;
271                 end
272
273                 sql_query = sql_query:format(t_concat(where, " AND "), query.reverse and "DESC" or "ASC", query.limit and " LIMIT ?" or "");
274                 module:log("debug", sql_query);
275                 return engine:select(sql_query, unpack(args));
276         end);
277         if not ok then return ok, result end
278         return function()
279                 local row = result();
280                 if row ~= nil then
281                         return row[1], deserialize(row[2], row[3]), row[4], row[5];
282                 end
283         end, total;
284 end
285
286 function archive_store:delete(username, query)
287         query = query or {};
288         local user,store = username,self.store;
289         return engine:transaction(function()
290                 local sql_query = "DELETE FROM `prosodyarchive` WHERE %s;";
291                 local args = { host, user or "", store, };
292                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
293                 if user == true then
294                         table.remove(args, 2);
295                         table.remove(where, 2);
296                 end
297                 archive_where(query, args, where);
298                 archive_where_id_range(query, args, where);
299                 sql_query = sql_query:format(t_concat(where, " AND "));
300                 module:log("debug", sql_query);
301                 return engine:delete(sql_query, unpack(args));
302         end);
303 end
304
305 local stores = {
306         keyval = keyval_store;
307         map = map_store;
308         archive = archive_store;
309 };
310
311 --- Implement storage driver API
312
313 -- FIXME: Some of these operations need to operate on the archive store(s) too
314
315 local driver = {};
316
317 function driver:open(store, typ)
318         local store_mt = stores[typ or "keyval"];
319         if store_mt then
320                 return setmetatable({ store = store }, store_mt);
321         end
322         return nil, "unsupported-store";
323 end
324
325 function driver:stores(username)
326         local query = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
327                 (username == true and "!=?" or "=?");
328         if username == true or not username then
329                 username = "";
330         end
331         local ok, result = engine:transaction(function()
332                 return engine:select(query, host, username);
333         end);
334         if not ok then return ok, result end
335         return iterator(result);
336 end
337
338 function driver:purge(username)
339         return engine:transaction(function()
340                 local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
341                 return true, err;
342         end);
343 end
344
345 --- Initialization
346
347
348 local function create_table(name)
349         local Table, Column, Index = sql.Table, sql.Column, sql.Index;
350
351         local ProsodyTable = Table {
352                 name= name or "prosody";
353                 Column { name="host", type="TEXT", nullable=false };
354                 Column { name="user", type="TEXT", nullable=false };
355                 Column { name="store", type="TEXT", nullable=false };
356                 Column { name="key", type="TEXT", nullable=false };
357                 Column { name="type", type="TEXT", nullable=false };
358                 Column { name="value", type="MEDIUMTEXT", nullable=false };
359                 Index { name="prosody_index", "host", "user", "store", "key" };
360         };
361         engine:transaction(function()
362                 ProsodyTable:create(engine);
363         end);
364
365         local ProsodyArchiveTable = Table {
366                 name="prosodyarchive";
367                 Column { name="sort_id", type="INTEGER", primary_key=true, auto_increment=true };
368                 Column { name="host", type="TEXT", nullable=false };
369                 Column { name="user", type="TEXT", nullable=false };
370                 Column { name="store", type="TEXT", nullable=false };
371                 Column { name="key", type="TEXT", nullable=false }; -- item id
372                 Column { name="when", type="INTEGER", nullable=false }; -- timestamp
373                 Column { name="with", type="TEXT", nullable=false }; -- related id
374                 Column { name="type", type="TEXT", nullable=false };
375                 Column { name="value", type="MEDIUMTEXT", nullable=false };
376                 Index { name="prosodyarchive_index", unique = true, "host", "user", "store", "key" };
377         };
378         engine:transaction(function()
379                 ProsodyArchiveTable:create(engine);
380         end);
381 end
382
383 local function upgrade_table(params, apply_changes)
384         local changes = false;
385         if params.driver == "MySQL" then
386                 local success,err = engine:transaction(function()
387                         local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
388                         if result:rowcount() > 0 then
389                                 changes = true;
390                                 if apply_changes then
391                                         module:log("info", "Upgrading database schema...");
392                                         engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
393                                         module:log("info", "Database table automatically upgraded");
394                                 end
395                         end
396                         return true;
397                 end);
398                 if not success then
399                         module:log("error", "Failed to check/upgrade database schema (%s), please see "
400                                 .."http://prosody.im/doc/mysql for help",
401                                 err or "unknown error");
402                         return false;
403                 end
404
405                 -- COMPAT w/pre-0.10: Upgrade table to UTF-8 if not already
406                 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' );";
407                 check_encoding_query = check_encoding_query:format(engine.charset, engine.charset);
408                 success,err = engine:transaction(function()
409                         local result = engine:execute(check_encoding_query);
410                         local n_bad_columns = result:rowcount();
411                         if n_bad_columns > 0 then
412                                 changes = true;
413                                 if apply_changes then
414                                         module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
415                                         local fix_column_query1 = "ALTER TABLE `%s` CHANGE `%s` `%s` BLOB;";
416                                         local fix_column_query2 = "ALTER TABLE `%s` CHANGE `%s` `%s` %s CHARACTER SET '%s' COLLATE '%s_bin';";
417                                         for row in result:rows() do
418                                                 local column_name, column_type, table_name  = unpack(row);
419                                                 module:log("debug", "Fixing column %s in table %s", column_name, table_name);
420                                                 engine:execute(fix_column_query1:format(table_name, column_name, column_name));
421                                                 engine:execute(fix_column_query2:format(table_name, column_name, column_name, column_type, engine.charset, engine.charset));
422                                         end
423                                         module:log("info", "Database encoding upgrade complete!");
424                                 end
425                         end
426                 end);
427                 success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
428                 if not success then
429                         module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
430                         return false;
431                 end
432         end
433         return changes;
434 end
435
436 local function normalize_params(params)
437         if params.driver == "SQLite3" then
438                 if params.database ~= ":memory:" then
439                         params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
440                 end
441         end
442         assert(params.driver and params.database, "Configuration error: Both the SQL driver and the database need to be specified");
443         return params;
444 end
445
446 function module.load()
447         if prosody.prosodyctl then return; end
448         local params = normalize_params(module:get_option("sql", default_params));
449         engine = sql:create_engine(params, function (engine)
450                 if module:get_option("sql_manage_tables", true) then
451                         -- Automatically create table, ignore failure (table probably already exists)
452                         -- FIXME: we should check in information_schema, etc.
453                         create_table();
454                         -- Check whether the table needs upgrading
455                         if upgrade_table(params, false) then
456                                 module:log("error", "Old database format detected. Please run: prosodyctl mod_%s upgrade", module.name);
457                                 return false, "database upgrade needed";
458                         end
459                 end
460         end);
461
462         module:provides("storage", driver);
463 end
464
465 function module.command(arg)
466         local config = require "core.configmanager";
467         local prosodyctl = require "util.prosodyctl";
468         local command = table.remove(arg, 1);
469         if command == "upgrade" then
470                 -- We need to find every unique dburi in the config
471                 local uris = {};
472                 for host in pairs(prosody.hosts) do
473                         local params = config.get(host, "sql") or default_params;
474                         uris[sql.db2uri(params)] = params;
475                 end
476                 print("We will check and upgrade the following databases:\n");
477                 for _, params in pairs(uris) do
478                         print("", "["..params.driver.."] "..params.database..(params.host and " on "..params.host or ""));
479                 end
480                 print("");
481                 print("Ensure you have working backups of the above databases before continuing! ");
482                 if not prosodyctl.show_yesno("Continue with the database upgrade? [yN]") then
483                         print("Ok, no upgrade. But you do have backups, don't you? ...don't you?? :-)");
484                         return;
485                 end
486                 -- Upgrade each one
487                 for _, params in pairs(uris) do
488                         print("Checking "..params.database.."...");
489                         engine = sql:create_engine(params);
490                         upgrade_table(params, true);
491                 end
492                 print("All done!");
493         else
494                 print("Unknown command: "..command);
495         end
496 end