Skip to content

Commit

Permalink
Merge pull request #1101 from pulsejet/pulsejet/opt
Browse files Browse the repository at this point in the history
Query performance improvements
  • Loading branch information
pulsejet committed Mar 29, 2024
2 parents f5bd610 + d7f6abb commit 5bb5f2f
Show file tree
Hide file tree
Showing 19 changed files with 339 additions and 52 deletions.
5 changes: 4 additions & 1 deletion CHANGELOG.md
Original file line number Diff line number Diff line change
Expand Up @@ -4,11 +4,14 @@ All notable changes to this project will be documented in this file.

## [Unreleased]

- A Docker Compose example using the community Nextcloud image is now available in the repo.
- **Notice**: This release significantly overhauls the core querying infrastructure for better performance. If you run into any regressions (including performance), please [file a bug report](https://github.com/pulsejet/memories/issues)
- **Breaking**: If you are running MySQL (not applicable to MariaDB), you may need some extra configuration for setting up database triggers. Check the admin panel for any errors in the performance section and refer to the documentation [here](https://memories.gallery/troubleshooting/#trigger-compatibility-mode).
- **Feature**: Allow sorting albums by most recently updated.
- **Feature**: Allow sorting albums in ascending and descending direction.
- **Feature**: Manual upload to folder is now available in the Android app.
- **Documentation**: A Docker Compose example using the community Nextcloud image is now available in the repo.
- **Fix**: Prevent turning off screen when playing videos.
- Support for Nextcloud 29

## [v7.0.2] - 2024-03-19

Expand Down
27 changes: 23 additions & 4 deletions docs/troubleshooting.md
Original file line number Diff line number Diff line change
Expand Up @@ -72,6 +72,18 @@ app:
occ config:system:set memories.exiftool.tmp --value /path/to/temp/dir
```

## Trigger compatibility mode

Memories utilizes database triggers for certain functionality and if these triggers cannot be used then the app will run in trigger compatibility mode. This mode is much slower especially on larger databases.

If your admin panel shows that Memories is running in trigger compatibility mode, try the following steps.

1. Run `occ maintenance:repair` to attempt to create the triggers. This will print any errors that occur.
2. Restart the PHP server.
3. If you are using MySQL (not applicable to MariaDB), set the `log_bin_trust_function_creators` option is set to `1` in your `my.cnf` file. If you are using docker, you can add `--log_bin_trust_function_creators=true` to your command line. Repeat steps 1 and 2 after making this change.

If none of the above work or are applicable, file a bug at the repository including the output of `occ maintenance:repair`.

## Issues with NixOS

### Background index fails
Expand Down Expand Up @@ -128,21 +140,28 @@ Memories transcodes videos on the fly per-user. This saves space, but requires r
If you want to completely reset Memories (e.g. for database trouble), uninstall it from the app store, then run the following SQL on your database to clean up any data.
Note that this can have unintended consequences such as some files appearing as duplicates in the mobile app when you reinstall Memories.

Note: this assumes the default prefix `oc_`. If you have a different prefix, replace `oc_` with your prefix.

```sql
DROP TABLE IF EXISTS oc_memories;
DROP TABLE IF EXISTS oc_memories_covers;
DROP TABLE IF EXISTS oc_memories_failures;
DROP TABLE IF EXISTS oc_memories_livephoto;
DROP TABLE IF EXISTS oc_memories_mapclusters;
DROP TABLE IF EXISTS oc_memories_places;
DROP TABLE IF EXISTS oc_memories_planet;
DROP TABLE IF EXISTS memories_planet_geometry;
DROP INDEX IF EXISTS memories_parent_mimetype ON oc_filecache; /* MySQL */
DELETE FROM oc_migrations WHERE app='memories';
```

On Postgres, the syntax for dropping the index is:
/* The following statements are ONLY for MySQL / MariaDB */
DROP INDEX IF EXISTS memories_parent_mimetype ON oc_filecache;
DROP INDEX IF EXISTS memories_type_tagid ON systemtag_object_mapping;
DROP TRIGGER IF EXISTS memories_fcu_trg;

```sql
/* The following statements are ONLY for Postgres */
DROP INDEX IF EXISTS memories_parent_mimetype;
DROP INDEX IF EXISTS memories_type_tagid;
DROP FUNCTION IF EXISTS memories_fcu_fun CASCADE;
```

!!! warning "Reinstallation"
Expand Down
30 changes: 26 additions & 4 deletions e2e/folders.spec.ts
Original file line number Diff line number Diff line change
Expand Up @@ -10,14 +10,36 @@ test.describe('Open', () => {
});

test('Look for Folders', async ({ page }) => {
const ct = await page.locator('.big-icon').count();
const ct = await page.locator('.big-icon:visible').count();
expect(ct, 'Number of folders').toBe(2);
});

test('Open folder', async ({ page }) => {
test('Select image and move out of folder', async ({ page }) => {
await page.locator('text=Local').click();
await page.waitForTimeout(2000);
const elems = await page.locator('.img-outer').all();
expect(elems.length).toBeGreaterThanOrEqual(3);
let elems = await page.locator('.img-outer:visible').all();
expect(elems.length, 'Number of files').toEqual(3);

// This also tests the SQL triggers since move has no hooks
await page.locator('.img-outer').nth(1).hover();
await page.locator('.p-outer:visible > .select').nth(1).click();
await page.waitForTimeout(500);

// click selection menu button
await page.locator('.top-bar button[aria-label="Actions"]').click();
await page.waitForTimeout(500);

// click move button
await page.locator('text=Move to folder').click();
await page.waitForTimeout(2000); // slow
await page.locator('tr[data-filename="Photos"]').click();

// Action button
await page.locator('.dialog button[aria-label^="Move"]').click();
await page.waitForTimeout(2000);

// Check if the file is moved
elems = await page.locator('.img-outer:visible').all();
expect(elems.length, 'Number of files').toEqual(2);
});
});
6 changes: 3 additions & 3 deletions lib/ClustersBackend/FaceRecognitionBackend.php
Original file line number Diff line number Diff line change
Expand Up @@ -175,7 +175,7 @@ public function getPhotos(string $name, ?int $limit = null, ?int $fileid = null)
$query->where($query->expr()->eq($nameField, $query->createNamedParameter($name)));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// LIMIT results
if (-6 === $limit) {
Expand Down Expand Up @@ -263,7 +263,7 @@ private function getFaceRecognitionClusters(int $fileid = 0): array
));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// GROUP by ID of face cluster
$query->addGroupBy('frp.id', 'frp.user');
Expand Down Expand Up @@ -324,7 +324,7 @@ private function getFaceRecognitionPersons(int $fileid = 0): array
));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// GROUP by name of face clusters
$query->where($query->expr()->isNotNull('frp.name'));
Expand Down
11 changes: 7 additions & 4 deletions lib/ClustersBackend/PlacesBackend.php
Original file line number Diff line number Diff line change
Expand Up @@ -120,7 +120,7 @@ public function getClustersInternal(int $fileid = 0): array
$query->innerJoin('mp', 'memories', 'm', $query->expr()->eq('m.fileid', 'mp.fileid'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// GROUP and ORDER by tag name
$query->groupBy('e.osm_id');
Expand Down Expand Up @@ -192,16 +192,19 @@ public function getPhotos(string $name, ?int $limit = null, ?int $fileid = null)
$query = $this->tq->getBuilder();

// SELECT all photos with this tag
$query->select('f.fileid', 'f.etag', 'mp.osm_id')
$query->select('m.fileid', 'f.etag', 'mp.osm_id')
->from('memories_places', 'mp')
->where($query->expr()->eq('mp.osm_id', $query->createNamedParameter((int) $name)))
;

// WHERE these items are memories indexed photos
$query->innerJoin('mp', 'memories', 'm', $query->expr()->eq('m.fileid', 'mp.fileid'));

// JOIN with the filecache table
$query->innerJoin('m', 'filecache', 'f', $query->expr()->eq('m.fileid', 'f.fileid'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// MAX number of photos
if (-6 === $limit) {
Expand All @@ -212,7 +215,7 @@ public function getPhotos(string $name, ?int $limit = null, ?int $fileid = null)

// Filter by fileid if specified
if (null !== $fileid) {
$query->andWhere($query->expr()->eq('f.fileid', $query->createNamedParameter($fileid, \PDO::PARAM_INT)));
$query->andWhere($query->expr()->eq('m.fileid', $query->createNamedParameter($fileid, \PDO::PARAM_INT)));
}

// FETCH tag photos
Expand Down
4 changes: 2 additions & 2 deletions lib/ClustersBackend/RecognizeBackend.php
Original file line number Diff line number Diff line change
Expand Up @@ -143,7 +143,7 @@ public function getClustersInternal(int $fileid = 0): array
$query->innerJoin('rfd', 'memories', 'm', $query->expr()->eq('m.fileid', 'rfd.file_id'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// WHERE this cluster belongs to the user
$query->where($query->expr()->eq('rfc.user_id', $query->createNamedParameter(Util::getUID())));
Expand Down Expand Up @@ -230,7 +230,7 @@ public function getPhotos(string $name, ?int $limit = null, ?int $fileid = null)
$query->innerJoin('rfd', 'memories', 'm', $query->expr()->eq('m.fileid', 'rfd.file_id'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// LIMIT results
if (-6 === $limit) {
Expand Down
7 changes: 5 additions & 2 deletions lib/ClustersBackend/TagsBackend.php
Original file line number Diff line number Diff line change
Expand Up @@ -88,7 +88,7 @@ public function getClustersInternal(int $fileid = 0): array
$query->innerJoin('stom', 'memories', 'm', $query->expr()->eq('m.objectid', 'stom.objectid'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// GROUP and ORDER by tag name
$query->addGroupBy('st.id');
Expand Down Expand Up @@ -140,7 +140,10 @@ public function getPhotos(string $name, ?int $limit = null, ?int $fileid = null)
$query->innerJoin('stom', 'memories', 'm', $query->expr()->eq('m.objectid', 'stom.objectid'));

// WHERE these photos are in the user's requested folder recursively
$query = $this->tq->joinFilecache($query);
$query = $this->tq->filterFilecache($query);

// JOIN with the filecache table
$query->innerJoin('m', 'filecache', 'f', $query->expr()->eq('f.fileid', 'm.fileid'));

// MAX number of files
if (-6 === $limit) {
Expand Down
76 changes: 76 additions & 0 deletions lib/Db/AddMissingIndices.php
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,8 @@
namespace OCA\Memories\Db;

use OC\DB\SchemaWrapper;
use OCA\Memories\Settings\SystemConfig;
use OCP\IDBConnection;
use OCP\Migration\IOutput;

class AddMissingIndices
Expand Down Expand Up @@ -68,6 +70,80 @@ public static function run(IOutput $output): SchemaWrapper
$output->info('External table schema seem up to date');
}

// Create triggers in this step too
self::createFilecacheTriggers($output);

return $schema;
}

/**
* Create filecache triggers.
*/
public static function createFilecacheTriggers(IOutput $output): void
{
$connection = \OC::$server->get(IDBConnection::class);
$platform = $connection->getDatabasePlatform();

// Trigger to update parent from filecache
try {
if (preg_match('/mysql|mariadb/i', $platform::class)) {
// MySQL has no upsert for triggers
$connection->executeQuery('DROP TRIGGER IF EXISTS memories_fcu_trg;');

// Create the trigger again
$connection->executeQuery(
'CREATE TRIGGER memories_fcu_trg
AFTER UPDATE ON *PREFIX*filecache
FOR EACH ROW
UPDATE *PREFIX*memories
SET parent = NEW.parent
WHERE fileid = NEW.fileid;',
);
} elseif (preg_match('/postgres/i', $platform::class)) {
// Postgres requres a function to do the update
// Note: when dropping, the function should be dropped
// with CASCADE to remove the trigger as well
$connection->executeQuery(
'CREATE OR REPLACE FUNCTION memories_fcu_fun()
RETURNS TRIGGER AS $$
BEGIN
UPDATE *PREFIX*memories
SET parent = NEW.parent
WHERE fileid = NEW.fileid;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;',
);

// Create the trigger for the function
$connection->executeQuery(
'CREATE OR REPLACE TRIGGER memories_fcu_trg
AFTER UPDATE ON *PREFIX*filecache
FOR EACH ROW
EXECUTE FUNCTION memories_fcu_fun();',
);
} elseif (preg_match('/sqlite/i', $platform::class)) {
// Exactly the same as MySQL except for the BEGIN and END
$connection->executeQuery('DROP TRIGGER IF EXISTS memories_fcu_trg;');
$connection->executeQuery(
'CREATE TRIGGER memories_fcu_trg
AFTER UPDATE ON *PREFIX*filecache
FOR EACH ROW
BEGIN
UPDATE *PREFIX*memories
SET parent = NEW.parent
WHERE fileid = NEW.fileid;
END;',
);
} else {
throw new \Exception('Unsupported database platform: '.$platform::class);
}

$output->info('Recreated filecache trigger with: '.$platform::class);
SystemConfig::set('memories.db.triggers.fcu', true);
} catch (\Throwable $e) {
$output->warning('Failed to create filecache trigger (compatibility mode will be used): '.$e->getMessage());
SystemConfig::set('memories.db.triggers.fcu', false);
}
}
}

0 comments on commit 5bb5f2f

Please sign in to comment.