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