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