DatabaseBackend.java

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