1package eu.siacs.conversations.persistance;
2
3import android.content.ContentValues;
4import android.content.Context;
5import android.database.Cursor;
6import android.database.DatabaseUtils;
7import android.database.sqlite.SQLiteDatabase;
8import android.database.sqlite.SQLiteOpenHelper;
9import android.os.Environment;
10import android.os.SystemClock;
11import android.util.Base64;
12import android.util.Log;
13
14import com.google.common.base.Stopwatch;
15
16import org.json.JSONException;
17import org.json.JSONObject;
18import org.whispersystems.libsignal.IdentityKey;
19import org.whispersystems.libsignal.IdentityKeyPair;
20import org.whispersystems.libsignal.InvalidKeyException;
21import org.whispersystems.libsignal.SignalProtocolAddress;
22import org.whispersystems.libsignal.state.PreKeyRecord;
23import org.whispersystems.libsignal.state.SessionRecord;
24import org.whispersystems.libsignal.state.SignedPreKeyRecord;
25
26import java.io.ByteArrayInputStream;
27import java.io.File;
28import java.io.IOException;
29import java.security.cert.CertificateEncodingException;
30import java.security.cert.CertificateException;
31import java.security.cert.CertificateFactory;
32import java.security.cert.X509Certificate;
33import java.util.ArrayList;
34import java.util.HashMap;
35import java.util.HashSet;
36import java.util.List;
37import java.util.Map;
38import java.util.Set;
39import java.util.UUID;
40import java.util.concurrent.CopyOnWriteArrayList;
41
42import io.ipfs.cid.Cid;
43
44import eu.siacs.conversations.Config;
45import eu.siacs.conversations.crypto.axolotl.AxolotlService;
46import eu.siacs.conversations.crypto.axolotl.FingerprintStatus;
47import eu.siacs.conversations.crypto.axolotl.SQLiteAxolotlStore;
48import eu.siacs.conversations.entities.Account;
49import eu.siacs.conversations.entities.Contact;
50import eu.siacs.conversations.entities.Conversation;
51import eu.siacs.conversations.entities.DownloadableFile;
52import eu.siacs.conversations.entities.Message;
53import eu.siacs.conversations.entities.PresenceTemplate;
54import eu.siacs.conversations.entities.Roster;
55import eu.siacs.conversations.entities.ServiceDiscoveryResult;
56import eu.siacs.conversations.services.QuickConversationsService;
57import eu.siacs.conversations.services.ShortcutService;
58import eu.siacs.conversations.utils.CryptoHelper;
59import eu.siacs.conversations.utils.CursorUtils;
60import eu.siacs.conversations.utils.FtsUtils;
61import eu.siacs.conversations.utils.MimeUtils;
62import eu.siacs.conversations.utils.Resolver;
63import eu.siacs.conversations.xmpp.InvalidJid;
64import eu.siacs.conversations.xmpp.Jid;
65import eu.siacs.conversations.xmpp.mam.MamReference;
66
67public class DatabaseBackend extends SQLiteOpenHelper {
68
69 private static final String DATABASE_NAME = "history";
70 private static final int DATABASE_VERSION = 51;
71
72 private static boolean requiresMessageIndexRebuild = false;
73 private static DatabaseBackend instance = null;
74 private static final String CREATE_CONTATCS_STATEMENT = "create table "
75 + Contact.TABLENAME + "(" + Contact.ACCOUNT + " TEXT, "
76 + Contact.SERVERNAME + " TEXT, " + Contact.SYSTEMNAME + " TEXT,"
77 + Contact.PRESENCE_NAME + " TEXT,"
78 + Contact.JID + " TEXT," + Contact.KEYS + " TEXT,"
79 + Contact.PHOTOURI + " TEXT," + Contact.OPTIONS + " NUMBER,"
80 + Contact.SYSTEMACCOUNT + " NUMBER, " + Contact.AVATAR + " TEXT, "
81 + Contact.LAST_PRESENCE + " TEXT, " + Contact.LAST_TIME + " NUMBER, "
82 + Contact.RTP_CAPABILITY + " TEXT,"
83 + Contact.GROUPS + " TEXT, FOREIGN KEY(" + Contact.ACCOUNT + ") REFERENCES "
84 + Account.TABLENAME + "(" + Account.UUID
85 + ") ON DELETE CASCADE, UNIQUE(" + Contact.ACCOUNT + ", "
86 + Contact.JID + ") ON CONFLICT REPLACE);";
87
88 private static final String CREATE_DISCOVERY_RESULTS_STATEMENT = "create table "
89 + ServiceDiscoveryResult.TABLENAME + "("
90 + ServiceDiscoveryResult.HASH + " TEXT, "
91 + ServiceDiscoveryResult.VER + " TEXT, "
92 + ServiceDiscoveryResult.RESULT + " TEXT, "
93 + "UNIQUE(" + ServiceDiscoveryResult.HASH + ", "
94 + ServiceDiscoveryResult.VER + ") ON CONFLICT REPLACE);";
95
96 private static final String CREATE_PRESENCE_TEMPLATES_STATEMENT = "CREATE TABLE "
97 + PresenceTemplate.TABELNAME + "("
98 + PresenceTemplate.UUID + " TEXT, "
99 + PresenceTemplate.LAST_USED + " NUMBER,"
100 + PresenceTemplate.MESSAGE + " TEXT,"
101 + PresenceTemplate.STATUS + " TEXT,"
102 + "UNIQUE(" + PresenceTemplate.MESSAGE + "," + PresenceTemplate.STATUS + ") ON CONFLICT REPLACE);";
103
104 private static final String CREATE_PREKEYS_STATEMENT = "CREATE TABLE "
105 + SQLiteAxolotlStore.PREKEY_TABLENAME + "("
106 + SQLiteAxolotlStore.ACCOUNT + " TEXT, "
107 + SQLiteAxolotlStore.ID + " INTEGER, "
108 + SQLiteAxolotlStore.KEY + " TEXT, FOREIGN KEY("
109 + SQLiteAxolotlStore.ACCOUNT
110 + ") REFERENCES " + Account.TABLENAME + "(" + Account.UUID + ") ON DELETE CASCADE, "
111 + "UNIQUE( " + SQLiteAxolotlStore.ACCOUNT + ", "
112 + SQLiteAxolotlStore.ID
113 + ") ON CONFLICT REPLACE"
114 + ");";
115
116 private static final String CREATE_SIGNED_PREKEYS_STATEMENT = "CREATE TABLE "
117 + SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME + "("
118 + SQLiteAxolotlStore.ACCOUNT + " TEXT, "
119 + SQLiteAxolotlStore.ID + " INTEGER, "
120 + SQLiteAxolotlStore.KEY + " TEXT, FOREIGN KEY("
121 + SQLiteAxolotlStore.ACCOUNT
122 + ") REFERENCES " + Account.TABLENAME + "(" + Account.UUID + ") ON DELETE CASCADE, "
123 + "UNIQUE( " + SQLiteAxolotlStore.ACCOUNT + ", "
124 + SQLiteAxolotlStore.ID
125 + ") ON CONFLICT REPLACE" +
126 ");";
127
128 private static final String CREATE_SESSIONS_STATEMENT = "CREATE TABLE "
129 + SQLiteAxolotlStore.SESSION_TABLENAME + "("
130 + SQLiteAxolotlStore.ACCOUNT + " TEXT, "
131 + SQLiteAxolotlStore.NAME + " TEXT, "
132 + SQLiteAxolotlStore.DEVICE_ID + " INTEGER, "
133 + SQLiteAxolotlStore.KEY + " TEXT, FOREIGN KEY("
134 + SQLiteAxolotlStore.ACCOUNT
135 + ") REFERENCES " + Account.TABLENAME + "(" + Account.UUID + ") ON DELETE CASCADE, "
136 + "UNIQUE( " + SQLiteAxolotlStore.ACCOUNT + ", "
137 + SQLiteAxolotlStore.NAME + ", "
138 + SQLiteAxolotlStore.DEVICE_ID
139 + ") ON CONFLICT REPLACE"
140 + ");";
141
142 private static final String CREATE_IDENTITIES_STATEMENT = "CREATE TABLE "
143 + SQLiteAxolotlStore.IDENTITIES_TABLENAME + "("
144 + SQLiteAxolotlStore.ACCOUNT + " TEXT, "
145 + SQLiteAxolotlStore.NAME + " TEXT, "
146 + SQLiteAxolotlStore.OWN + " INTEGER, "
147 + SQLiteAxolotlStore.FINGERPRINT + " TEXT, "
148 + SQLiteAxolotlStore.CERTIFICATE + " BLOB, "
149 + SQLiteAxolotlStore.TRUST + " TEXT, "
150 + SQLiteAxolotlStore.ACTIVE + " NUMBER, "
151 + SQLiteAxolotlStore.LAST_ACTIVATION + " NUMBER,"
152 + SQLiteAxolotlStore.KEY + " TEXT, FOREIGN KEY("
153 + SQLiteAxolotlStore.ACCOUNT
154 + ") REFERENCES " + Account.TABLENAME + "(" + Account.UUID + ") ON DELETE CASCADE, "
155 + "UNIQUE( " + SQLiteAxolotlStore.ACCOUNT + ", "
156 + SQLiteAxolotlStore.NAME + ", "
157 + SQLiteAxolotlStore.FINGERPRINT
158 + ") ON CONFLICT IGNORE"
159 + ");";
160
161 private static final String RESOLVER_RESULTS_TABLENAME = "resolver_results";
162
163 private static final String CREATE_RESOLVER_RESULTS_TABLE = "create table " + RESOLVER_RESULTS_TABLENAME + "("
164 + Resolver.Result.DOMAIN + " TEXT,"
165 + Resolver.Result.HOSTNAME + " TEXT,"
166 + Resolver.Result.IP + " BLOB,"
167 + Resolver.Result.PRIORITY + " NUMBER,"
168 + Resolver.Result.DIRECT_TLS + " NUMBER,"
169 + Resolver.Result.AUTHENTICATED + " NUMBER,"
170 + Resolver.Result.PORT + " NUMBER,"
171 + "UNIQUE(" + Resolver.Result.DOMAIN + ") ON CONFLICT REPLACE"
172 + ");";
173
174 private static final String CREATE_MESSAGE_TIME_INDEX = "CREATE INDEX message_time_index ON " + Message.TABLENAME + "(" + Message.TIME_SENT + ")";
175 private static final String CREATE_MESSAGE_CONVERSATION_INDEX = "CREATE INDEX message_conversation_index ON " + Message.TABLENAME + "(" + Message.CONVERSATION + ")";
176 private static final String CREATE_MESSAGE_DELETED_INDEX = "CREATE INDEX message_deleted_index ON " + Message.TABLENAME + "(" + Message.DELETED + ")";
177 private static final String CREATE_MESSAGE_RELATIVE_FILE_PATH_INDEX = "CREATE INDEX message_file_path_index ON " + Message.TABLENAME + "(" + Message.RELATIVE_FILE_PATH + ")";
178 private static final String CREATE_MESSAGE_TYPE_INDEX = "CREATE INDEX message_type_index ON " + Message.TABLENAME + "(" + Message.TYPE + ")";
179
180 private static final String CREATE_MESSAGE_INDEX_TABLE = "CREATE VIRTUAL TABLE messages_index USING fts4 (uuid,body,notindexed=\"uuid\",content=\"" + Message.TABLENAME + "\",tokenize='unicode61')";
181 private static final String CREATE_MESSAGE_INSERT_TRIGGER = "CREATE TRIGGER after_message_insert AFTER INSERT ON " + Message.TABLENAME + " BEGIN INSERT INTO messages_index(rowid,uuid,body) VALUES(NEW.rowid,NEW.uuid,NEW.body); END;";
182 private static final String CREATE_MESSAGE_UPDATE_TRIGGER = "CREATE TRIGGER after_message_update UPDATE OF uuid,body ON " + Message.TABLENAME + " BEGIN UPDATE messages_index SET body=NEW.body,uuid=NEW.uuid WHERE rowid=OLD.rowid; END;";
183 private static final String CREATE_MESSAGE_DELETE_TRIGGER = "CREATE TRIGGER after_message_delete AFTER DELETE ON " + Message.TABLENAME + " BEGIN DELETE FROM messages_index WHERE rowid=OLD.rowid; END;";
184 private static final String COPY_PREEXISTING_ENTRIES = "INSERT INTO messages_index(messages_index) VALUES('rebuild');";
185
186 protected Context context;
187
188 private DatabaseBackend(Context context) {
189 super(context, DATABASE_NAME, null, DATABASE_VERSION);
190 this.context = context;
191 }
192
193 private static ContentValues createFingerprintStatusContentValues(FingerprintStatus.Trust trust, boolean active) {
194 ContentValues values = new ContentValues();
195 values.put(SQLiteAxolotlStore.TRUST, trust.toString());
196 values.put(SQLiteAxolotlStore.ACTIVE, active ? 1 : 0);
197 return values;
198 }
199
200 public static boolean requiresMessageIndexRebuild() {
201 return requiresMessageIndexRebuild;
202 }
203
204 public void rebuildMessagesIndex() {
205 final SQLiteDatabase db = getWritableDatabase();
206 final Stopwatch stopwatch = Stopwatch.createStarted();
207 db.execSQL(COPY_PREEXISTING_ENTRIES);
208 Log.d(Config.LOGTAG,"rebuilt message index in "+ stopwatch.stop().toString());
209 }
210
211 public static synchronized DatabaseBackend getInstance(Context context) {
212 if (instance == null) {
213 instance = new DatabaseBackend(context);
214 }
215 return instance;
216 }
217
218 protected void cheogramMigrate(SQLiteDatabase db) {
219 db.beginTransaction();
220
221 try {
222 Cursor cursor = db.rawQuery("PRAGMA cheogram.user_version", null);
223 cursor.moveToNext();
224 int cheogramVersion = cursor.getInt(0);
225 cursor.close();
226
227 if(cheogramVersion < 1) {
228 // No cross-DB foreign keys unfortunately
229 db.execSQL(
230 "CREATE TABLE cheogram." + Message.TABLENAME + "(" +
231 Message.UUID + " TEXT PRIMARY KEY, " +
232 "subject TEXT" +
233 ")"
234 );
235 db.execSQL("PRAGMA cheogram.user_version = 1");
236 }
237
238 if(cheogramVersion < 2) {
239 db.execSQL(
240 "ALTER TABLE cheogram." + Message.TABLENAME + " " +
241 "ADD COLUMN oobUri TEXT"
242 );
243 db.execSQL(
244 "ALTER TABLE cheogram." + Message.TABLENAME + " " +
245 "ADD COLUMN fileParams TEXT"
246 );
247 db.execSQL("PRAGMA cheogram.user_version = 2");
248 }
249
250 if(cheogramVersion < 3) {
251 db.execSQL(
252 "ALTER TABLE cheogram." + Message.TABLENAME + " " +
253 "ADD COLUMN payloads TEXT"
254 );
255 db.execSQL("PRAGMA cheogram.user_version = 3");
256 }
257
258 if(cheogramVersion < 4) {
259 db.execSQL(
260 "CREATE TABLE cheogram.cids (" +
261 "cid TEXT NOT NULL PRIMARY KEY," +
262 "path TEXT NOT NULL" +
263 ")"
264 );
265 db.execSQL("PRAGMA cheogram.user_version = 4");
266 }
267
268 if(cheogramVersion < 5) {
269 db.execSQL(
270 "ALTER TABLE cheogram." + Message.TABLENAME + " " +
271 "ADD COLUMN timeReceived NUMBER"
272 );
273 db.execSQL("CREATE INDEX cheogram.message_time_received_index ON " + Message.TABLENAME + " (timeReceived)");
274 db.execSQL("PRAGMA cheogram.user_version = 5");
275 }
276
277 db.setTransactionSuccessful();
278 } finally {
279 db.endTransaction();
280 }
281 }
282
283 @Override
284 public void onConfigure(SQLiteDatabase db) {
285 db.execSQL("PRAGMA foreign_keys=ON");
286 db.rawQuery("PRAGMA secure_delete=ON", null).close();
287 db.execSQL("ATTACH DATABASE ? AS cheogram", new Object[]{context.getDatabasePath("cheogram").getPath()});
288 cheogramMigrate(db);
289 }
290
291 @Override
292 public void onCreate(SQLiteDatabase db) {
293 db.execSQL("create table " + Account.TABLENAME + "(" + Account.UUID + " TEXT PRIMARY KEY,"
294 + Account.USERNAME + " TEXT,"
295 + Account.SERVER + " TEXT,"
296 + Account.PASSWORD + " TEXT,"
297 + Account.DISPLAY_NAME + " TEXT, "
298 + Account.STATUS + " TEXT,"
299 + Account.STATUS_MESSAGE + " TEXT,"
300 + Account.ROSTERVERSION + " TEXT,"
301 + Account.OPTIONS + " NUMBER, "
302 + Account.AVATAR + " TEXT, "
303 + Account.KEYS + " TEXT, "
304 + Account.HOSTNAME + " TEXT, "
305 + Account.RESOURCE + " TEXT,"
306 + Account.PINNED_MECHANISM + " TEXT,"
307 + Account.PINNED_CHANNEL_BINDING + " TEXT,"
308 + Account.FAST_MECHANISM + " TEXT,"
309 + Account.FAST_TOKEN + " TEXT,"
310 + Account.PORT + " NUMBER DEFAULT 5222)");
311 db.execSQL("create table " + Conversation.TABLENAME + " ("
312 + Conversation.UUID + " TEXT PRIMARY KEY, " + Conversation.NAME
313 + " TEXT, " + Conversation.CONTACT + " TEXT, "
314 + Conversation.ACCOUNT + " TEXT, " + Conversation.CONTACTJID
315 + " TEXT, " + Conversation.CREATED + " NUMBER, "
316 + Conversation.STATUS + " NUMBER, " + Conversation.MODE
317 + " NUMBER, " + Conversation.ATTRIBUTES + " TEXT, FOREIGN KEY("
318 + Conversation.ACCOUNT + ") REFERENCES " + Account.TABLENAME
319 + "(" + Account.UUID + ") ON DELETE CASCADE);");
320 db.execSQL("create table " + Message.TABLENAME + "( " + Message.UUID
321 + " TEXT PRIMARY KEY, " + Message.CONVERSATION + " TEXT, "
322 + Message.TIME_SENT + " NUMBER, " + Message.COUNTERPART
323 + " TEXT, " + Message.TRUE_COUNTERPART + " TEXT,"
324 + Message.BODY + " TEXT, " + Message.ENCRYPTION + " NUMBER, "
325 + Message.STATUS + " NUMBER," + Message.TYPE + " NUMBER, "
326 + Message.RELATIVE_FILE_PATH + " TEXT, "
327 + Message.SERVER_MSG_ID + " TEXT, "
328 + Message.FINGERPRINT + " TEXT, "
329 + Message.CARBON + " INTEGER, "
330 + Message.EDITED + " TEXT, "
331 + Message.READ + " NUMBER DEFAULT 1, "
332 + Message.OOB + " INTEGER, "
333 + Message.ERROR_MESSAGE + " TEXT,"
334 + Message.READ_BY_MARKERS + " TEXT,"
335 + Message.MARKABLE + " NUMBER DEFAULT 0,"
336 + Message.DELETED + " NUMBER DEFAULT 0,"
337 + Message.BODY_LANGUAGE + " TEXT,"
338 + Message.REMOTE_MSG_ID + " TEXT, FOREIGN KEY("
339 + Message.CONVERSATION + ") REFERENCES "
340 + Conversation.TABLENAME + "(" + Conversation.UUID
341 + ") ON DELETE CASCADE);");
342 db.execSQL(CREATE_MESSAGE_TIME_INDEX);
343 db.execSQL(CREATE_MESSAGE_CONVERSATION_INDEX);
344 db.execSQL(CREATE_MESSAGE_DELETED_INDEX);
345 db.execSQL(CREATE_MESSAGE_RELATIVE_FILE_PATH_INDEX);
346 db.execSQL(CREATE_MESSAGE_TYPE_INDEX);
347 db.execSQL(CREATE_CONTATCS_STATEMENT);
348 db.execSQL(CREATE_DISCOVERY_RESULTS_STATEMENT);
349 db.execSQL(CREATE_SESSIONS_STATEMENT);
350 db.execSQL(CREATE_PREKEYS_STATEMENT);
351 db.execSQL(CREATE_SIGNED_PREKEYS_STATEMENT);
352 db.execSQL(CREATE_IDENTITIES_STATEMENT);
353 db.execSQL(CREATE_PRESENCE_TEMPLATES_STATEMENT);
354 db.execSQL(CREATE_RESOLVER_RESULTS_TABLE);
355 db.execSQL(CREATE_MESSAGE_INDEX_TABLE);
356 db.execSQL(CREATE_MESSAGE_INSERT_TRIGGER);
357 db.execSQL(CREATE_MESSAGE_UPDATE_TRIGGER);
358 db.execSQL(CREATE_MESSAGE_DELETE_TRIGGER);
359 }
360
361 @Override
362 public void onUpgrade(SQLiteDatabase db, int oldVersion, int newVersion) {
363 if (oldVersion < 2 && newVersion >= 2) {
364 db.execSQL("update " + Account.TABLENAME + " set "
365 + Account.OPTIONS + " = " + Account.OPTIONS + " | 8");
366 }
367 if (oldVersion < 3 && newVersion >= 3) {
368 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
369 + Message.TYPE + " NUMBER");
370 }
371 if (oldVersion < 5 && newVersion >= 5) {
372 db.execSQL("DROP TABLE " + Contact.TABLENAME);
373 db.execSQL(CREATE_CONTATCS_STATEMENT);
374 db.execSQL("UPDATE " + Account.TABLENAME + " SET "
375 + Account.ROSTERVERSION + " = NULL");
376 }
377 if (oldVersion < 6 && newVersion >= 6) {
378 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
379 + Message.TRUE_COUNTERPART + " TEXT");
380 }
381 if (oldVersion < 7 && newVersion >= 7) {
382 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
383 + Message.REMOTE_MSG_ID + " TEXT");
384 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN "
385 + Contact.AVATAR + " TEXT");
386 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN "
387 + Account.AVATAR + " TEXT");
388 }
389 if (oldVersion < 8 && newVersion >= 8) {
390 db.execSQL("ALTER TABLE " + Conversation.TABLENAME + " ADD COLUMN "
391 + Conversation.ATTRIBUTES + " TEXT");
392 }
393 if (oldVersion < 9 && newVersion >= 9) {
394 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN "
395 + Contact.LAST_TIME + " NUMBER");
396 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN "
397 + Contact.LAST_PRESENCE + " TEXT");
398 }
399 if (oldVersion < 10 && newVersion >= 10) {
400 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
401 + Message.RELATIVE_FILE_PATH + " TEXT");
402 }
403 if (oldVersion < 11 && newVersion >= 11) {
404 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN "
405 + Contact.GROUPS + " TEXT");
406 db.execSQL("delete from " + Contact.TABLENAME);
407 db.execSQL("update " + Account.TABLENAME + " set " + Account.ROSTERVERSION + " = NULL");
408 }
409 if (oldVersion < 12 && newVersion >= 12) {
410 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
411 + Message.SERVER_MSG_ID + " TEXT");
412 }
413 if (oldVersion < 13 && newVersion >= 13) {
414 db.execSQL("delete from " + Contact.TABLENAME);
415 db.execSQL("update " + Account.TABLENAME + " set " + Account.ROSTERVERSION + " = NULL");
416 }
417 if (oldVersion < 14 && newVersion >= 14) {
418 canonicalizeJids(db);
419 }
420 if (oldVersion < 15 && newVersion >= 15) {
421 recreateAxolotlDb(db);
422 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
423 + Message.FINGERPRINT + " TEXT");
424 }
425 if (oldVersion < 16 && newVersion >= 16) {
426 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN "
427 + Message.CARBON + " INTEGER");
428 }
429 if (oldVersion < 19 && newVersion >= 19) {
430 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.DISPLAY_NAME + " TEXT");
431 }
432 if (oldVersion < 20 && newVersion >= 20) {
433 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.HOSTNAME + " TEXT");
434 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.PORT + " NUMBER DEFAULT 5222");
435 }
436 if (oldVersion < 26 && newVersion >= 26) {
437 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.STATUS + " TEXT");
438 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.STATUS_MESSAGE + " TEXT");
439 }
440 if (oldVersion < 40 && newVersion >= 40) {
441 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.RESOURCE + " TEXT");
442 }
443 /* Any migrations that alter the Account table need to happen BEFORE this migration, as it
444 * depends on account de-serialization.
445 */
446 if (oldVersion < 17 && newVersion >= 17 && newVersion < 31) {
447 List<Account> accounts = getAccounts(db);
448 for (Account account : accounts) {
449 String ownDeviceIdString = account.getKey(SQLiteAxolotlStore.JSONKEY_REGISTRATION_ID);
450 if (ownDeviceIdString == null) {
451 continue;
452 }
453 int ownDeviceId = Integer.valueOf(ownDeviceIdString);
454 SignalProtocolAddress ownAddress = new SignalProtocolAddress(account.getJid().asBareJid().toString(), ownDeviceId);
455 deleteSession(db, account, ownAddress);
456 IdentityKeyPair identityKeyPair = loadOwnIdentityKeyPair(db, account);
457 if (identityKeyPair != null) {
458 String[] selectionArgs = {
459 account.getUuid(),
460 CryptoHelper.bytesToHex(identityKeyPair.getPublicKey().serialize())
461 };
462 ContentValues values = new ContentValues();
463 values.put(SQLiteAxolotlStore.TRUSTED, 2);
464 db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, values,
465 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
466 + SQLiteAxolotlStore.FINGERPRINT + " = ? ",
467 selectionArgs);
468 } else {
469 Log.d(Config.LOGTAG, account.getJid().asBareJid() + ": could not load own identity key pair");
470 }
471 }
472 }
473 if (oldVersion < 18 && newVersion >= 18) {
474 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.READ + " NUMBER DEFAULT 1");
475 }
476
477 if (oldVersion < 21 && newVersion >= 21) {
478 List<Account> accounts = getAccounts(db);
479 for (Account account : accounts) {
480 account.unsetPgpSignature();
481 db.update(Account.TABLENAME, account.getContentValues(), Account.UUID
482 + "=?", new String[]{account.getUuid()});
483 }
484 }
485
486 if (oldVersion >= 15 && oldVersion < 22 && newVersion >= 22) {
487 db.execSQL("ALTER TABLE " + SQLiteAxolotlStore.IDENTITIES_TABLENAME + " ADD COLUMN " + SQLiteAxolotlStore.CERTIFICATE);
488 }
489
490 if (oldVersion < 23 && newVersion >= 23) {
491 db.execSQL(CREATE_DISCOVERY_RESULTS_STATEMENT);
492 }
493
494 if (oldVersion < 24 && newVersion >= 24) {
495 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.EDITED + " TEXT");
496 }
497
498 if (oldVersion < 25 && newVersion >= 25) {
499 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.OOB + " INTEGER");
500 }
501
502 if (oldVersion < 26 && newVersion >= 26) {
503 db.execSQL(CREATE_PRESENCE_TEMPLATES_STATEMENT);
504 }
505
506 if (oldVersion < 27 && newVersion >= 27) {
507 db.execSQL("DELETE FROM " + ServiceDiscoveryResult.TABLENAME);
508 }
509
510 if (oldVersion < 28 && newVersion >= 28) {
511 canonicalizeJids(db);
512 }
513
514 if (oldVersion < 29 && newVersion >= 29) {
515 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.ERROR_MESSAGE + " TEXT");
516 }
517 if (oldVersion >= 15 && oldVersion < 31 && newVersion >= 31) {
518 db.execSQL("ALTER TABLE " + SQLiteAxolotlStore.IDENTITIES_TABLENAME + " ADD COLUMN " + SQLiteAxolotlStore.TRUST + " TEXT");
519 db.execSQL("ALTER TABLE " + SQLiteAxolotlStore.IDENTITIES_TABLENAME + " ADD COLUMN " + SQLiteAxolotlStore.ACTIVE + " NUMBER");
520 HashMap<Integer, ContentValues> migration = new HashMap<>();
521 migration.put(0, createFingerprintStatusContentValues(FingerprintStatus.Trust.TRUSTED, true));
522 migration.put(1, createFingerprintStatusContentValues(FingerprintStatus.Trust.TRUSTED, true));
523 migration.put(2, createFingerprintStatusContentValues(FingerprintStatus.Trust.UNTRUSTED, true));
524 migration.put(3, createFingerprintStatusContentValues(FingerprintStatus.Trust.COMPROMISED, false));
525 migration.put(4, createFingerprintStatusContentValues(FingerprintStatus.Trust.TRUSTED, false));
526 migration.put(5, createFingerprintStatusContentValues(FingerprintStatus.Trust.TRUSTED, false));
527 migration.put(6, createFingerprintStatusContentValues(FingerprintStatus.Trust.UNTRUSTED, false));
528 migration.put(7, createFingerprintStatusContentValues(FingerprintStatus.Trust.VERIFIED_X509, true));
529 migration.put(8, createFingerprintStatusContentValues(FingerprintStatus.Trust.VERIFIED_X509, false));
530 for (Map.Entry<Integer, ContentValues> entry : migration.entrySet()) {
531 String whereClause = SQLiteAxolotlStore.TRUSTED + "=?";
532 String[] where = {String.valueOf(entry.getKey())};
533 db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, entry.getValue(), whereClause, where);
534 }
535
536 }
537 if (oldVersion >= 15 && oldVersion < 32 && newVersion >= 32) {
538 db.execSQL("ALTER TABLE " + SQLiteAxolotlStore.IDENTITIES_TABLENAME + " ADD COLUMN " + SQLiteAxolotlStore.LAST_ACTIVATION + " NUMBER");
539 ContentValues defaults = new ContentValues();
540 defaults.put(SQLiteAxolotlStore.LAST_ACTIVATION, System.currentTimeMillis());
541 db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, defaults, null, null);
542 }
543 if (oldVersion >= 15 && oldVersion < 33 && newVersion >= 33) {
544 String whereClause = SQLiteAxolotlStore.OWN + "=1";
545 db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, createFingerprintStatusContentValues(FingerprintStatus.Trust.VERIFIED, true), whereClause, null);
546 }
547
548 if (oldVersion < 34 && newVersion >= 34) {
549 db.execSQL(CREATE_MESSAGE_TIME_INDEX);
550
551 final File oldPicturesDirectory = new File(Environment.getExternalStoragePublicDirectory(Environment.DIRECTORY_PICTURES) + "/Conversations/");
552 final File oldFilesDirectory = new File(Environment.getExternalStorageDirectory() + "/Conversations/");
553 final File newFilesDirectory = new File(Environment.getExternalStorageDirectory() + "/Conversations/Media/Conversations Files/");
554 final File newVideosDirectory = new File(Environment.getExternalStorageDirectory() + "/Conversations/Media/Conversations Videos/");
555 if (oldPicturesDirectory.exists() && oldPicturesDirectory.isDirectory()) {
556 final File newPicturesDirectory = new File(Environment.getExternalStorageDirectory() + "/Conversations/Media/Conversations Images/");
557 newPicturesDirectory.getParentFile().mkdirs();
558 if (oldPicturesDirectory.renameTo(newPicturesDirectory)) {
559 Log.d(Config.LOGTAG, "moved " + oldPicturesDirectory.getAbsolutePath() + " to " + newPicturesDirectory.getAbsolutePath());
560 }
561 }
562 if (oldFilesDirectory.exists() && oldFilesDirectory.isDirectory()) {
563 newFilesDirectory.mkdirs();
564 newVideosDirectory.mkdirs();
565 final File[] files = oldFilesDirectory.listFiles();
566 if (files == null) {
567 return;
568 }
569 for (File file : files) {
570 if (file.getName().equals(".nomedia")) {
571 if (file.delete()) {
572 Log.d(Config.LOGTAG, "deleted nomedia file in " + oldFilesDirectory.getAbsolutePath());
573 }
574 } else if (file.isFile()) {
575 final String name = file.getName();
576 boolean isVideo = false;
577 int start = name.lastIndexOf('.') + 1;
578 if (start < name.length()) {
579 String mime = MimeUtils.guessMimeTypeFromExtension(name.substring(start));
580 isVideo = mime != null && mime.startsWith("video/");
581 }
582 File dst = new File((isVideo ? newVideosDirectory : newFilesDirectory).getAbsolutePath() + "/" + file.getName());
583 if (file.renameTo(dst)) {
584 Log.d(Config.LOGTAG, "moved " + file + " to " + dst);
585 }
586 }
587 }
588 }
589 }
590 if (oldVersion < 35 && newVersion >= 35) {
591 db.execSQL(CREATE_MESSAGE_CONVERSATION_INDEX);
592 }
593 if (oldVersion < 36 && newVersion >= 36) {
594 List<Account> accounts = getAccounts(db);
595 for (Account account : accounts) {
596 account.setOption(Account.OPTION_REQUIRES_ACCESS_MODE_CHANGE, true);
597 account.setOption(Account.OPTION_LOGGED_IN_SUCCESSFULLY, false);
598 db.update(Account.TABLENAME, account.getContentValues(), Account.UUID
599 + "=?", new String[]{account.getUuid()});
600 }
601 }
602
603 if (oldVersion < 37 && newVersion >= 37) {
604 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.READ_BY_MARKERS + " TEXT");
605 }
606
607 if (oldVersion < 38 && newVersion >= 38) {
608 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.MARKABLE + " NUMBER DEFAULT 0");
609 }
610
611 if (oldVersion < 39 && newVersion >= 39) {
612 db.execSQL(CREATE_RESOLVER_RESULTS_TABLE);
613 }
614
615 if (QuickConversationsService.isQuicksy() && oldVersion < 43 && newVersion >= 43) {
616 List<Account> accounts = getAccounts(db);
617 for (Account account : accounts) {
618 account.setOption(Account.OPTION_MAGIC_CREATE, true);
619 db.update(Account.TABLENAME, account.getContentValues(), Account.UUID
620 + "=?", new String[]{account.getUuid()});
621 }
622 }
623
624 if (oldVersion < 44 && newVersion >= 44) {
625 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.DELETED + " NUMBER DEFAULT 0");
626 db.execSQL(CREATE_MESSAGE_DELETED_INDEX);
627 db.execSQL(CREATE_MESSAGE_RELATIVE_FILE_PATH_INDEX);
628 db.execSQL(CREATE_MESSAGE_TYPE_INDEX);
629 }
630
631 if (oldVersion < 45 && newVersion >= 45) {
632 db.execSQL("ALTER TABLE " + Message.TABLENAME + " ADD COLUMN " + Message.BODY_LANGUAGE);
633 }
634
635 if (oldVersion < 46 && newVersion >= 46) {
636 final long start = SystemClock.elapsedRealtime();
637 db.rawQuery("PRAGMA secure_delete = FALSE", null).close();
638 db.execSQL("update " + Message.TABLENAME + " set " + Message.EDITED + "=NULL");
639 db.rawQuery("PRAGMA secure_delete=ON", null).close();
640 final long diff = SystemClock.elapsedRealtime() - start;
641 Log.d(Config.LOGTAG, "deleted old edit information in " + diff + "ms");
642 }
643 if (oldVersion < 47 && newVersion >= 47) {
644 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN " + Contact.PRESENCE_NAME + " TEXT");
645 }
646 if (oldVersion < 48 && newVersion >= 48) {
647 db.execSQL("ALTER TABLE " + Contact.TABLENAME + " ADD COLUMN " + Contact.RTP_CAPABILITY + " TEXT");
648 }
649 if (oldVersion < 49 && newVersion >= 49) {
650 db.beginTransaction();
651 db.execSQL("DROP TRIGGER IF EXISTS after_message_insert;");
652 db.execSQL("DROP TRIGGER IF EXISTS after_message_update;");
653 db.execSQL("DROP TRIGGER IF EXISTS after_message_delete;");
654 db.execSQL("DROP TABLE IF EXISTS messages_index;");
655 // a hack that should not be necessary, but
656 // there was at least one occurence when SQLite failed at this
657 db.execSQL("DROP TABLE IF EXISTS messages_index_docsize;");
658 db.execSQL("DROP TABLE IF EXISTS messages_index_segdir;");
659 db.execSQL("DROP TABLE IF EXISTS messages_index_segments;");
660 db.execSQL("DROP TABLE IF EXISTS messages_index_stat;");
661 db.execSQL(CREATE_MESSAGE_INDEX_TABLE);
662 db.execSQL(CREATE_MESSAGE_INSERT_TRIGGER);
663 db.execSQL(CREATE_MESSAGE_UPDATE_TRIGGER);
664 db.execSQL(CREATE_MESSAGE_DELETE_TRIGGER);
665 db.setTransactionSuccessful();
666 db.endTransaction();
667 requiresMessageIndexRebuild = true;
668 }
669 if (oldVersion < 50 && newVersion >= 50) {
670 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.PINNED_MECHANISM + " TEXT");
671 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.PINNED_CHANNEL_BINDING + " TEXT");
672 }
673 if (oldVersion < 51 && newVersion >= 51) {
674 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.FAST_MECHANISM + " TEXT");
675 db.execSQL("ALTER TABLE " + Account.TABLENAME + " ADD COLUMN " + Account.FAST_TOKEN + " TEXT");
676 }
677 }
678
679 private void canonicalizeJids(SQLiteDatabase db) {
680 // migrate db to new, canonicalized JID domainpart representation
681
682 // Conversation table
683 Cursor cursor = db.rawQuery("select * from " + Conversation.TABLENAME, new String[0]);
684 while (cursor.moveToNext()) {
685 String newJid;
686 try {
687 newJid = Jid.of(cursor.getString(cursor.getColumnIndex(Conversation.CONTACTJID))).toString();
688 } catch (IllegalArgumentException ignored) {
689 Log.e(Config.LOGTAG, "Failed to migrate Conversation CONTACTJID "
690 + cursor.getString(cursor.getColumnIndex(Conversation.CONTACTJID))
691 + ": " + ignored + ". Skipping...");
692 continue;
693 }
694
695 final String[] updateArgs = {
696 newJid,
697 cursor.getString(cursor.getColumnIndex(Conversation.UUID)),
698 };
699 db.execSQL("update " + Conversation.TABLENAME
700 + " set " + Conversation.CONTACTJID + " = ? "
701 + " where " + Conversation.UUID + " = ?", updateArgs);
702 }
703 cursor.close();
704
705 // Contact table
706 cursor = db.rawQuery("select * from " + Contact.TABLENAME, new String[0]);
707 while (cursor.moveToNext()) {
708 String newJid;
709 try {
710 newJid = Jid.of(cursor.getString(cursor.getColumnIndex(Contact.JID))).toString();
711 } catch (final IllegalArgumentException e) {
712 Log.e(Config.LOGTAG, "Failed to migrate Contact JID "
713 + cursor.getString(cursor.getColumnIndex(Contact.JID))
714 + ": Skipping...", e);
715 continue;
716 }
717
718 final String[] updateArgs = {
719 newJid,
720 cursor.getString(cursor.getColumnIndex(Contact.ACCOUNT)),
721 cursor.getString(cursor.getColumnIndex(Contact.JID)),
722 };
723 db.execSQL("update " + Contact.TABLENAME
724 + " set " + Contact.JID + " = ? "
725 + " where " + Contact.ACCOUNT + " = ? "
726 + " AND " + Contact.JID + " = ?", updateArgs);
727 }
728 cursor.close();
729
730 // Account table
731 cursor = db.rawQuery("select * from " + Account.TABLENAME, new String[0]);
732 while (cursor.moveToNext()) {
733 String newServer;
734 try {
735 newServer = Jid.of(
736 cursor.getString(cursor.getColumnIndex(Account.USERNAME)),
737 cursor.getString(cursor.getColumnIndex(Account.SERVER)),
738 null
739 ).getDomain().toEscapedString();
740 } catch (IllegalArgumentException ignored) {
741 Log.e(Config.LOGTAG, "Failed to migrate Account SERVER "
742 + cursor.getString(cursor.getColumnIndex(Account.SERVER))
743 + ": " + ignored + ". Skipping...");
744 continue;
745 }
746
747 String[] updateArgs = {
748 newServer,
749 cursor.getString(cursor.getColumnIndex(Account.UUID)),
750 };
751 db.execSQL("update " + Account.TABLENAME
752 + " set " + Account.SERVER + " = ? "
753 + " where " + Account.UUID + " = ?", updateArgs);
754 }
755 cursor.close();
756 }
757
758 public DownloadableFile getFileForCid(Cid cid) {
759 SQLiteDatabase db = this.getReadableDatabase();
760 Cursor cursor = db.query("cheogram.cids", new String[]{"path"}, "cid=?", new String[]{cid.toString()}, null, null, null);
761 DownloadableFile f = null;
762 if (cursor.moveToNext()) {
763 f = new DownloadableFile(cursor.getString(0));
764 }
765 cursor.close();
766 return f;
767 }
768
769 public void saveCid(Cid cid, File file) {
770 SQLiteDatabase db = this.getWritableDatabase();
771 ContentValues cv = new ContentValues();
772 cv.put("cid", cid.toString());
773 cv.put("path", file.getAbsolutePath());
774 db.insertWithOnConflict("cheogram.cids", null, cv, SQLiteDatabase.CONFLICT_REPLACE);
775 }
776
777 public void createConversation(Conversation conversation) {
778 SQLiteDatabase db = this.getWritableDatabase();
779 db.insert(Conversation.TABLENAME, null, conversation.getContentValues());
780 }
781
782 public void createMessage(Message message) {
783 SQLiteDatabase db = this.getWritableDatabase();
784 db.insert(Message.TABLENAME, null, message.getContentValues());
785 db.insert("cheogram." + Message.TABLENAME, null, message.getCheogramContentValues());
786 }
787
788 public void createAccount(Account account) {
789 SQLiteDatabase db = this.getWritableDatabase();
790 db.insert(Account.TABLENAME, null, account.getContentValues());
791 }
792
793 public void insertDiscoveryResult(ServiceDiscoveryResult result) {
794 SQLiteDatabase db = this.getWritableDatabase();
795 db.insert(ServiceDiscoveryResult.TABLENAME, null, result.getContentValues());
796 }
797
798 public ServiceDiscoveryResult findDiscoveryResult(final String hash, final String ver) {
799 SQLiteDatabase db = this.getReadableDatabase();
800 String[] selectionArgs = {hash, ver};
801 Cursor cursor = db.query(ServiceDiscoveryResult.TABLENAME, null,
802 ServiceDiscoveryResult.HASH + "=? AND " + ServiceDiscoveryResult.VER + "=?",
803 selectionArgs, null, null, null);
804 if (cursor.getCount() == 0) {
805 cursor.close();
806 return null;
807 }
808 cursor.moveToFirst();
809
810 ServiceDiscoveryResult result = null;
811 try {
812 result = new ServiceDiscoveryResult(cursor);
813 } catch (JSONException e) { /* result is still null */ }
814
815 cursor.close();
816 return result;
817 }
818
819 public void saveResolverResult(String domain, Resolver.Result result) {
820 SQLiteDatabase db = this.getWritableDatabase();
821 ContentValues contentValues = result.toContentValues();
822 contentValues.put(Resolver.Result.DOMAIN, domain);
823 db.insert(RESOLVER_RESULTS_TABLENAME, null, contentValues);
824 }
825
826 public synchronized Resolver.Result findResolverResult(String domain) {
827 SQLiteDatabase db = this.getReadableDatabase();
828 String where = Resolver.Result.DOMAIN + "=?";
829 String[] whereArgs = {domain};
830 final Cursor cursor = db.query(RESOLVER_RESULTS_TABLENAME, null, where, whereArgs, null, null, null);
831 Resolver.Result result = null;
832 if (cursor != null) {
833 try {
834 if (cursor.moveToFirst()) {
835 result = Resolver.Result.fromCursor(cursor);
836 }
837 } catch (Exception e) {
838 Log.d(Config.LOGTAG, "unable to find cached resolver result in database " + e.getMessage());
839 return null;
840 } finally {
841 cursor.close();
842 }
843 }
844 return result;
845 }
846
847 public void insertPresenceTemplate(PresenceTemplate template) {
848 SQLiteDatabase db = this.getWritableDatabase();
849 String whereToDelete = PresenceTemplate.MESSAGE + "=?";
850 String[] whereToDeleteArgs = {template.getStatusMessage()};
851 db.delete(PresenceTemplate.TABELNAME, whereToDelete, whereToDeleteArgs);
852 db.delete(PresenceTemplate.TABELNAME, PresenceTemplate.UUID + " not in (select " + PresenceTemplate.UUID + " from " + PresenceTemplate.TABELNAME + " order by " + PresenceTemplate.LAST_USED + " desc limit 9)", null);
853 db.insert(PresenceTemplate.TABELNAME, null, template.getContentValues());
854 }
855
856 public List<PresenceTemplate> getPresenceTemplates() {
857 ArrayList<PresenceTemplate> templates = new ArrayList<>();
858 SQLiteDatabase db = this.getReadableDatabase();
859 Cursor cursor = db.query(PresenceTemplate.TABELNAME, null, null, null, null, null, PresenceTemplate.LAST_USED + " desc");
860 while (cursor.moveToNext()) {
861 templates.add(PresenceTemplate.fromCursor(cursor));
862 }
863 cursor.close();
864 return templates;
865 }
866
867 public CopyOnWriteArrayList<Conversation> getConversations(int status) {
868 CopyOnWriteArrayList<Conversation> list = new CopyOnWriteArrayList<>();
869 SQLiteDatabase db = this.getReadableDatabase();
870 String[] selectionArgs = {Integer.toString(status)};
871 Cursor cursor = db.rawQuery("select * from " + Conversation.TABLENAME
872 + " where " + Conversation.STATUS + " = ? and " + Conversation.CONTACTJID + " is not null order by "
873 + Conversation.CREATED + " desc", selectionArgs);
874 while (cursor.moveToNext()) {
875 final Conversation conversation = Conversation.fromCursor(cursor);
876 if (conversation.getJid() instanceof InvalidJid) {
877 continue;
878 }
879 list.add(conversation);
880 }
881 cursor.close();
882 return list;
883 }
884
885 public ArrayList<Message> getMessages(Conversation conversations, int limit) {
886 return getMessages(conversations, limit, -1);
887 }
888
889 public ArrayList<Message> getMessages(Conversation conversation, int limit, long timestamp) {
890 ArrayList<Message> list = new ArrayList<>();
891 SQLiteDatabase db = this.getReadableDatabase();
892 Cursor cursor;
893 if (timestamp == -1) {
894 String[] selectionArgs = {conversation.getUuid()};
895 cursor = db.rawQuery(
896 "SELECT * FROM " + Message.TABLENAME + " " +
897 "LEFT JOIN cheogram." + Message.TABLENAME +
898 " USING (" + Message.UUID + ")" +
899 "WHERE " + Message.CONVERSATION + "=? " +
900 "ORDER BY " + Message.TIME_SENT + " DESC " +
901 "LIMIT " + String.valueOf(limit),
902 selectionArgs
903 );
904 } else {
905 String[] selectionArgs = {conversation.getUuid(),
906 Long.toString(timestamp)};
907 cursor = db.rawQuery(
908 "SELECT * FROM " + Message.TABLENAME + " " +
909 "LEFT JOIN cheogram." + Message.TABLENAME +
910 " USING (" + Message.UUID + ")" +
911 "WHERE " + Message.CONVERSATION + "=? AND " +
912 Message.TIME_SENT + "<? " +
913 "ORDER BY " + Message.TIME_SENT + " DESC " +
914 "LIMIT " + String.valueOf(limit),
915 selectionArgs
916 );
917 }
918 CursorUtils.upgradeCursorWindowSize(cursor);
919 while (cursor.moveToNext()) {
920 try {
921 list.add(0, Message.fromCursor(cursor, conversation));
922 } catch (Exception e) {
923 Log.e(Config.LOGTAG, "unable to restore message");
924 }
925 }
926 cursor.close();
927 return list;
928 }
929
930 public Cursor getMessageSearchCursor(final List<String> term, final String uuid) {
931 final SQLiteDatabase db = this.getReadableDatabase();
932 final StringBuilder SQL = new StringBuilder();
933 final String[] selectionArgs;
934 SQL.append("SELECT " + Message.TABLENAME + ".*," + Conversation.TABLENAME + "." + Conversation.CONTACTJID + "," + Conversation.TABLENAME + "." + Conversation.ACCOUNT + "," + Conversation.TABLENAME + "." + Conversation.MODE + " FROM " + Message.TABLENAME + " JOIN " + Conversation.TABLENAME + " ON " + Message.TABLENAME + "." + Message.CONVERSATION + "=" + Conversation.TABLENAME + "." + Conversation.UUID + " JOIN messages_index ON messages_index.rowid=messages.rowid WHERE " + Message.ENCRYPTION + " NOT IN(" + Message.ENCRYPTION_AXOLOTL_NOT_FOR_THIS_DEVICE + "," + Message.ENCRYPTION_PGP + "," + Message.ENCRYPTION_DECRYPTION_FAILED + "," + Message.ENCRYPTION_AXOLOTL_FAILED + ") AND " + Message.TYPE + " IN(" + Message.TYPE_TEXT + "," + Message.TYPE_PRIVATE + ") AND messages_index.body MATCH ?");
935 if (uuid == null) {
936 selectionArgs = new String[]{FtsUtils.toMatchString(term)};
937 } else {
938 selectionArgs = new String[]{FtsUtils.toMatchString(term), uuid};
939 SQL.append(" AND " + Conversation.TABLENAME + '.' + Conversation.UUID + "=?");
940 }
941 SQL.append(" ORDER BY " + Message.TIME_SENT + " DESC limit " + Config.MAX_SEARCH_RESULTS);
942 Log.d(Config.LOGTAG, "search term: " + FtsUtils.toMatchString(term));
943 return db.rawQuery(SQL.toString(), selectionArgs);
944 }
945
946 public List<String> markFileAsDeleted(final File file, final boolean internal) {
947 SQLiteDatabase db = this.getReadableDatabase();
948 String selection;
949 String[] selectionArgs;
950 if (internal) {
951 final String name = file.getName();
952 if (name.endsWith(".pgp")) {
953 selection = "(" + Message.RELATIVE_FILE_PATH + " IN(?,?) OR (" + Message.RELATIVE_FILE_PATH + "=? and encryption in(1,4))) and type in (1,2,5)";
954 selectionArgs = new String[]{file.getAbsolutePath(), name, name.substring(0, name.length() - 4)};
955 } else {
956 selection = Message.RELATIVE_FILE_PATH + " IN(?,?) and type in (1,2,5)";
957 selectionArgs = new String[]{file.getAbsolutePath(), name};
958 }
959 } else {
960 selection = Message.RELATIVE_FILE_PATH + "=? and type in (1,2,5)";
961 selectionArgs = new String[]{file.getAbsolutePath()};
962 }
963 final List<String> uuids = new ArrayList<>();
964 Cursor cursor = db.query(Message.TABLENAME, new String[]{Message.UUID}, selection, selectionArgs, null, null, null);
965 while (cursor != null && cursor.moveToNext()) {
966 uuids.add(cursor.getString(0));
967 }
968 if (cursor != null) {
969 cursor.close();
970 }
971 markFileAsDeleted(uuids);
972 return uuids;
973 }
974
975 public void markFileAsDeleted(List<String> uuids) {
976 SQLiteDatabase db = this.getReadableDatabase();
977 final ContentValues contentValues = new ContentValues();
978 final String where = Message.UUID + "=?";
979 contentValues.put(Message.DELETED, 1);
980 db.beginTransaction();
981 for (String uuid : uuids) {
982 db.update(Message.TABLENAME, contentValues, where, new String[]{uuid});
983 }
984 db.setTransactionSuccessful();
985 db.endTransaction();
986 }
987
988 public void markFilesAsChanged(List<FilePathInfo> files) {
989 SQLiteDatabase db = this.getReadableDatabase();
990 final String where = Message.UUID + "=?";
991 db.beginTransaction();
992 for (FilePathInfo info : files) {
993 final ContentValues contentValues = new ContentValues();
994 contentValues.put(Message.DELETED, info.deleted ? 1 : 0);
995 db.update(Message.TABLENAME, contentValues, where, new String[]{info.uuid.toString()});
996 }
997 db.setTransactionSuccessful();
998 db.endTransaction();
999 }
1000
1001 public List<FilePathInfo> getFilePathInfo() {
1002 final SQLiteDatabase db = this.getReadableDatabase();
1003 final Cursor cursor = db.query(Message.TABLENAME, new String[]{Message.UUID, Message.RELATIVE_FILE_PATH, Message.DELETED}, "type in (1,2,5) and " + Message.RELATIVE_FILE_PATH + " is not null", null, null, null, null);
1004 final List<FilePathInfo> list = new ArrayList<>();
1005 while (cursor != null && cursor.moveToNext()) {
1006 list.add(new FilePathInfo(cursor.getString(0), cursor.getString(1), cursor.getInt(2) > 0));
1007 }
1008 if (cursor != null) {
1009 cursor.close();
1010 }
1011 return list;
1012 }
1013
1014 public List<FilePath> getRelativeFilePaths(String account, Jid jid, int limit) {
1015 SQLiteDatabase db = this.getReadableDatabase();
1016 final String SQL = "select uuid,relativeFilePath from messages where type in (1,2,5) and deleted=0 and " + Message.RELATIVE_FILE_PATH + " is not null and conversationUuid=(select uuid from conversations where accountUuid=? and (contactJid=? or contactJid like ?)) order by timeSent desc";
1017 final String[] args = {account, jid.toString(), jid.toString() + "/%"};
1018 Cursor cursor = db.rawQuery(SQL + (limit > 0 ? " limit " + limit : ""), args);
1019 List<FilePath> filesPaths = new ArrayList<>();
1020 while (cursor.moveToNext()) {
1021 filesPaths.add(new FilePath(cursor.getString(0), cursor.getString(1)));
1022 }
1023 cursor.close();
1024 return filesPaths;
1025 }
1026
1027 public static class FilePath {
1028 public final UUID uuid;
1029 public final String path;
1030
1031 private FilePath(String uuid, String path) {
1032 this.uuid = UUID.fromString(uuid);
1033 this.path = path;
1034 }
1035 }
1036
1037 public static class FilePathInfo extends FilePath {
1038 public boolean deleted;
1039
1040 private FilePathInfo(String uuid, String path, boolean deleted) {
1041 super(uuid, path);
1042 this.deleted = deleted;
1043 }
1044
1045 public boolean setDeleted(boolean deleted) {
1046 final boolean changed = deleted != this.deleted;
1047 this.deleted = deleted;
1048 return changed;
1049 }
1050 }
1051
1052 public Conversation findConversation(final Account account, final Jid contactJid) {
1053 SQLiteDatabase db = this.getReadableDatabase();
1054 String[] selectionArgs = {account.getUuid(),
1055 contactJid.asBareJid().toString() + "/%",
1056 contactJid.asBareJid().toString()
1057 };
1058 try(final Cursor cursor = db.query(Conversation.TABLENAME, null,
1059 Conversation.ACCOUNT + "=? AND (" + Conversation.CONTACTJID
1060 + " like ? OR " + Conversation.CONTACTJID + "=?)", selectionArgs, null, null, null)) {
1061 if (cursor.getCount() == 0) {
1062 return null;
1063 }
1064 cursor.moveToFirst();
1065 final Conversation conversation = Conversation.fromCursor(cursor);
1066 if (conversation.getJid() instanceof InvalidJid) {
1067 return null;
1068 }
1069 return conversation;
1070 }
1071 }
1072
1073 public void updateConversation(final Conversation conversation) {
1074 final SQLiteDatabase db = this.getWritableDatabase();
1075 final String[] args = {conversation.getUuid()};
1076 db.update(Conversation.TABLENAME, conversation.getContentValues(),
1077 Conversation.UUID + "=?", args);
1078 }
1079
1080 public List<Account> getAccounts() {
1081 SQLiteDatabase db = this.getReadableDatabase();
1082 return getAccounts(db);
1083 }
1084
1085 public List<Jid> getAccountJids(final boolean enabledOnly) {
1086 final SQLiteDatabase db = this.getReadableDatabase();
1087 final List<Jid> jids = new ArrayList<>();
1088 final String[] columns = new String[]{Account.USERNAME, Account.SERVER};
1089 final String where = enabledOnly ? "not options & (1 <<1)" : null;
1090 try (final Cursor cursor = db.query(Account.TABLENAME, columns, where, null, null, null, null)) {
1091 while (cursor != null && cursor.moveToNext()) {
1092 jids.add(Jid.of(cursor.getString(0), cursor.getString(1), null));
1093 }
1094 } catch (final Exception e) {
1095 return jids;
1096 }
1097 return jids;
1098 }
1099
1100 private List<Account> getAccounts(SQLiteDatabase db) {
1101 final List<Account> list = new ArrayList<>();
1102 try (final Cursor cursor =
1103 db.query(Account.TABLENAME, null, null, null, null, null, null)) {
1104 while (cursor != null && cursor.moveToNext()) {
1105 list.add(Account.fromCursor(cursor));
1106 }
1107 }
1108 return list;
1109 }
1110
1111 public boolean updateAccount(Account account) {
1112 SQLiteDatabase db = this.getWritableDatabase();
1113 String[] args = {account.getUuid()};
1114 final int rows = db.update(Account.TABLENAME, account.getContentValues(), Account.UUID + "=?", args);
1115 return rows == 1;
1116 }
1117
1118 public boolean deleteAccount(Account account) {
1119 SQLiteDatabase db = this.getWritableDatabase();
1120 String[] args = {account.getUuid()};
1121 final int rows = db.delete(Account.TABLENAME, Account.UUID + "=?", args);
1122 return rows == 1;
1123 }
1124
1125 public boolean updateMessage(Message message, boolean includeBody) {
1126 SQLiteDatabase db = this.getWritableDatabase();
1127 String[] args = {message.getUuid()};
1128 ContentValues contentValues = message.getContentValues();
1129 contentValues.remove(Message.UUID);
1130 if (!includeBody) {
1131 contentValues.remove(Message.BODY);
1132 }
1133 return db.update(Message.TABLENAME, message.getContentValues(), Message.UUID + "=?", args) == 1 &&
1134 db.update("cheogram." + Message.TABLENAME, message.getCheogramContentValues(), Message.UUID + "=?", args) == 1;
1135 }
1136
1137 public boolean updateMessage(Message message, String uuid) {
1138 SQLiteDatabase db = this.getWritableDatabase();
1139 String[] args = {uuid};
1140 return db.update(Message.TABLENAME, message.getContentValues(), Message.UUID + "=?", args) == 1 &&
1141 db.update("cheogram." + Message.TABLENAME, message.getCheogramContentValues(), Message.UUID + "=?", args) == 1;
1142 }
1143
1144 public void readRoster(Roster roster) {
1145 final SQLiteDatabase db = this.getReadableDatabase();
1146 final String[] args = {roster.getAccount().getUuid()};
1147 try (final Cursor cursor =
1148 db.query(Contact.TABLENAME, null, Contact.ACCOUNT + "=?", args, null, null, null)) {
1149 while (cursor.moveToNext()) {
1150 roster.initContact(Contact.fromCursor(cursor));
1151 }
1152 }
1153 }
1154
1155 public void writeRoster(final Roster roster) {
1156 long start = SystemClock.elapsedRealtime();
1157 final Account account = roster.getAccount();
1158 final SQLiteDatabase db = this.getWritableDatabase();
1159 db.beginTransaction();
1160 for (Contact contact : roster.getContacts()) {
1161 if (contact.getOption(Contact.Options.IN_ROSTER) || contact.hasAvatarOrPresenceName() || contact.getOption(Contact.Options.SYNCED_VIA_OTHER)) {
1162 db.insert(Contact.TABLENAME, null, contact.getContentValues());
1163 } else {
1164 String where = Contact.ACCOUNT + "=? AND " + Contact.JID + "=?";
1165 String[] whereArgs = {account.getUuid(), contact.getJid().toString()};
1166 db.delete(Contact.TABLENAME, where, whereArgs);
1167 }
1168 }
1169 db.setTransactionSuccessful();
1170 db.endTransaction();
1171 account.setRosterVersion(roster.getVersion());
1172 updateAccount(account);
1173 long duration = SystemClock.elapsedRealtime() - start;
1174 Log.d(Config.LOGTAG, account.getJid().asBareJid() + ": persisted roster in " + duration + "ms");
1175 }
1176
1177 public void deleteMessagesInConversation(Conversation conversation) {
1178 long start = SystemClock.elapsedRealtime();
1179 final SQLiteDatabase db = this.getWritableDatabase();
1180 db.beginTransaction();
1181 final String[] args = {conversation.getUuid()};
1182 int num = db.delete(Message.TABLENAME, Message.CONVERSATION + "=?", args);
1183 db.setTransactionSuccessful();
1184 db.endTransaction();
1185 Log.d(Config.LOGTAG, "deleted " + num + " messages for " + conversation.getJid().asBareJid() + " in " + (SystemClock.elapsedRealtime() - start) + "ms");
1186 }
1187
1188 public void expireOldMessages(long timestamp) {
1189 final String[] args = {String.valueOf(timestamp)};
1190 SQLiteDatabase db = this.getReadableDatabase();
1191 db.beginTransaction();
1192 db.delete(Message.TABLENAME, "timeSent<?", args);
1193 db.setTransactionSuccessful();
1194 db.endTransaction();
1195 }
1196
1197 public MamReference getLastMessageReceived(Account account) {
1198 Cursor cursor = null;
1199 try {
1200 SQLiteDatabase db = this.getReadableDatabase();
1201 String sql = "select messages.timeSent,messages.serverMsgId from accounts join conversations on accounts.uuid=conversations.accountUuid join messages on conversations.uuid=messages.conversationUuid where accounts.uuid=? and (messages.status=0 or messages.carbon=1 or messages.serverMsgId not null) and (conversations.mode=0 or (messages.serverMsgId not null and messages.type=4)) order by messages.timesent desc limit 1";
1202 String[] args = {account.getUuid()};
1203 cursor = db.rawQuery(sql, args);
1204 if (cursor.getCount() == 0) {
1205 return null;
1206 } else {
1207 cursor.moveToFirst();
1208 return new MamReference(cursor.getLong(0), cursor.getString(1));
1209 }
1210 } catch (Exception e) {
1211 return null;
1212 } finally {
1213 if (cursor != null) {
1214 cursor.close();
1215 }
1216 }
1217 }
1218
1219 public long getLastTimeFingerprintUsed(Account account, String fingerprint) {
1220 String SQL = "select messages.timeSent from accounts join conversations on accounts.uuid=conversations.accountUuid join messages on conversations.uuid=messages.conversationUuid where accounts.uuid=? and messages.axolotl_fingerprint=? order by messages.timesent desc limit 1";
1221 String[] args = {account.getUuid(), fingerprint};
1222 Cursor cursor = getReadableDatabase().rawQuery(SQL, args);
1223 long time;
1224 if (cursor.moveToFirst()) {
1225 time = cursor.getLong(0);
1226 } else {
1227 time = 0;
1228 }
1229 cursor.close();
1230 return time;
1231 }
1232
1233 public MamReference getLastClearDate(Account account) {
1234 SQLiteDatabase db = this.getReadableDatabase();
1235 String[] columns = {Conversation.ATTRIBUTES};
1236 String selection = Conversation.ACCOUNT + "=?";
1237 String[] args = {account.getUuid()};
1238 Cursor cursor = db.query(Conversation.TABLENAME, columns, selection, args, null, null, null);
1239 MamReference maxClearDate = new MamReference(0);
1240 while (cursor.moveToNext()) {
1241 try {
1242 final JSONObject o = new JSONObject(cursor.getString(0));
1243 maxClearDate = MamReference.max(maxClearDate, MamReference.fromAttribute(o.getString(Conversation.ATTRIBUTE_LAST_CLEAR_HISTORY)));
1244 } catch (Exception e) {
1245 //ignored
1246 }
1247 }
1248 cursor.close();
1249 return maxClearDate;
1250 }
1251
1252 private Cursor getCursorForSession(Account account, SignalProtocolAddress contact) {
1253 final SQLiteDatabase db = this.getReadableDatabase();
1254 String[] selectionArgs = {account.getUuid(),
1255 contact.getName(),
1256 Integer.toString(contact.getDeviceId())};
1257 return db.query(SQLiteAxolotlStore.SESSION_TABLENAME,
1258 null,
1259 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
1260 + SQLiteAxolotlStore.NAME + " = ? AND "
1261 + SQLiteAxolotlStore.DEVICE_ID + " = ? ",
1262 selectionArgs,
1263 null, null, null);
1264 }
1265
1266 public SessionRecord loadSession(Account account, SignalProtocolAddress contact) {
1267 SessionRecord session = null;
1268 Cursor cursor = getCursorForSession(account, contact);
1269 if (cursor.getCount() != 0) {
1270 cursor.moveToFirst();
1271 try {
1272 session = new SessionRecord(Base64.decode(cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY)), Base64.DEFAULT));
1273 } catch (IOException e) {
1274 cursor.close();
1275 throw new AssertionError(e);
1276 }
1277 }
1278 cursor.close();
1279 return session;
1280 }
1281
1282 public List<Integer> getSubDeviceSessions(Account account, SignalProtocolAddress contact) {
1283 final SQLiteDatabase db = this.getReadableDatabase();
1284 return getSubDeviceSessions(db, account, contact);
1285 }
1286
1287 private List<Integer> getSubDeviceSessions(SQLiteDatabase db, Account account, SignalProtocolAddress contact) {
1288 List<Integer> devices = new ArrayList<>();
1289 String[] columns = {SQLiteAxolotlStore.DEVICE_ID};
1290 String[] selectionArgs = {account.getUuid(),
1291 contact.getName()};
1292 Cursor cursor = db.query(SQLiteAxolotlStore.SESSION_TABLENAME,
1293 columns,
1294 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
1295 + SQLiteAxolotlStore.NAME + " = ?",
1296 selectionArgs,
1297 null, null, null);
1298
1299 while (cursor.moveToNext()) {
1300 devices.add(cursor.getInt(
1301 cursor.getColumnIndex(SQLiteAxolotlStore.DEVICE_ID)));
1302 }
1303
1304 cursor.close();
1305 return devices;
1306 }
1307
1308 public List<String> getKnownSignalAddresses(Account account) {
1309 List<String> addresses = new ArrayList<>();
1310 String[] colums = {"DISTINCT " + SQLiteAxolotlStore.NAME};
1311 String[] selectionArgs = {account.getUuid()};
1312 Cursor cursor = getReadableDatabase().query(SQLiteAxolotlStore.SESSION_TABLENAME,
1313 colums,
1314 SQLiteAxolotlStore.ACCOUNT + " = ?",
1315 selectionArgs,
1316 null, null, null
1317 );
1318 while (cursor.moveToNext()) {
1319 addresses.add(cursor.getString(0));
1320 }
1321 cursor.close();
1322 return addresses;
1323 }
1324
1325 public boolean containsSession(Account account, SignalProtocolAddress contact) {
1326 Cursor cursor = getCursorForSession(account, contact);
1327 int count = cursor.getCount();
1328 cursor.close();
1329 return count != 0;
1330 }
1331
1332 public void storeSession(Account account, SignalProtocolAddress contact, SessionRecord session) {
1333 SQLiteDatabase db = this.getWritableDatabase();
1334 ContentValues values = new ContentValues();
1335 values.put(SQLiteAxolotlStore.NAME, contact.getName());
1336 values.put(SQLiteAxolotlStore.DEVICE_ID, contact.getDeviceId());
1337 values.put(SQLiteAxolotlStore.KEY, Base64.encodeToString(session.serialize(), Base64.DEFAULT));
1338 values.put(SQLiteAxolotlStore.ACCOUNT, account.getUuid());
1339 db.insert(SQLiteAxolotlStore.SESSION_TABLENAME, null, values);
1340 }
1341
1342 public void deleteSession(Account account, SignalProtocolAddress contact) {
1343 SQLiteDatabase db = this.getWritableDatabase();
1344 deleteSession(db, account, contact);
1345 }
1346
1347 private void deleteSession(SQLiteDatabase db, Account account, SignalProtocolAddress contact) {
1348 String[] args = {account.getUuid(),
1349 contact.getName(),
1350 Integer.toString(contact.getDeviceId())};
1351 db.delete(SQLiteAxolotlStore.SESSION_TABLENAME,
1352 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
1353 + SQLiteAxolotlStore.NAME + " = ? AND "
1354 + SQLiteAxolotlStore.DEVICE_ID + " = ? ",
1355 args);
1356 }
1357
1358 public void deleteAllSessions(Account account, SignalProtocolAddress contact) {
1359 SQLiteDatabase db = this.getWritableDatabase();
1360 String[] args = {account.getUuid(), contact.getName()};
1361 db.delete(SQLiteAxolotlStore.SESSION_TABLENAME,
1362 SQLiteAxolotlStore.ACCOUNT + "=? AND "
1363 + SQLiteAxolotlStore.NAME + " = ?",
1364 args);
1365 }
1366
1367 private Cursor getCursorForPreKey(Account account, int preKeyId) {
1368 SQLiteDatabase db = this.getReadableDatabase();
1369 String[] columns = {SQLiteAxolotlStore.KEY};
1370 String[] selectionArgs = {account.getUuid(), Integer.toString(preKeyId)};
1371 Cursor cursor = db.query(SQLiteAxolotlStore.PREKEY_TABLENAME,
1372 columns,
1373 SQLiteAxolotlStore.ACCOUNT + "=? AND "
1374 + SQLiteAxolotlStore.ID + "=?",
1375 selectionArgs,
1376 null, null, null);
1377
1378 return cursor;
1379 }
1380
1381 public PreKeyRecord loadPreKey(Account account, int preKeyId) {
1382 PreKeyRecord record = null;
1383 Cursor cursor = getCursorForPreKey(account, preKeyId);
1384 if (cursor.getCount() != 0) {
1385 cursor.moveToFirst();
1386 try {
1387 record = new PreKeyRecord(Base64.decode(cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY)), Base64.DEFAULT));
1388 } catch (IOException e) {
1389 throw new AssertionError(e);
1390 }
1391 }
1392 cursor.close();
1393 return record;
1394 }
1395
1396 public boolean containsPreKey(Account account, int preKeyId) {
1397 Cursor cursor = getCursorForPreKey(account, preKeyId);
1398 int count = cursor.getCount();
1399 cursor.close();
1400 return count != 0;
1401 }
1402
1403 public void storePreKey(Account account, PreKeyRecord record) {
1404 SQLiteDatabase db = this.getWritableDatabase();
1405 ContentValues values = new ContentValues();
1406 values.put(SQLiteAxolotlStore.ID, record.getId());
1407 values.put(SQLiteAxolotlStore.KEY, Base64.encodeToString(record.serialize(), Base64.DEFAULT));
1408 values.put(SQLiteAxolotlStore.ACCOUNT, account.getUuid());
1409 db.insert(SQLiteAxolotlStore.PREKEY_TABLENAME, null, values);
1410 }
1411
1412 public int deletePreKey(Account account, int preKeyId) {
1413 SQLiteDatabase db = this.getWritableDatabase();
1414 String[] args = {account.getUuid(), Integer.toString(preKeyId)};
1415 return db.delete(SQLiteAxolotlStore.PREKEY_TABLENAME,
1416 SQLiteAxolotlStore.ACCOUNT + "=? AND "
1417 + SQLiteAxolotlStore.ID + "=?",
1418 args);
1419 }
1420
1421 private Cursor getCursorForSignedPreKey(Account account, int signedPreKeyId) {
1422 SQLiteDatabase db = this.getReadableDatabase();
1423 String[] columns = {SQLiteAxolotlStore.KEY};
1424 String[] selectionArgs = {account.getUuid(), Integer.toString(signedPreKeyId)};
1425 Cursor cursor = db.query(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME,
1426 columns,
1427 SQLiteAxolotlStore.ACCOUNT + "=? AND " + SQLiteAxolotlStore.ID + "=?",
1428 selectionArgs,
1429 null, null, null);
1430
1431 return cursor;
1432 }
1433
1434 public SignedPreKeyRecord loadSignedPreKey(Account account, int signedPreKeyId) {
1435 SignedPreKeyRecord record = null;
1436 Cursor cursor = getCursorForSignedPreKey(account, signedPreKeyId);
1437 if (cursor.getCount() != 0) {
1438 cursor.moveToFirst();
1439 try {
1440 record = new SignedPreKeyRecord(Base64.decode(cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY)), Base64.DEFAULT));
1441 } catch (IOException e) {
1442 throw new AssertionError(e);
1443 }
1444 }
1445 cursor.close();
1446 return record;
1447 }
1448
1449 public List<SignedPreKeyRecord> loadSignedPreKeys(Account account) {
1450 List<SignedPreKeyRecord> prekeys = new ArrayList<>();
1451 SQLiteDatabase db = this.getReadableDatabase();
1452 String[] columns = {SQLiteAxolotlStore.KEY};
1453 String[] selectionArgs = {account.getUuid()};
1454 Cursor cursor = db.query(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME,
1455 columns,
1456 SQLiteAxolotlStore.ACCOUNT + "=?",
1457 selectionArgs,
1458 null, null, null);
1459
1460 while (cursor.moveToNext()) {
1461 try {
1462 prekeys.add(new SignedPreKeyRecord(Base64.decode(cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY)), Base64.DEFAULT)));
1463 } catch (IOException ignored) {
1464 }
1465 }
1466 cursor.close();
1467 return prekeys;
1468 }
1469
1470 public int getSignedPreKeysCount(Account account) {
1471 String[] columns = {"count(" + SQLiteAxolotlStore.KEY + ")"};
1472 String[] selectionArgs = {account.getUuid()};
1473 SQLiteDatabase db = this.getReadableDatabase();
1474 Cursor cursor = db.query(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME,
1475 columns,
1476 SQLiteAxolotlStore.ACCOUNT + "=?",
1477 selectionArgs,
1478 null, null, null);
1479 final int count;
1480 if (cursor.moveToFirst()) {
1481 count = cursor.getInt(0);
1482 } else {
1483 count = 0;
1484 }
1485 cursor.close();
1486 return count;
1487 }
1488
1489 public boolean containsSignedPreKey(Account account, int signedPreKeyId) {
1490 Cursor cursor = getCursorForPreKey(account, signedPreKeyId);
1491 int count = cursor.getCount();
1492 cursor.close();
1493 return count != 0;
1494 }
1495
1496 public void storeSignedPreKey(Account account, SignedPreKeyRecord record) {
1497 SQLiteDatabase db = this.getWritableDatabase();
1498 ContentValues values = new ContentValues();
1499 values.put(SQLiteAxolotlStore.ID, record.getId());
1500 values.put(SQLiteAxolotlStore.KEY, Base64.encodeToString(record.serialize(), Base64.DEFAULT));
1501 values.put(SQLiteAxolotlStore.ACCOUNT, account.getUuid());
1502 db.insert(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME, null, values);
1503 }
1504
1505 public void deleteSignedPreKey(Account account, int signedPreKeyId) {
1506 SQLiteDatabase db = this.getWritableDatabase();
1507 String[] args = {account.getUuid(), Integer.toString(signedPreKeyId)};
1508 db.delete(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME,
1509 SQLiteAxolotlStore.ACCOUNT + "=? AND "
1510 + SQLiteAxolotlStore.ID + "=?",
1511 args);
1512 }
1513
1514 private Cursor getIdentityKeyCursor(Account account, String name, boolean own) {
1515 final SQLiteDatabase db = this.getReadableDatabase();
1516 return getIdentityKeyCursor(db, account, name, own);
1517 }
1518
1519 private Cursor getIdentityKeyCursor(SQLiteDatabase db, Account account, String name, boolean own) {
1520 return getIdentityKeyCursor(db, account, name, own, null);
1521 }
1522
1523 private Cursor getIdentityKeyCursor(Account account, String fingerprint) {
1524 final SQLiteDatabase db = this.getReadableDatabase();
1525 return getIdentityKeyCursor(db, account, fingerprint);
1526 }
1527
1528 private Cursor getIdentityKeyCursor(SQLiteDatabase db, Account account, String fingerprint) {
1529 return getIdentityKeyCursor(db, account, null, null, fingerprint);
1530 }
1531
1532 private Cursor getIdentityKeyCursor(SQLiteDatabase db, Account account, String name, Boolean own, String fingerprint) {
1533 String[] columns = {SQLiteAxolotlStore.TRUST,
1534 SQLiteAxolotlStore.ACTIVE,
1535 SQLiteAxolotlStore.LAST_ACTIVATION,
1536 SQLiteAxolotlStore.KEY};
1537 ArrayList<String> selectionArgs = new ArrayList<>(4);
1538 selectionArgs.add(account.getUuid());
1539 String selectionString = SQLiteAxolotlStore.ACCOUNT + " = ?";
1540 if (name != null) {
1541 selectionArgs.add(name);
1542 selectionString += " AND " + SQLiteAxolotlStore.NAME + " = ?";
1543 }
1544 if (fingerprint != null) {
1545 selectionArgs.add(fingerprint);
1546 selectionString += " AND " + SQLiteAxolotlStore.FINGERPRINT + " = ?";
1547 }
1548 if (own != null) {
1549 selectionArgs.add(own ? "1" : "0");
1550 selectionString += " AND " + SQLiteAxolotlStore.OWN + " = ?";
1551 }
1552 Cursor cursor = db.query(SQLiteAxolotlStore.IDENTITIES_TABLENAME,
1553 columns,
1554 selectionString,
1555 selectionArgs.toArray(new String[selectionArgs.size()]),
1556 null, null, null);
1557
1558 return cursor;
1559 }
1560
1561 public IdentityKeyPair loadOwnIdentityKeyPair(Account account) {
1562 SQLiteDatabase db = getReadableDatabase();
1563 return loadOwnIdentityKeyPair(db, account);
1564 }
1565
1566 private IdentityKeyPair loadOwnIdentityKeyPair(SQLiteDatabase db, Account account) {
1567 String name = account.getJid().asBareJid().toString();
1568 IdentityKeyPair identityKeyPair = null;
1569 Cursor cursor = getIdentityKeyCursor(db, account, name, true);
1570 if (cursor.getCount() != 0) {
1571 cursor.moveToFirst();
1572 try {
1573 identityKeyPair = new IdentityKeyPair(Base64.decode(cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY)), Base64.DEFAULT));
1574 } catch (InvalidKeyException e) {
1575 Log.d(Config.LOGTAG, AxolotlService.getLogprefix(account) + "Encountered invalid IdentityKey in database for account" + account.getJid().asBareJid() + ", address: " + name);
1576 }
1577 }
1578 cursor.close();
1579
1580 return identityKeyPair;
1581 }
1582
1583 public Set<IdentityKey> loadIdentityKeys(Account account, String name) {
1584 return loadIdentityKeys(account, name, null);
1585 }
1586
1587 public Set<IdentityKey> loadIdentityKeys(Account account, String name, FingerprintStatus status) {
1588 Set<IdentityKey> identityKeys = new HashSet<>();
1589 Cursor cursor = getIdentityKeyCursor(account, name, false);
1590
1591 while (cursor.moveToNext()) {
1592 if (status != null && !FingerprintStatus.fromCursor(cursor).equals(status)) {
1593 continue;
1594 }
1595 try {
1596 String key = cursor.getString(cursor.getColumnIndex(SQLiteAxolotlStore.KEY));
1597 if (key != null) {
1598 identityKeys.add(new IdentityKey(Base64.decode(key, Base64.DEFAULT), 0));
1599 } else {
1600 Log.d(Config.LOGTAG, AxolotlService.getLogprefix(account) + "Missing key (possibly preverified) in database for account" + account.getJid().asBareJid() + ", address: " + name);
1601 }
1602 } catch (InvalidKeyException e) {
1603 Log.d(Config.LOGTAG, AxolotlService.getLogprefix(account) + "Encountered invalid IdentityKey in database for account" + account.getJid().asBareJid() + ", address: " + name);
1604 }
1605 }
1606 cursor.close();
1607
1608 return identityKeys;
1609 }
1610
1611 public long numTrustedKeys(Account account, String name) {
1612 SQLiteDatabase db = getReadableDatabase();
1613 String[] args = {
1614 account.getUuid(),
1615 name,
1616 FingerprintStatus.Trust.TRUSTED.toString(),
1617 FingerprintStatus.Trust.VERIFIED.toString(),
1618 FingerprintStatus.Trust.VERIFIED_X509.toString()
1619 };
1620 return DatabaseUtils.queryNumEntries(db, SQLiteAxolotlStore.IDENTITIES_TABLENAME,
1621 SQLiteAxolotlStore.ACCOUNT + " = ?"
1622 + " AND " + SQLiteAxolotlStore.NAME + " = ?"
1623 + " AND (" + SQLiteAxolotlStore.TRUST + " = ? OR " + SQLiteAxolotlStore.TRUST + " = ? OR " + SQLiteAxolotlStore.TRUST + " = ?)"
1624 + " AND " + SQLiteAxolotlStore.ACTIVE + " > 0",
1625 args
1626 );
1627 }
1628
1629 private void storeIdentityKey(Account account, String name, boolean own, String fingerprint, String base64Serialized, FingerprintStatus status) {
1630 SQLiteDatabase db = this.getWritableDatabase();
1631 ContentValues values = new ContentValues();
1632 values.put(SQLiteAxolotlStore.ACCOUNT, account.getUuid());
1633 values.put(SQLiteAxolotlStore.NAME, name);
1634 values.put(SQLiteAxolotlStore.OWN, own ? 1 : 0);
1635 values.put(SQLiteAxolotlStore.FINGERPRINT, fingerprint);
1636 values.put(SQLiteAxolotlStore.KEY, base64Serialized);
1637 values.putAll(status.toContentValues());
1638 String where = SQLiteAxolotlStore.ACCOUNT + "=? AND " + SQLiteAxolotlStore.NAME + "=? AND " + SQLiteAxolotlStore.FINGERPRINT + " =?";
1639 String[] whereArgs = {account.getUuid(), name, fingerprint};
1640 int rows = db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, values, where, whereArgs);
1641 if (rows == 0) {
1642 db.insert(SQLiteAxolotlStore.IDENTITIES_TABLENAME, null, values);
1643 }
1644 }
1645
1646 public void storePreVerification(Account account, String name, String fingerprint, FingerprintStatus status) {
1647 SQLiteDatabase db = this.getWritableDatabase();
1648 ContentValues values = new ContentValues();
1649 values.put(SQLiteAxolotlStore.ACCOUNT, account.getUuid());
1650 values.put(SQLiteAxolotlStore.NAME, name);
1651 values.put(SQLiteAxolotlStore.OWN, 0);
1652 values.put(SQLiteAxolotlStore.FINGERPRINT, fingerprint);
1653 values.putAll(status.toContentValues());
1654 db.insert(SQLiteAxolotlStore.IDENTITIES_TABLENAME, null, values);
1655 }
1656
1657 public FingerprintStatus getFingerprintStatus(Account account, String fingerprint) {
1658 Cursor cursor = getIdentityKeyCursor(account, fingerprint);
1659 final FingerprintStatus status;
1660 if (cursor.getCount() > 0) {
1661 cursor.moveToFirst();
1662 status = FingerprintStatus.fromCursor(cursor);
1663 } else {
1664 status = null;
1665 }
1666 cursor.close();
1667 return status;
1668 }
1669
1670 public boolean setIdentityKeyTrust(Account account, String fingerprint, FingerprintStatus fingerprintStatus) {
1671 SQLiteDatabase db = this.getWritableDatabase();
1672 return setIdentityKeyTrust(db, account, fingerprint, fingerprintStatus);
1673 }
1674
1675 private boolean setIdentityKeyTrust(SQLiteDatabase db, Account account, String fingerprint, FingerprintStatus status) {
1676 String[] selectionArgs = {
1677 account.getUuid(),
1678 fingerprint
1679 };
1680 int rows = db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, status.toContentValues(),
1681 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
1682 + SQLiteAxolotlStore.FINGERPRINT + " = ? ",
1683 selectionArgs);
1684 return rows == 1;
1685 }
1686
1687 public boolean setIdentityKeyCertificate(Account account, String fingerprint, X509Certificate x509Certificate) {
1688 SQLiteDatabase db = this.getWritableDatabase();
1689 String[] selectionArgs = {
1690 account.getUuid(),
1691 fingerprint
1692 };
1693 try {
1694 ContentValues values = new ContentValues();
1695 values.put(SQLiteAxolotlStore.CERTIFICATE, x509Certificate.getEncoded());
1696 return db.update(SQLiteAxolotlStore.IDENTITIES_TABLENAME, values,
1697 SQLiteAxolotlStore.ACCOUNT + " = ? AND "
1698 + SQLiteAxolotlStore.FINGERPRINT + " = ? ",
1699 selectionArgs) == 1;
1700 } catch (CertificateEncodingException e) {
1701 Log.d(Config.LOGTAG, "could not encode certificate");
1702 return false;
1703 }
1704 }
1705
1706 public X509Certificate getIdentityKeyCertifcate(Account account, String fingerprint) {
1707 SQLiteDatabase db = this.getReadableDatabase();
1708 String[] selectionArgs = {
1709 account.getUuid(),
1710 fingerprint
1711 };
1712 String[] colums = {SQLiteAxolotlStore.CERTIFICATE};
1713 String selection = SQLiteAxolotlStore.ACCOUNT + " = ? AND " + SQLiteAxolotlStore.FINGERPRINT + " = ? ";
1714 Cursor cursor = db.query(SQLiteAxolotlStore.IDENTITIES_TABLENAME, colums, selection, selectionArgs, null, null, null);
1715 if (cursor.getCount() < 1) {
1716 return null;
1717 } else {
1718 cursor.moveToFirst();
1719 byte[] certificate = cursor.getBlob(cursor.getColumnIndex(SQLiteAxolotlStore.CERTIFICATE));
1720 cursor.close();
1721 if (certificate == null || certificate.length == 0) {
1722 return null;
1723 }
1724 try {
1725 CertificateFactory certificateFactory = CertificateFactory.getInstance("X.509");
1726 return (X509Certificate) certificateFactory.generateCertificate(new ByteArrayInputStream(certificate));
1727 } catch (CertificateException e) {
1728 Log.d(Config.LOGTAG, "certificate exception " + e.getMessage());
1729 return null;
1730 }
1731 }
1732 }
1733
1734 public void storeIdentityKey(Account account, String name, IdentityKey identityKey, FingerprintStatus status) {
1735 storeIdentityKey(account, name, false, CryptoHelper.bytesToHex(identityKey.getPublicKey().serialize()), Base64.encodeToString(identityKey.serialize(), Base64.DEFAULT), status);
1736 }
1737
1738 public void storeOwnIdentityKeyPair(Account account, IdentityKeyPair identityKeyPair) {
1739 storeIdentityKey(account, account.getJid().asBareJid().toString(), true, CryptoHelper.bytesToHex(identityKeyPair.getPublicKey().serialize()), Base64.encodeToString(identityKeyPair.serialize(), Base64.DEFAULT), FingerprintStatus.createActiveVerified(false));
1740 }
1741
1742
1743 private void recreateAxolotlDb(SQLiteDatabase db) {
1744 Log.d(Config.LOGTAG, AxolotlService.LOGPREFIX + " : " + ">>> (RE)CREATING AXOLOTL DATABASE <<<");
1745 db.execSQL("DROP TABLE IF EXISTS " + SQLiteAxolotlStore.SESSION_TABLENAME);
1746 db.execSQL(CREATE_SESSIONS_STATEMENT);
1747 db.execSQL("DROP TABLE IF EXISTS " + SQLiteAxolotlStore.PREKEY_TABLENAME);
1748 db.execSQL(CREATE_PREKEYS_STATEMENT);
1749 db.execSQL("DROP TABLE IF EXISTS " + SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME);
1750 db.execSQL(CREATE_SIGNED_PREKEYS_STATEMENT);
1751 db.execSQL("DROP TABLE IF EXISTS " + SQLiteAxolotlStore.IDENTITIES_TABLENAME);
1752 db.execSQL(CREATE_IDENTITIES_STATEMENT);
1753 }
1754
1755 public void wipeAxolotlDb(Account account) {
1756 String accountName = account.getUuid();
1757 Log.d(Config.LOGTAG, AxolotlService.getLogprefix(account) + ">>> WIPING AXOLOTL DATABASE FOR ACCOUNT " + accountName + " <<<");
1758 SQLiteDatabase db = this.getWritableDatabase();
1759 String[] deleteArgs = {
1760 accountName
1761 };
1762 db.delete(SQLiteAxolotlStore.SESSION_TABLENAME,
1763 SQLiteAxolotlStore.ACCOUNT + " = ?",
1764 deleteArgs);
1765 db.delete(SQLiteAxolotlStore.PREKEY_TABLENAME,
1766 SQLiteAxolotlStore.ACCOUNT + " = ?",
1767 deleteArgs);
1768 db.delete(SQLiteAxolotlStore.SIGNED_PREKEY_TABLENAME,
1769 SQLiteAxolotlStore.ACCOUNT + " = ?",
1770 deleteArgs);
1771 db.delete(SQLiteAxolotlStore.IDENTITIES_TABLENAME,
1772 SQLiteAxolotlStore.ACCOUNT + " = ?",
1773 deleteArgs);
1774 }
1775
1776 public List<ShortcutService.FrequentContact> getFrequentContacts(int days) {
1777 SQLiteDatabase db = this.getReadableDatabase();
1778 final String SQL = "select " + Conversation.TABLENAME + "." + Conversation.ACCOUNT + "," + Conversation.TABLENAME + "." + Conversation.CONTACTJID + " from " + Conversation.TABLENAME + " join " + Message.TABLENAME + " on conversations.uuid=messages.conversationUuid where messages.status!=0 and carbon==0 and conversations.mode=0 and messages.timeSent>=? group by conversations.uuid order by count(body) desc limit 4;";
1779 String[] whereArgs = new String[]{String.valueOf(System.currentTimeMillis() - (Config.MILLISECONDS_IN_DAY * days))};
1780 Cursor cursor = db.rawQuery(SQL, whereArgs);
1781 ArrayList<ShortcutService.FrequentContact> contacts = new ArrayList<>();
1782 while (cursor.moveToNext()) {
1783 try {
1784 contacts.add(new ShortcutService.FrequentContact(cursor.getString(0), Jid.of(cursor.getString(1))));
1785 } catch (Exception e) {
1786 Log.d(Config.LOGTAG, e.getMessage());
1787 }
1788 }
1789 cursor.close();
1790 return contacts;
1791 }
1792}