Skip to content

Commit

Permalink
Merge pull request #702 from cosmocode/optimize-queries
Browse files Browse the repository at this point in the history
Optimize queries
  • Loading branch information
annda committed Jan 18, 2024
2 parents 67f70d5 + 52637a9 commit 0faf857
Show file tree
Hide file tree
Showing 5 changed files with 55 additions and 2 deletions.
27 changes: 27 additions & 0 deletions action/migration.php
Expand Up @@ -340,6 +340,33 @@ protected function migration19($sqlite)
return $ok;
}

/**
* Executes Migration 20
*
* Adds indexes on "latest" and "published".
* Those fields are not part of (autoindexed) primary key, but are used in many queries.
*
* @param SQLiteDB $sqlite
* @return bool
*/
protected function migration20($sqlite)
{
$ok = true;

/** @noinspection SqlResolve */
$sql = "SELECT name FROM sqlite_master WHERE type = 'table' AND (name LIKE 'data_%' OR name LIKE 'multi_%')";
$tables = $sqlite->queryAll($sql);

foreach ($tables as $row) {
$table = $row['name']; // no escaping needed, it's our own tables
$sql = "CREATE INDEX idx_$table" . "_latest ON $table(latest);";
$ok = $ok && $sqlite->query($sql);
$sql = "CREATE INDEX idx_$table" . "_published ON $table(published);";
$ok = $ok && $sqlite->query($sql);
}
return $ok;
}


/**
* Returns a select statement to fetch Lookup columns in the current schema
Expand Down
2 changes: 1 addition & 1 deletion db/latest.version
@@ -1 +1 @@
19
20
3 changes: 3 additions & 0 deletions db/update0020.sql
@@ -0,0 +1,3 @@
-- this migration is handled in action/migrations.php in migration20()
--
-- it adds indexes on fields that are not automatically indexed (latest, published)
22 changes: 22 additions & 0 deletions helper/db.php
Expand Up @@ -29,6 +29,9 @@ protected function init()
// register our JSON function with variable parameters
$this->sqlite->getPdo()->sqliteCreateFunction('STRUCT_JSON', [$this, 'STRUCT_JSON'], -1);

// register our JSON decode function with variable parameters
$this->sqlite->getPdo()->sqliteCreateFunction('STRUCT_LOOKUP', [$this, 'STRUCT_LOOKUP'], -1);

// this function is meant to be overwritten by plugins
$this->sqlite->getPdo()->sqliteCreateFunction('IS_PUBLISHER', [$this, 'IS_PUBLISHER'], -1);
}
Expand Down Expand Up @@ -83,6 +86,25 @@ public function STRUCT_JSON(...$args) // phpcs:ignore PSR1.Methods.CamelCapsMeth
return json_encode($args, JSON_THROW_ON_ERROR);
}

/**
* Decodes a struct JSON structure and returns the requested value
*
* @param ...$args
* @return mixed|null
*/
public function STRUCT_LOOKUP(...$args) // phpcs:ignore PSR1.Methods.CamelCapsMethodName.NotCamelCaps
{
$json = $args[0];
$field = $args[1];

try {
$vals = json_decode($json, true, 512, JSON_THROW_ON_ERROR);
} catch (\JsonException $exception) {
return null;
}
return $vals[$field];
}

/**
* This dummy implementation can be overwritten by a plugin
*
Expand Down
3 changes: 2 additions & 1 deletion types/Lookup.php
Expand Up @@ -245,7 +245,8 @@ public function select(QueryBuilder $QB, $tablealias, $colname, $alias)
$tablealias,
$schema,
$rightalias,
"$tablealias.$colname = STRUCT_JSON($rightalias.pid, CAST($rightalias.rid AS DECIMAL)) " .
"STRUCT_LOOKUP($tablealias.$colname, 0) = $rightalias.pid " .
"AND STRUCT_LOOKUP($tablealias.$colname, 1) = $rightalias.rid " .
"AND $rightalias.latest = 1"
);
$column->getType()->select($QB, $rightalias, $field, $alias);
Expand Down

0 comments on commit 0faf857

Please sign in to comment.