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