mod_storage_sql2: Create an additional table `prosodyarchive` for chronological colle...
[prosody.git] / plugins / mod_storage_sql2.lua
1
2 local json = require "util.json";
3 local xml_parse = require "util.xml".parse;
4 local resolve_relative_path = require "core.configmanager".resolve_relative_path;
5
6 local stanza_mt = require"util.stanza".stanza_mt;
7 local getmetatable = getmetatable;
8 local function is_stanza(x) return getmetatable(x) == stanza_mt; end
9
10 local unpack = unpack
11 local function iterator(result)
12         return function(result)
13                 local row = result();
14                 if row ~= nil then
15                         return unpack(row);
16                 end
17         end, result, nil;
18 end
19
20 local mod_sql = module:require("sql");
21 local params = module:get_option("sql");
22
23 local engine; -- TODO create engine
24
25 local function create_table()
26         local Table,Column,Index = mod_sql.Table,mod_sql.Column,mod_sql.Index;
27         --[[
28         local ProsodyTable = Table {
29                 name="prosody";
30                 Column { name="host", type="TEXT", nullable=false };
31                 Column { name="user", type="TEXT", nullable=false };
32                 Column { name="store", type="TEXT", nullable=false };
33                 Column { name="key", type="TEXT", nullable=false };
34                 Column { name="type", type="TEXT", nullable=false };
35                 Column { name="value", type="TEXT", nullable=false };
36                 Index { name="prosody_index", "host", "user", "store", "key" };
37         };
38         engine:transaction(function()
39                 ProsodyTable:create(engine);
40         end);]]
41         if not module:get_option("sql_manage_tables", true) then
42                 return;
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         if not success then -- so we failed to create
65                 if params.driver == "MySQL" then
66                         success,err = engine:transaction(function()
67                                 local result = engine:execute("SHOW COLUMNS FROM prosody WHERE Field='value' and Type='text'");
68                                 if result:rowcount() > 0 then
69                                         module:log("info", "Upgrading database schema...");
70                                         engine:execute("ALTER TABLE prosody MODIFY COLUMN `value` MEDIUMTEXT");
71                                         module:log("info", "Database table automatically upgraded");
72                                 end
73                                 return true;
74                         end);
75                         if not success then
76                                 module:log("error", "Failed to check/upgrade database schema (%s), please see "
77                                         .."http://prosody.im/doc/mysql for help",
78                                         err or "unknown error");
79                         end
80                 end
81         end
82         local ProsodyArchiveTable = Table {
83                 name="prosodyarchive";
84                 Column { name="sort_id", type="INTEGER PRIMARY KEY AUTOINCREMENT", nullable=false };
85                 Column { name="host", type="TEXT", nullable=false };
86                 Column { name="user", type="TEXT", nullable=false };
87                 Column { name="store", type="TEXT", nullable=false };
88                 Column { name="key", type="TEXT", nullable=false }; -- item id
89                 Column { name="when", type="INTEGER", nullable=false }; -- timestamp
90                 Column { name="with", type="TEXT", nullable=false }; -- related id
91                 Column { name="type", type="TEXT", nullable=false };
92                 Column { name="value", type=params.driver == "MySQL" and "MEDIUMTEXT" or "TEXT", nullable=false };
93                 Index { name="prosodyarchive_index", "host", "user", "store", "key" };
94         };
95         engine:transaction(function()
96                 ProsodyArchiveTable:create(engine);
97         end);
98 end
99 local function set_encoding()
100         if params.driver ~= "SQLite3" then
101                 local set_names_query = "SET NAMES 'utf8';";
102                 if params.driver == "MySQL" then
103                         set_names_query = set_names_query:gsub(";$", " COLLATE 'utf8_bin';");
104                 end
105                 local success,err = engine:transaction(function() return engine:execute(set_names_query); end);
106                 if not success then
107                         module:log("error", "Failed to set database connection encoding to UTF8: %s", err);
108                         return;
109                 end
110                 if params.driver == "MySQL" then
111                         -- COMPAT w/pre-0.9: Upgrade tables to UTF-8 if not already
112                         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' );";
113                         local success,err = engine:transaction(function()
114                                 local result = engine:execute(check_encoding_query);
115                                 local n_bad_columns = result:rowcount();
116                                 if n_bad_columns > 0 then
117                                         module:log("warn", "Found %d columns in prosody table requiring encoding change, updating now...", n_bad_columns);
118                                         local fix_column_query1 = "ALTER TABLE `prosody` CHANGE `%s` `%s` BLOB;";
119                                         local fix_column_query2 = "ALTER TABLE `prosody` CHANGE `%s` `%s` %s CHARACTER SET 'utf8' COLLATE 'utf8_bin';";
120                                         for row in result:rows() do
121                                                 local column_name, column_type = unpack(row);
122                                                 engine:execute(fix_column_query1:format(column_name, column_name));
123                                                 engine:execute(fix_column_query2:format(column_name, column_name, column_type));
124                                         end
125                                         module:log("info", "Database encoding upgrade complete!");
126                                 end
127                         end);
128                         local success,err = engine:transaction(function() return engine:execute(check_encoding_query); end);
129                         if not success then
130                                 module:log("error", "Failed to check/upgrade database encoding: %s", err or "unknown error");
131                         end
132                 end
133         end
134 end
135
136 do -- process options to get a db connection
137         params = params or { driver = "SQLite3" };
138         
139         if params.driver == "SQLite3" then
140                 params.database = resolve_relative_path(prosody.paths.data or ".", params.database or "prosody.sqlite");
141         end
142         
143         assert(params.driver and params.database, "Both the SQL driver and the database need to be specified");
144
145         --local dburi = db2uri(params);
146         engine = mod_sql:create_engine(params);
147         
148         -- Encoding mess
149         set_encoding();
150
151         -- Automatically create table, ignore failure (table probably already exists)
152         create_table();
153 end
154
155 local function serialize(value)
156         local t = type(value);
157         if t == "string" or t == "boolean" or t == "number" then
158                 return t, tostring(value);
159         elseif is_stanza(value) then
160                 return "xml", tostring(value);
161         elseif t == "table" then
162                 local value,err = json.encode(value);
163                 if value then return "json", value; end
164                 return nil, err;
165         end
166         return nil, "Unhandled value type: "..t;
167 end
168 local function deserialize(t, value)
169         if t == "string" then return value;
170         elseif t == "boolean" then
171                 if value == "true" then return true;
172                 elseif value == "false" then return false; end
173         elseif t == "number" then return tonumber(value);
174         elseif t == "json" then
175                 return json.decode(value);
176         elseif t == "xml" then
177                 return xml_parse(value);
178         end
179 end
180
181 local host = module.host;
182 local user, store;
183
184 local function keyval_store_get()
185         local haveany;
186         local result = {};
187         for row in engine:select("SELECT `key`,`type`,`value` FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store) do
188                 haveany = true;
189                 local k = row[1];
190                 local v = deserialize(row[2], row[3]);
191                 if k and v then
192                         if k ~= "" then result[k] = v; elseif type(v) == "table" then
193                                 for a,b in pairs(v) do
194                                         result[a] = b;
195                                 end
196                         end
197                 end
198         end
199         if haveany then
200                 return result;
201         end
202 end
203 local function keyval_store_set(data)
204         engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=? AND `store`=?", host, user or "", store);
205         
206         if data and next(data) ~= nil then
207                 local extradata = {};
208                 for key, value in pairs(data) do
209                         if type(key) == "string" and key ~= "" then
210                                 local t, value = serialize(value);
211                                 assert(t, value);
212                                 engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, key, t, value);
213                         else
214                                 extradata[key] = value;
215                         end
216                 end
217                 if next(extradata) ~= nil then
218                         local t, extradata = serialize(extradata);
219                         assert(t, extradata);
220                         engine:insert("INSERT INTO `prosody` (`host`,`user`,`store`,`key`,`type`,`value`) VALUES (?,?,?,?,?,?)", host, user or "", store, "", t, extradata);
221                 end
222         end
223         return true;
224 end
225
226 local keyval_store = {};
227 keyval_store.__index = keyval_store;
228 function keyval_store:get(username)
229         user,store = username,self.store;
230         return select(2, engine:transaction(keyval_store_get));
231 end
232 function keyval_store:set(username, data)
233         user,store = username,self.store;
234         return engine:transaction(function()
235                 return keyval_store_set(data);
236         end);
237 end
238 function keyval_store:users()
239         local ok, result = engine:transaction(function()
240                 return engine:select("SELECT DISTINCT `user` FROM `prosody` WHERE `host`=? AND `store`=?", host, self.store);
241         end);
242         if not ok then return ok, result end
243         return iterator(result);
244 end
245
246 local stores = {
247         keyval = keyval_store;
248 };
249
250 local driver = {};
251
252 function driver:open(store, typ)
253         local store_mt = stores[typ or "keyval"];
254         if store_mt then
255                 return setmetatable({ store = store }, store_mt);
256         end
257         return nil, "unsupported-store";
258 end
259
260 function driver:stores(username)
261         local sql = "SELECT DISTINCT `store` FROM `prosody` WHERE `host`=? AND `user`" ..
262                 (username == true and "!=?" or "=?");
263         if username == true or not username then
264                 username = "";
265         end
266         local ok, result = engine:transaction(function()
267                 return engine:select(sql, host, username);
268         end);
269         if not ok then return ok, result end
270         return iterator(result);
271 end
272
273 function driver:purge(username)
274         return engine:transaction(function()
275                 local stmt,err = engine:delete("DELETE FROM `prosody` WHERE `host`=? AND `user`=?", host, username);
276                 return true,err;
277         end);
278 end
279
280 module:provides("storage", driver);
281
282