Skip to content
This repository has been archived by the owner on Nov 8, 2023. It is now read-only.

Commit

Permalink
Optimize STREQUENT queries and fix estimated table row counts
Browse files Browse the repository at this point in the history
 - Use id instead of strings for matching mimetypes
 - Use inner LIMIT of 25 to prevent the extra subquery
   (also fixes correctness)
 - Reorder JOIN for data-usage-stat JOIN contacts
 - Defeat sqlite3's "optimization" attempt by using +0 on fields
   from contacts/data <-- This is huge

Bug:5560534

Change-Id: I412d359afe07f32643cc2faef8735b719686741f
  • Loading branch information
Daniel Lehmann committed Nov 15, 2011
1 parent b5000cb commit 72c4b26
Show file tree
Hide file tree
Showing 2 changed files with 137 additions and 35 deletions.
120 changes: 108 additions & 12 deletions src/com/android/providers/contacts/ContactsDatabaseHelper.java
Expand Up @@ -103,7 +103,7 @@
* 600-699 Ice Cream Sandwich
* </pre>
*/
static final int DATABASE_VERSION = 623;
static final int DATABASE_VERSION = 624;

private static final String DATABASE_NAME = "contacts2.db";
private static final String DATABASE_PRESENCE = "presence_db";
Expand Down Expand Up @@ -1270,6 +1270,7 @@ public void onCreate(SQLiteDatabase db) {
DataUsageStatColumns.USAGE_TYPE_INT +
");");

// When adding new tables, be sure to also add size-estimates in updateSqliteStats
createContactsViews(db);
createGroupsView(db);
createContactsTriggers(db);
Expand Down Expand Up @@ -2290,6 +2291,12 @@ public void onUpgrade(SQLiteDatabase db, int oldVersion, int newVersion) {
oldVersion = 623;
}

if (oldVersion < 624) {
// Upgraded the sqlite index stats
upgradeViewsAndTriggers = true;
oldVersion = 624;
}

if (upgradeViewsAndTriggers) {
createContactsViews(db);
createGroupsView(db);
Expand Down Expand Up @@ -3578,37 +3585,120 @@ private void bindLong(SQLiteStatement stmt, int index, Number value) {
private void updateSqliteStats(SQLiteDatabase db) {

// Specific stats strings are based on an actual large database after running ANALYZE
// Important here are relative sizes. Raw-Contacts is slightly bigger than Contacts
// Warning: Missing tables in here will make SQLite assume to contain 1000000 rows,
// which can lead to catastrophic query plans for small tables
try {
db.execSQL("DELETE FROM sqlite_stat1");
updateIndexStats(db, Tables.CONTACTS,
"contacts_has_phone_index", "10000 500");
"contacts_has_phone_index", "9000 500");
updateIndexStats(db, Tables.CONTACTS,
"contacts_name_raw_contact_id_index", "9000 1");

updateIndexStats(db, Tables.RAW_CONTACTS,
"raw_contacts_source_id_index", "10000 1 1 1");
updateIndexStats(db, Tables.RAW_CONTACTS,
"raw_contacts_contact_id_index", "10000 2");
updateIndexStats(db, Tables.RAW_CONTACTS,
"raw_contact_sort_key2_index", "10000 2");
updateIndexStats(db, Tables.RAW_CONTACTS,
"raw_contact_sort_key1_index", "10000 2");
updateIndexStats(db, Tables.RAW_CONTACTS,
"raw_contacts_source_id_data_set_index", "10000 1 1 1 1");

updateIndexStats(db, Tables.NAME_LOOKUP,
"name_lookup_raw_contact_id_index", "10000 3");
"name_lookup_raw_contact_id_index", "35000 4");
updateIndexStats(db, Tables.NAME_LOOKUP,
"name_lookup_index", "10000 3 2 2 1");
"name_lookup_index", "35000 2 2 2 1");
updateIndexStats(db, Tables.NAME_LOOKUP,
"sqlite_autoindex_name_lookup_1", "10000 3 2 1");
"sqlite_autoindex_name_lookup_1", "35000 3 2 1");

updateIndexStats(db, Tables.PHONE_LOOKUP,
"phone_lookup_index", "10000 2 2 1");
"phone_lookup_index", "3500 3 2 1");
updateIndexStats(db, Tables.PHONE_LOOKUP,
"phone_lookup_min_match_index", "3500 3 2 2");
updateIndexStats(db, Tables.PHONE_LOOKUP,
"phone_lookup_min_match_index", "10000 2 2 1");
"phone_lookup_data_id_min_match_index", "3500 2 2");

updateIndexStats(db, Tables.DATA,
"data_mimetype_data1_index", "60000 5000 2");
updateIndexStats(db, Tables.DATA,
"data_raw_contact_id", "60000 10");

updateIndexStats(db, Tables.GROUPS,
"groups_source_id_index", "50 1 1 1");
"groups_source_id_index", "50 2 2 1");
updateIndexStats(db, Tables.GROUPS,
"groups_source_id_data_set_index", "50 2 2 1 1");

updateIndexStats(db, Tables.NICKNAME_LOOKUP,
"sqlite_autoindex_name_lookup_1", "500 2 1");
"nickname_lookup_index", "500 2 1");

updateIndexStats(db, Tables.CALLS,
null, "250");

updateIndexStats(db, Tables.STATUS_UPDATES,
null, "100");

updateIndexStats(db, Tables.STREAM_ITEMS,
null, "500");
updateIndexStats(db, Tables.STREAM_ITEM_PHOTOS,
null, "50");

updateIndexStats(db, Tables.ACTIVITIES,
null, "5");

updateIndexStats(db, Tables.VOICEMAIL_STATUS,
null, "5");

updateIndexStats(db, Tables.ACCOUNTS,
null, "3");

updateIndexStats(db, Tables.VISIBLE_CONTACTS,
null, "2000");

updateIndexStats(db, Tables.PHOTO_FILES,
null, "50");

updateIndexStats(db, Tables.DEFAULT_DIRECTORY,
null, "1500");

updateIndexStats(db, Tables.MIMETYPES,
"mime_type", "18 1");

updateIndexStats(db, Tables.DATA_USAGE_STAT,
"data_usage_stat_index", "20 2 1");

// Tiny tables
updateIndexStats(db, Tables.AGGREGATION_EXCEPTIONS,
null, "10");
updateIndexStats(db, Tables.SETTINGS,
null, "10");
updateIndexStats(db, Tables.PACKAGES,
null, "0");
updateIndexStats(db, Tables.DIRECTORIES,
null, "3");
updateIndexStats(db, LegacyApiSupport.LegacyTables.SETTINGS,
null, "0");
updateIndexStats(db, "android_metadata",
null, "1");
updateIndexStats(db, "_sync_state",
"sqlite_autoindex__sync_state_1", "2 1 1");
updateIndexStats(db, "_sync_state_metadata",
null, "1");
updateIndexStats(db, "properties",
"sqlite_autoindex_properties_1", "4 1");

// Search index
updateIndexStats(db, "search_index_docsize",
null, "9000");
updateIndexStats(db, "search_index_content",
null, "9000");
updateIndexStats(db, "search_index_stat",
null, "1");
updateIndexStats(db, "search_index_segments",
null, "450");
updateIndexStats(db, "search_index_segdir",
"sqlite_autoindex_search_index_segdir_1", "9 5 1");

} catch (SQLException e) {
Log.e(TAG, "Could not update index stats", e);
Expand All @@ -3624,9 +3714,15 @@ private void updateSqliteStats(SQLiteDatabase db) {
*/
private void updateIndexStats(SQLiteDatabase db, String table, String index,
String stats) {
db.execSQL("DELETE FROM sqlite_stat1 WHERE tbl='" + table + "' AND idx='" + index + "';");
db.execSQL("INSERT INTO sqlite_stat1 (tbl,idx,stat)"
+ " VALUES ('" + table + "','" + index + "','" + stats + "');");
if (index == null) {
db.execSQL("DELETE FROM sqlite_stat1 WHERE tbl=? AND idx IS NULL",
new String[] { table });
} else {
db.execSQL("DELETE FROM sqlite_stat1 WHERE tbl=? AND idx=?",
new String[] { table, index });
}
db.execSQL("INSERT INTO sqlite_stat1 (tbl,idx,stat) VALUES (?,?,?)",
new String[] { table, index, stats });
}

@Override
Expand Down
52 changes: 29 additions & 23 deletions src/com/android/providers/contacts/ContactsProvider2.java
Expand Up @@ -28,7 +28,6 @@
import com.android.providers.contacts.ContactsDatabaseHelper.DataUsageStatColumns;
import com.android.providers.contacts.ContactsDatabaseHelper.GroupsColumns;
import com.android.providers.contacts.ContactsDatabaseHelper.Joins;
import com.android.providers.contacts.ContactsDatabaseHelper.MimetypesColumns;
import com.android.providers.contacts.ContactsDatabaseHelper.NameLookupColumns;
import com.android.providers.contacts.ContactsDatabaseHelper.NameLookupType;
import com.android.providers.contacts.ContactsDatabaseHelper.PhoneColumns;
Expand Down Expand Up @@ -236,13 +235,6 @@ public class ContactsProvider2 extends AbstractContactsProvider
*/
private static final String TIMES_USED_SORT_COLUMN = "times_used_sort";

private static final String STREQUENT_ORDER_BY = Contacts.STARRED + " DESC, "
+ TIMES_USED_SORT_COLUMN + " DESC, "
+ Contacts.DISPLAY_NAME + " COLLATE LOCALIZED ASC";
private static final String STREQUENT_LIMIT =
"(SELECT COUNT(1) FROM " + Tables.CONTACTS + " WHERE "
+ Contacts.STARRED + "=1) + 25";

private static final String FREQUENT_ORDER_BY = DataUsageStatColumns.TIMES_USED + " DESC,"
+ Contacts.DISPLAY_NAME + " COLLATE LOCALIZED ASC";

Expand Down Expand Up @@ -5205,15 +5197,17 @@ protected Cursor queryLocal(Uri uri, String[] projection, String selection,
selection, Contacts.HAS_PHONE_NUMBER + "=1"));
}
qb.setStrict(true);
final String starredQuery = qb.buildQuery(subProjection,
Contacts.STARRED + "=1", Contacts._ID, null, null, null);
final String starredInnerQuery = qb.buildQuery(subProjection,
Contacts.STARRED + "=1", Contacts._ID, null,
Contacts.DISPLAY_NAME + " COLLATE LOCALIZED ASC", null);

// Reset the builder.
qb = new SQLiteQueryBuilder();
qb.setStrict(true);

// Build the second query for frequent part.
final String frequentQuery;
// Build the second query for frequent part. These JOINS can be very slow
// if assembled in the wrong order. Be sure to test changes against huge databases.
final String frequentInnerQuery;
if (phoneOnly) {
final StringBuilder tableBuilder = new StringBuilder();
// In phone only mode, we need to look at view_data instead of
Expand All @@ -5238,27 +5232,36 @@ protected Cursor queryLocal(Uri uri, String[] projection, String selection,

qb.setTables(tableBuilder.toString());
qb.setProjectionMap(sStrequentPhoneOnlyFrequentProjectionMap);
final long phoneMimeTypeId =
mDbHelper.get().getMimeTypeId(Phone.CONTENT_ITEM_TYPE);
final long sipMimeTypeId =
mDbHelper.get().getMimeTypeId(SipAddress.CONTENT_ITEM_TYPE);
qb.appendWhere(DbQueryUtils.concatenateClauses(
selection,
Contacts.STARRED + "=0 OR " + Contacts.STARRED + " IS NULL",
MimetypesColumns.MIMETYPE + " IN ("
+ "'" + Phone.CONTENT_ITEM_TYPE + "', "
+ "'" + SipAddress.CONTENT_ITEM_TYPE + "')"));
frequentQuery = qb.buildQuery(subProjection, null, null, null, null, null);
DataColumns.MIMETYPE_ID + " IN (" +
phoneMimeTypeId + ", " + sipMimeTypeId + ")"));
frequentInnerQuery =
qb.buildQuery(subProjection, null, null, null,
TIMES_USED_SORT_COLUMN + " DESC", "25");
} else {
setTablesAndProjectionMapForContacts(qb, uri, projection, true);
qb.setProjectionMap(sStrequentFrequentProjectionMap);
qb.appendWhere(DbQueryUtils.concatenateClauses(
selection,
"(" + Contacts.STARRED + " =0 OR " + Contacts.STARRED + " IS NULL)"));
frequentQuery = qb.buildQuery(subProjection,
null, Contacts._ID, null, null, null);
frequentInnerQuery = qb.buildQuery(subProjection,
null, Contacts._ID, null, null, "25");
}

// We need to wrap the inner queries in an extra select, because they contain
// their own SORT and LIMIT
final String frequentQuery = "SELECT * FROM (" + frequentInnerQuery + ")";
final String starredQuery = "SELECT * FROM (" + starredInnerQuery + ")";

// Put them together
final String unionQuery =
qb.buildUnionQuery(new String[] {starredQuery, frequentQuery},
STREQUENT_ORDER_BY, STREQUENT_LIMIT);
qb.buildUnionQuery(new String[] {starredQuery, frequentQuery}, null, null);

// Here, we need to use selection / selectionArgs (supplied from users) "twice",
// as we want them both for starred items and for frequently contacted items.
Expand Down Expand Up @@ -6398,13 +6401,16 @@ private void setTablesAndProjectionMapForContacts(SQLiteQueryBuilder qb, Uri uri
private void setTablesAndProjectionMapForContacts(SQLiteQueryBuilder qb, Uri uri,
String[] projection, boolean includeDataUsageStat) {
StringBuilder sb = new StringBuilder();
if (includeDataUsageStat) {
sb.append(Views.DATA_USAGE_STAT + " AS " + Tables.DATA_USAGE_STAT);
sb.append(" INNER JOIN ");
}

sb.append(Views.CONTACTS);

// Just for frequently contacted contacts in Strequent Uri handling.
if (includeDataUsageStat) {
sb.append(" INNER JOIN " +
Views.DATA_USAGE_STAT + " AS " + Tables.DATA_USAGE_STAT +
" ON (" +
sb.append(" ON (" +
DbQueryUtils.concatenateClauses(
DataUsageStatColumns.CONCRETE_TIMES_USED + " > 0",
RawContacts.CONTACT_ID + "=" + Views.CONTACTS + "." + Contacts._ID) +
Expand Down

0 comments on commit 72c4b26

Please sign in to comment.