Bug 1135086 - Implement in-place computed UPDATE in DBUtils. r=margaret

Sometimes it's convenient to want to do an UPDATE query like:

  UPDATE foo
  SET bar = bar | 5

or similar -- that is, refer to existing values in the SET expression.

This patch allows that, accepting an array of ContentValues and an array of
operations as input. A single UPDATE will be constructed from the entire input.
This commit is contained in:
Richard Newman 2015-02-19 21:38:18 -08:00
parent fd591238ff
commit c224ce808b
3 changed files with 249 additions and 0 deletions

View File

@ -4,7 +4,11 @@
package org.mozilla.gecko.db;
import android.annotation.TargetApi;
import android.database.sqlite.SQLiteDatabase;
import android.database.sqlite.SQLiteStatement;
import android.os.Build;
import org.mozilla.gecko.AppConstants;
import org.mozilla.gecko.GeckoAppShell;
import org.mozilla.gecko.GeckoProfile;
@ -15,6 +19,9 @@ import android.net.Uri;
import android.text.TextUtils;
import android.util.Log;
import org.mozilla.gecko.Telemetry;
import org.mozilla.gecko.mozglue.RobocopTarget;
import java.util.Map;
public class DBUtils {
private static final String LOGTAG = "GeckoDBUtils";
@ -173,4 +180,175 @@ public class DBUtils {
}
return appendProfile(profile, uri);
}
/**
* Use the following when no conflict action is specified.
*/
private static final int CONFLICT_NONE = 0;
private static final String[] CONFLICT_VALUES = new String[] {"", " OR ROLLBACK ", " OR ABORT ", " OR FAIL ", " OR IGNORE ", " OR REPLACE "};
/**
* Convenience method for updating rows in the database.
*
* @param table the table to update in
* @param values a map from column names to new column values. null is a
* valid value that will be translated to NULL.
* @param whereClause the optional WHERE clause to apply when updating.
* Passing null will update all rows.
* @param whereArgs You may include ?s in the where clause, which
* will be replaced by the values from whereArgs. The values
* will be bound as Strings.
* @return the number of rows affected
*/
@RobocopTarget
public static int updateArrays(SQLiteDatabase db, String table, ContentValues[] values, UpdateOperation[] ops, String whereClause, String[] whereArgs) {
return updateArraysWithOnConflict(db, table, values, ops, whereClause, whereArgs, CONFLICT_NONE, true);
}
public static void updateArraysBlindly(SQLiteDatabase db, String table, ContentValues[] values, UpdateOperation[] ops, String whereClause, String[] whereArgs) {
updateArraysWithOnConflict(db, table, values, ops, whereClause, whereArgs, CONFLICT_NONE, false);
}
@RobocopTarget
public enum UpdateOperation {
ASSIGN,
BITWISE_OR,
}
/**
* This is an evil reimplementation of SQLiteDatabase's methods to allow for
* smarter updating.
*
* Each ContentValues has an associated enum that describes how to unify input values with the existing column values.
*/
private static int updateArraysWithOnConflict(SQLiteDatabase db, String table,
ContentValues[] values,
UpdateOperation[] ops,
String whereClause,
String[] whereArgs,
int conflictAlgorithm,
boolean returnChangedRows) {
if (values == null || values.length == 0) {
throw new IllegalArgumentException("Empty values");
}
if (ops == null || ops.length != values.length) {
throw new IllegalArgumentException("ops and values don't match");
}
StringBuilder sql = new StringBuilder(120);
sql.append("UPDATE ");
sql.append(CONFLICT_VALUES[conflictAlgorithm]);
sql.append(table);
sql.append(" SET ");
// move all bind args to one array
int setValuesSize = 0;
for (int i = 0; i < values.length; i++) {
setValuesSize += values[i].size();
}
int bindArgsSize = (whereArgs == null) ? setValuesSize : (setValuesSize + whereArgs.length);
Object[] bindArgs = new Object[bindArgsSize];
int arg = 0;
for (int i = 0; i < values.length; i++) {
final ContentValues v = values[i];
final UpdateOperation op = ops[i];
// Alas, code duplication.
switch (op) {
case ASSIGN:
for (Map.Entry<String, Object> entry : v.valueSet()) {
final String colName = entry.getKey();
sql.append((arg > 0) ? "," : "");
sql.append(colName);
bindArgs[arg++] = entry.getValue();
sql.append("= ?");
}
break;
case BITWISE_OR:
for (Map.Entry<String, Object> entry : v.valueSet()) {
final String colName = entry.getKey();
sql.append((arg > 0) ? "," : "");
sql.append(colName);
bindArgs[arg++] = entry.getValue();
sql.append("= ? | ");
sql.append(colName);
}
break;
}
}
if (whereArgs != null) {
for (arg = setValuesSize; arg < bindArgsSize; arg++) {
bindArgs[arg] = whereArgs[arg - setValuesSize];
}
}
if (!TextUtils.isEmpty(whereClause)) {
sql.append(" WHERE ");
sql.append(whereClause);
}
// What a huge pain in the ass, all because SQLiteDatabase doesn't expose .executeSql,
// and we can't get a DB handle. Nor can we easily construct a statement with arguments
// already bound.
final SQLiteStatement statement = db.compileStatement(sql.toString());
try {
bindAllArgs(statement, bindArgs);
if (!returnChangedRows) {
statement.execute();
return 0;
}
if (AppConstants.Versions.feature11Plus) {
// This is a separate method so we can annotate it with @TargetApi.
return executeStatementReturningChangedRows(statement);
} else {
statement.execute();
final Cursor cursor = db.rawQuery("SELECT changes()", null);
try {
cursor.moveToFirst();
return cursor.getInt(0);
} finally {
cursor.close();
}
}
} finally {
statement.close();
}
}
@TargetApi(Build.VERSION_CODES.HONEYCOMB)
private static int executeStatementReturningChangedRows(SQLiteStatement statement) {
return statement.executeUpdateDelete();
}
// All because {@link SQLiteProgram#bind(integer, Object)} is private.
private static void bindAllArgs(SQLiteStatement statement, Object[] bindArgs) {
if (bindArgs == null) {
return;
}
for (int i = bindArgs.length; i != 0; i--) {
Object v = bindArgs[i - 1];
if (v == null) {
statement.bindNull(i);
} else if (v instanceof String) {
statement.bindString(i, (String) v);
} else if (v instanceof Double) {
statement.bindDouble(i, (Double) v);
} else if (v instanceof Float) {
statement.bindDouble(i, (Float) v);
} else if (v instanceof Long) {
statement.bindLong(i, (Long) v);
} else if (v instanceof Integer) {
statement.bindLong(i, (Integer) v);
} else if (v instanceof Byte) {
statement.bindLong(i, (Byte) v);
} else if (v instanceof byte[]) {
statement.bindBlob(i, (byte[]) v);
}
}
}
}

View File

@ -33,6 +33,7 @@ skip-if = android_version == "10"
[testClearPrivateData]
# disabled on x86 and 2.3; bug 948591
skip-if = android_version == "10" || processor == "x86"
[testDBUtils]
[testDistribution]
[testDoorHanger]
[testFilterOpenTab]

View File

@ -0,0 +1,70 @@
/* -*- Mode: Java; c-basic-offset: 4; tab-width: 20; indent-tabs-mode: nil; -*-
* This Source Code Form is subject to the terms of the Mozilla Public
* License, v. 2.0. If a copy of the MPL was not distributed with this
* file, You can obtain one at http://mozilla.org/MPL/2.0/. */
package org.mozilla.gecko.tests;
import android.content.ContentValues;
import android.database.Cursor;
import android.database.sqlite.SQLiteDatabase;
import org.mozilla.gecko.db.DBUtils;
import java.io.File;
import java.io.IOException;
public class testDBUtils extends BaseTest {
public void testDBUtils() throws IOException {
final File cacheDir = getInstrumentation().getContext().getCacheDir();
final File dbFile = File.createTempFile("testDBUtils", ".db", cacheDir);
final SQLiteDatabase db = SQLiteDatabase.openOrCreateDatabase(dbFile, null);
try {
mAsserter.ok(db != null, "Created DB.", null);
db.execSQL("CREATE TABLE foo (x INTEGER NOT NULL DEFAULT 0, y TEXT)");
final ContentValues v = new ContentValues();
v.put("x", 5);
v.put("y", "a");
db.insert("foo", null, v);
v.put("x", 2);
v.putNull("y");
db.insert("foo", null, v);
v.put("x", 3);
v.put("y", "z");
db.insert("foo", null, v);
DBUtils.UpdateOperation[] ops = {DBUtils.UpdateOperation.BITWISE_OR, DBUtils.UpdateOperation.ASSIGN};
ContentValues[] values = {new ContentValues(), new ContentValues()};
values[0].put("x", 0xff);
values[1].put("y", "hello");
final int updated = DBUtils.updateArrays(db, "foo", values, ops, "x >= 3", null);
mAsserter.ok(updated == 2, "Updated two rows.", null);
final Cursor out = db.query("foo", new String[]{"x", "y"}, null, null, null, null, "x");
try {
mAsserter.ok(out.moveToNext(), "Has first result.", null);
mAsserter.ok(2 == out.getInt(0), "1: First column was untouched.", null);
mAsserter.ok(out.isNull(1), "1: Second column was untouched.", null);
mAsserter.ok(out.moveToNext(), "Has second result.", null);
mAsserter.ok((0xff | 3) == out.getInt(0), "2: First column was ORed correctly.", null);
mAsserter.ok("hello".equals(out.getString(1)), "2: Second column was assigned correctly.", null);
mAsserter.ok(out.moveToNext(), "Has third result.", null);
mAsserter.ok((0xff | 5) == out.getInt(0), "3: First column was ORed correctly.", null);
mAsserter.ok("hello".equals(out.getString(1)), "3: Second column was assigned correctly.", null);
mAsserter.ok(!out.moveToNext(), "No more results.", null);
} finally {
out.close();
}
} finally {
try {
db.close();
} catch (Exception e) {
}
dbFile.delete();
}
}
}