mod_storage_sql2: Move all schema upgrade code to the same place
[prosody.git] / plugins / mod_storage_sql2.lua
1
2 local json = require "util.json";
3 local xml_parse = require "util.xml".parse;
4 local uuid = require "util.uuid";
5 local resolve_relative_path = require "core.configmanager".resolve_relative_path;
6
7 local stanza_mt = require"util.stanza".stanza_mt;
8 local getmetatable = getmetatable;
9 local t_concat = table.concat;
10 local function is_stanza(x) return getmetatable(x) == stanza_mt; end
11
12 local noop = function() end
13 local unpack = unpack
14 local function iterator(result)
15         return function(result)
16                 local row = result();
17                 if row ~= nil then
18                         return unpack(row);
19                 end
20         end, result, nil;
21 end
22
23 local mod_sql = module:require("sql");
24 local params = module:get_option("sql");
25
26 local engine; -- TODO create engine
27
28 local function create_table()
29         local Table,Column,Index = mod_sql.Table,mod_sql.Column,mod_sql.Index;
30         --[[
31         local ProsodyTable = Table {
32                 name="prosody";
33                 Column { name="host", type="TEXT", nullable=false };
34                 Column { name="user", type="TEXT", nullable=false };
35                 Column { name="store", type="TEXT", nullable=false };
36                 Column { name="key", type="TEXT", nullable=false };
37                 Column { name="type", type="TEXT", nullable=false };
38                 Column { name="value", type="TEXT", nullable=false };
39                 Index { name="prosody_index", "host", "user", "store", "key" };
40         };
41         engine:transaction(function()
42                 ProsodyTable:create(engine);
43         end);]]
44         if not module:get_option("sql_manage_tables", true) then
45                 return;
46         end
47
48         local create_sql = "CREATE TABLE `prosody` (`host` TEXT, `user` TEXT, `store` TEXT, `key` TEXT, `type` TEXT, `value` TEXT);";
49         if params.driver == "PostgreSQL" then
50                 create_sql = create_sql:gsub("`", "\"");
51         elseif params.driver == "MySQL" then
52                 create_sql = create_sql:gsub("`value` TEXT", "`value` MEDIUMTEXT")
53                         :gsub(";$", " CHARACTER SET 'utf8' COLLATE 'utf8_bin';");
54         end
55
56         local index_sql = "CREATE INDEX `prosody_index` ON `prosody` (`host`, `user`, `store`, `key`)";
57         if params.driver == "PostgreSQL" then
58                 index_sql = index_sql:gsub("`", "\"");
59         elseif params.driver == "MySQL" then
60                 index_sql = index_sql:gsub("`([,)])", "`(20)%1");
61         end
62
63         local success,err = engine:transaction(function()
64                 engine:execute(create_sql);
65                 engine:execute(index_sql);
66         end);
67
68         local ProsodyArchiveTable = Table {
69                 name="prosodyarchive";
70                 Column { name="sort_id", type="INTEGER PRIMARY KEY AUTOINCREMENT", nullable=false };
71                 Column { name="host", type="TEXT", nullable=false };
72                 Column { name="user", type="TEXT", nullable=false };
73                 Column { name="store", type="TEXT", nullable=false };
74                 Column { name="key", type="TEXT", nullable=false }; -- item id
75                 Column { name="when", type="INTEGER", nullable=false }; -- timestamp
76                 Column { name="with", type="TEXT", nullable=false }; -- related id
77                 Column { name="type", type="TEXT", nullable=false };
78                 Column { name="value", type=params.driver == "MySQL" and "MEDIUMTEXT" or "TEXT", nullable=false };
79                 Index { name="prosodyarchive_index", "host", "user", "store", "key" };
80         };
81         engine:transaction(function()
82                 ProsodyArchiveTable:create(engine);
83         end);
84 end
85 local function set_encoding()
86         if params.driver == "SQLite3" then return end
87         local set_names_query = "SET NAMES 'utf8';";
88         if params.driver == "MySQL" then
89                 set_names_query = set_names_query:gsub(";$", " COLLATE 'utf8_bin';");
90         end
91         local success,err = engine:transaction(function() return engine:execute(set_names_query); end);
92         if not success then
93                 module:log("error", "Failed to set database connection encoding to UTF8: %s", err);
94         end
95 end
96 local function upgrade_table()
97         if params.driver == "MySQL" then
98                 local success,err = engine:transaction(function()
99                         local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
100                         if result:rowcount() > 0 then
101                                 module:log("info", "Upgrading database schema...");
102                                 engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
103                                 module:log("info", "Database table automatically upgraded");
104                         end
105                         return true;
106                 end);
107                 if not success then
108                         module:log("error", "Failed to check/upgrade database schema (%s), please see "
109                                 .."http://prosody.im/doc/mysql for help",
110                                 err or "unknown error");
111                         return false;
112                 end
113                 -- COMPAT w/pre-0.9: Upgrade tables to UTF-8 if not already
114                 local check_encoding_query = "SELECT `COLUMN_NAME`,`COLUMN_TYPE` FROM `information_schema`.`columns` WHERE `TABLE_NAME`='prosody' AND ( `CHARACTER_SET_NAME`!='utf8' OR `COLLATION_NAME`!='utf8_bin' );";
115                 success,err = engine:transaction(function()
116                         local result = engine:execute(check_encoding_query);
117                         local n_bad_columns = result:rowcount();
118                         if n_bad_columns > 0 then
119                                 module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
120                                 local fix_column_query1 = "ALTER TABLE `prosody` CHANGE `%s` `%s` BLOB;";
121                                 local fix_column_query2 = "ALTER TABLE `prosody` CHANGE `%s` `%s` %s CHARACTER SET 'utf8' COLLATE 'utf8_bin';";
122                                 for row in result:rows() do
123                                         local column_name, column_type = unpack(row);
124                                         engine:execute(fix_column_query1:format(column_name, column_name));
125                                         engine:execute(fix_column_query2:format(column_name, column_name, column_type));
126                                 end
127                                 module:log("info", "Database encoding upgrade complete!");
128                         end
129                 end);
130                 success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
131                 if not success then
132                         module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
133                 end
134         end
135 end
136
137 do -- process options to get a db connection
138         params = params or { driver = "SQLite3" };
139
140         if params.driver == "SQLite3" then
141                 params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
142         end
143
144         assert(params.driver and params.database, "Both the SQL driver and the database need to be specified");
145
146         --local dburi = db2uri(params);
147         engine = mod_sql:create_engine(params);
148
149         set_encoding();
150
151         -- Automatically create table, ignore failure (table probably already exists)
152         create_table();
153         -- Encoding mess
154         upgrade_table();
155 end
156
157 local function serialize(value)
158         local t = type(value);
159         if t == "string" or t == "boolean" or t == "number" then
160                 return t, tostring(value);
161         elseif is_stanza(value) then
162                 return "xml", tostring(value);
163         elseif t == "table" then
164                 local value,err = json.encode(value);
165                 if value then return "json", value; end
166                 return nil, err;
167         end
168         return nil, "Unhandled value type: "..t;
169 end
170 local function deserialize(t, value)
171         if t == "string" then return value;
172         elseif t == "boolean" then
173                 if value == "true" then return true;
174                 elseif value == "false" then return false; end
175         elseif t == "number" then return tonumber(value);
176         elseif t == "json" then
177                 return json.decode(value);
178         elseif t == "xml" then
179                 return xml_parse(value);
180         end
181 end
182
183 local host = module.host;
184 local user, store;
185
186 local function keyval_store_get()
187         local haveany;
188         local result = {};
189         for row in engine:select("SELECT `key`,`type`,`value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store) do
190                 haveany = true;
191                 local k = row[1];
192                 local v = deserialize(row[2], row[3]);
193                 if k and v then
194                         if k ~= "" then result[k] = v; elseif type(v) == "table" then
195                                 for a,b in pairs(v) do
196                                         result[a] = b;
197                                 end
198                         end
199                 end
200         end
201         if haveany then
202                 return result;
203         end
204 end
205 local function keyval_store_set(data)
206         engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store);
207
208         if data and next(data) ~= nil then
209                 local extradata = {};
210                 for key, value in pairs(data) do
211                         if type(key) == "string" and key ~= "" then
212                                 local t, value = serialize(value);
213                                 assert(t, value);
214                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, key, t, value);
215                         else
216                                 extradata[key] = value;
217                         end
218                 end
219                 if next(extradata) ~= nil then
220                         local t, extradata = serialize(extradata);
221                         assert(t, extradata);
222                         engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, "", t, extradata);
223                 end
224         end
225         return true;
226 end
227
228 local keyval_store = {};
229 keyval_store.__index = keyval_store;
230 function keyval_store:get(username)
231         user,store = username,self.store;
232         return select(2, engine:transaction(keyval_store_get));
233 end
234 function keyval_store:set(username, data)
235         user,store = username,self.store;
236         return engine:transaction(function()
237                 return keyval_store_set(data);
238         end);
239 end
240 function keyval_store:users()
241         local ok, result = engine:transaction(function()
242                 return engine:select("SELECT DISTINCT `user` FROM `prosody` WHERE `host`=? AND `store`=?", host, self.store);
243         end);
244         if not ok then return ok, result end
245         return iterator(result);
246 end
247
248 local archive_store = {}
249 archive_store.__index = archive_store
250 function archive_store:append(username, when, with, value)
251         local user,store = username,self.store;
252         return engine:transaction(function()
253                 local key = uuid.generate();
254                 local t, value = serialize(value);
255                 engine:insert("INSERT INTO `prosodyarchive` (`host`, `user`, `store`, `when`, `with`, `key`, `type`, `value`) VALUES (?,?,?,?,?,?,?,?)", host, user or "", store, when, with, key, t, value);
256                 return key;
257         end);
258 end
259
260 -- Helpers for building the WHERE clause
261 local function archive_where(query, args, where)
262         -- Time range, inclusive
263         if query.start then
264                 args[#args+1] = query.start
265                 where[#where+1] = "`when` >= ?"
266         end
267
268         if query["end"] then
269                 args[#args+1] = query["end"];
270                 if query.start then
271                         where[#where] = "`when` BETWEEN ? AND ?" -- is this inclusive?
272                 else
273                         where[#where+1] = "`when` >= ?"
274                 end
275         end
276
277         -- Related name
278         if query.with then
279                 where[#where+1] = "`with` = ?";
280                 args[#args+1] = query.with
281         end
282
283         -- Unique id
284         if query.key then
285                 where[#where+1] = "`key` = ?";
286                 args[#args+1] = query.key
287         end
288 end
289 local function archive_where_id_range(query, args, where)
290         -- Before or after specific item, exclusive
291         if query.after then  -- keys better be unique!
292                 where[#where+1] = "`sort_id` > (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? LIMIT 1)"
293                 args[#args+1] = query.after
294         end
295         if query.before then
296                 where[#where+1] = "`sort_id` < (SELECT `sort_id` FROM `prosodyarchive` WHERE `key` = ? LIMIT 1)"
297                 args[#args+1] = query.before
298         end
299 end
300
301 function archive_store:find(username, query)
302         query = query or {};
303         local user,store = username,self.store;
304         local total;
305         local ok, result = engine:transaction(function()
306                 local sql_query = "SELECT `key`, `type`, `value`, `when` FROM `prosodyarchive` WHERE %s ORDER BY `sort_id` %s%s;";
307                 local args = { host, user or "", store, };
308                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
309
310                 archive_where(query, args, where);
311
312                 -- Total matching
313                 if query.total then
314                         local stats = engine:select(sql_query:gsub("^(SELECT).-(FROM)", "%1 COUNT(*) %2"):format(t_concat(where, " AND "), "DESC", ""), unpack(args));
315                         if stats then
316                                 local _total = stats()
317                                 total = _total and _total[1];
318                         end
319                         if query.limit == 0 then -- Skip the real query
320                                 return noop, total;
321                         end
322                 end
323
324                 archive_where_id_range(query, args, where);
325
326                 if query.limit then
327                         args[#args+1] = query.limit;
328                 end
329
330                 sql_query = sql_query:format(t_concat(where, " AND "), query.reverse and "DESC" or "ASC", query.limit and " LIMIT ?" or "");
331                 module:log("debug", sql_query);
332                 return engine:select(sql_query, unpack(args));
333         end);
334         if not ok then return ok, result end
335         return function()
336                 local row = result();
337                 if row ~= nil then
338                         return row[1], deserialize(row[2], row[3]), row[4];
339                 end
340         end, total;
341 end
342
343 function archive_store:delete(username, query)
344         query = query or {};
345         local user,store = username,self.store;
346         return engine:transaction(function()
347                 local sql_query = "DELETE FROM `prosodyarchive` WHERE %s;";
348                 local args = { host, user or "", store, };
349                 local where = { "`host` = ?", "`user` = ?", "`store` = ?", };
350                 archive_where(query, args, where);
351                 archive_where_id_range(query, args, where);
352                 sql_query = sql_query:format(t_concat(where, " AND "));
353                 module:log("debug", sql_query);
354                 return engine:delete(sql_query, unpack(args));
355         end);
356 end
357
358 local stores = {
359         keyval = keyval_store;
360         archive = archive_store;
361 };
362
363 local driver = {};
364
365 function driver:open(store, typ)
366         local store_mt = stores[typ or "keyval"];
367         if store_mt then
368                 return setmetatable({ store = store }, store_mt);
369         end
370         return nil, "unsupported-store";
371 end
372
373 function driver:stores(username)
374         local sql = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
375                 (username == true and "!=?" or "=?");
376         if username == true or not username then
377                 username = "";
378         end
379         local ok, result = engine:transaction(function()
380                 return engine:select(sql, host, username);
381         end);
382         if not ok then return ok, result end
383         return iterator(result);
384 end
385
386 function driver:purge(username)
387         return engine:transaction(function()
388                 local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
389                 return true,err;
390         end);
391 end
392
393 module:provides("storage", driver);
394
395