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