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