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