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