mirror of
https://github.com/wallabag/wallabag.git
synced 2024-12-16 20:56:28 +00:00
Merge pull request #4081 from shtrom/fix-slow-queries
Fix slow/unindexed queries
This commit is contained in:
commit
97c678a0b2
4 changed files with 131 additions and 3 deletions
116
app/DoctrineMigrations/Version20190806130304.php
Normal file
116
app/DoctrineMigrations/Version20190806130304.php
Normal file
|
@ -0,0 +1,116 @@
|
|||
<?php
|
||||
|
||||
namespace Application\Migrations;
|
||||
|
||||
use Doctrine\DBAL\Schema\Schema;
|
||||
use Wallabag\CoreBundle\Doctrine\WallabagMigration;
|
||||
|
||||
/**
|
||||
* Adding more index to kill some slow queries:
|
||||
* - user_language
|
||||
* - user_archived
|
||||
* - user_created
|
||||
* - user_starred
|
||||
* - tag_label
|
||||
* - config_feed_token.
|
||||
*/
|
||||
final class Version20190806130304 extends WallabagMigration
|
||||
{
|
||||
public function up(Schema $schema): void
|
||||
{
|
||||
switch ($this->connection->getDatabasePlatform()->getName()) {
|
||||
case 'sqlite':
|
||||
$this->addSql('DROP INDEX uid');
|
||||
$this->addSql('DROP INDEX created_at');
|
||||
$this->addSql('DROP INDEX hashed_url_user_id');
|
||||
$this->addSql('DROP INDEX IDX_F4D18282A76ED395');
|
||||
$this->addSql('DROP INDEX hashed_given_url_user_id');
|
||||
$this->addSql('CREATE TEMPORARY TABLE __temp__wallabag_entry AS SELECT id, user_id, title, url, is_archived, is_starred, content, created_at, updated_at, mimetype, language, domain_name, preview_picture, uid, http_status, published_at, starred_at, origin_url, archived_at, given_url, reading_time, published_by, headers, hashed_url, hashed_given_url FROM ' . $this->getTable('entry', true));
|
||||
$this->addSql('DROP TABLE ' . $this->getTable('entry', true));
|
||||
$this->addSql('CREATE TABLE ' . $this->getTable('entry', true) . ' (id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, user_id INTEGER DEFAULT NULL, title CLOB DEFAULT NULL COLLATE BINARY, url CLOB DEFAULT NULL COLLATE BINARY, is_archived BOOLEAN NOT NULL, is_starred BOOLEAN NOT NULL, content CLOB DEFAULT NULL COLLATE BINARY, created_at DATETIME NOT NULL, updated_at DATETIME NOT NULL, mimetype CLOB DEFAULT NULL COLLATE BINARY, domain_name CLOB DEFAULT NULL COLLATE BINARY, preview_picture CLOB DEFAULT NULL COLLATE BINARY, uid VARCHAR(23) DEFAULT NULL COLLATE BINARY, http_status VARCHAR(3) DEFAULT NULL COLLATE BINARY, published_at DATETIME DEFAULT NULL, starred_at DATETIME DEFAULT NULL, origin_url CLOB DEFAULT NULL COLLATE BINARY, archived_at DATETIME DEFAULT NULL, given_url CLOB DEFAULT NULL COLLATE BINARY, reading_time INTEGER NOT NULL, published_by CLOB DEFAULT NULL COLLATE BINARY --(DC2Type:array)
|
||||
, headers CLOB DEFAULT NULL COLLATE BINARY --(DC2Type:array)
|
||||
, hashed_url VARCHAR(40) DEFAULT NULL COLLATE BINARY, hashed_given_url VARCHAR(40) DEFAULT NULL COLLATE BINARY, language VARCHAR(20) DEFAULT NULL, CONSTRAINT FK_F4D18282A76ED395 FOREIGN KEY (user_id) REFERENCES "wallabag_user" (id) NOT DEFERRABLE INITIALLY IMMEDIATE)');
|
||||
$this->addSql('INSERT INTO ' . $this->getTable('entry', true) . ' (id, user_id, title, url, is_archived, is_starred, content, created_at, updated_at, mimetype, language, domain_name, preview_picture, uid, http_status, published_at, starred_at, origin_url, archived_at, given_url, reading_time, published_by, headers, hashed_url, hashed_given_url) SELECT id, user_id, title, url, is_archived, is_starred, content, created_at, updated_at, mimetype, language, domain_name, preview_picture, uid, http_status, published_at, starred_at, origin_url, archived_at, given_url, reading_time, published_by, headers, hashed_url, hashed_given_url FROM __temp__wallabag_entry');
|
||||
$this->addSql('DROP TABLE __temp__wallabag_entry');
|
||||
$this->addSql('CREATE INDEX uid ON ' . $this->getTable('entry', true) . ' (uid)');
|
||||
$this->addSql('CREATE INDEX created_at ON ' . $this->getTable('entry', true) . ' (created_at)');
|
||||
$this->addSql('CREATE INDEX hashed_url_user_id ON ' . $this->getTable('entry', true) . ' (user_id, hashed_url)');
|
||||
$this->addSql('CREATE INDEX IDX_F4D18282A76ED395 ON ' . $this->getTable('entry', true) . ' (user_id)');
|
||||
$this->addSql('CREATE INDEX hashed_given_url_user_id ON ' . $this->getTable('entry', true) . ' (user_id, hashed_given_url)');
|
||||
$this->addSql('CREATE INDEX user_language ON ' . $this->getTable('entry', true) . ' (language, user_id)');
|
||||
$this->addSql('CREATE INDEX user_archived ON ' . $this->getTable('entry', true) . ' (user_id, is_archived, archived_at)');
|
||||
$this->addSql('CREATE INDEX user_created ON ' . $this->getTable('entry', true) . ' (user_id, created_at)');
|
||||
$this->addSql('CREATE INDEX user_starred ON ' . $this->getTable('entry', true) . ' (user_id, is_starred, starred_at)');
|
||||
$this->addSql('CREATE INDEX tag_label ON ' . $this->getTable('tag', true) . ' (label)');
|
||||
$this->addSql('CREATE INDEX config_feed_token ON ' . $this->getTable('config', true) . ' (feed_token)');
|
||||
break;
|
||||
case 'mysql':
|
||||
$this->addSql('ALTER TABLE ' . $this->getTable('entry') . ' MODIFY language VARCHAR(20) DEFAULT NULL');
|
||||
$this->addSql('CREATE INDEX user_language ON ' . $this->getTable('entry') . ' (language, user_id)');
|
||||
$this->addSql('CREATE INDEX user_archived ON ' . $this->getTable('entry') . ' (user_id, is_archived, archived_at)');
|
||||
$this->addSql('CREATE INDEX user_created ON ' . $this->getTable('entry') . ' (user_id, created_at)');
|
||||
$this->addSql('CREATE INDEX user_starred ON ' . $this->getTable('entry') . ' (user_id, is_starred, starred_at)');
|
||||
$this->addSql('CREATE INDEX tag_label ON ' . $this->getTable('tag') . ' (label (255))');
|
||||
$this->addSql('CREATE INDEX config_feed_token ON ' . $this->getTable('config') . ' (feed_token (255))');
|
||||
break;
|
||||
case 'postgresql':
|
||||
$this->addSql('ALTER TABLE ' . $this->getTable('entry') . ' ALTER language TYPE VARCHAR(20)');
|
||||
$this->addSql('CREATE INDEX user_language ON ' . $this->getTable('entry') . ' (language, user_id)');
|
||||
$this->addSql('CREATE INDEX user_archived ON ' . $this->getTable('entry') . ' (user_id, is_archived, archived_at)');
|
||||
$this->addSql('CREATE INDEX user_created ON ' . $this->getTable('entry') . ' (user_id, created_at)');
|
||||
$this->addSql('CREATE INDEX user_starred ON ' . $this->getTable('entry') . ' (user_id, is_starred, starred_at)');
|
||||
$this->addSql('CREATE INDEX tag_label ON ' . $this->getTable('tag') . ' (label)');
|
||||
$this->addSql('CREATE INDEX config_feed_token ON ' . $this->getTable('config') . ' (feed_token)');
|
||||
break;
|
||||
}
|
||||
}
|
||||
|
||||
public function down(Schema $schema): void
|
||||
{
|
||||
switch ($this->connection->getDatabasePlatform()->getName()) {
|
||||
case 'sqlite':
|
||||
$this->addSql('DROP INDEX IDX_F4D18282A76ED395');
|
||||
$this->addSql('DROP INDEX created_at');
|
||||
$this->addSql('DROP INDEX uid');
|
||||
$this->addSql('DROP INDEX hashed_url_user_id');
|
||||
$this->addSql('DROP INDEX hashed_given_url_user_id');
|
||||
$this->addSql('DROP INDEX user_language');
|
||||
$this->addSql('DROP INDEX user_archived');
|
||||
$this->addSql('DROP INDEX user_created');
|
||||
$this->addSql('DROP INDEX user_starred');
|
||||
$this->addSql('DROP INDEX tag_label');
|
||||
$this->addSql('DROP INDEX config_feed_token');
|
||||
$this->addSql('CREATE TEMPORARY TABLE __temp__wallabag_entry AS SELECT id, user_id, uid, title, url, hashed_url, origin_url, given_url, hashed_given_url, is_archived, archived_at, is_starred, content, created_at, updated_at, published_at, published_by, starred_at, mimetype, language, reading_time, domain_name, preview_picture, http_status, headers FROM ' . $this->getTable('entry', true));
|
||||
$this->addSql('DROP TABLE ' . $this->getTable('entry', true));
|
||||
$this->addSql('CREATE TABLE ' . $this->getTable('entry', true) . ' (id INTEGER PRIMARY KEY AUTOINCREMENT NOT NULL, user_id INTEGER DEFAULT NULL, uid VARCHAR(23) DEFAULT NULL, title CLOB DEFAULT NULL, url CLOB DEFAULT NULL, hashed_url VARCHAR(40) DEFAULT NULL, origin_url CLOB DEFAULT NULL, given_url CLOB DEFAULT NULL, hashed_given_url VARCHAR(40) DEFAULT NULL, is_archived BOOLEAN NOT NULL, archived_at DATETIME DEFAULT NULL, is_starred BOOLEAN NOT NULL, content CLOB DEFAULT NULL, created_at DATETIME NOT NULL, updated_at DATETIME NOT NULL, published_at DATETIME DEFAULT NULL, published_by CLOB DEFAULT NULL --(DC2Type:array)
|
||||
, starred_at DATETIME DEFAULT NULL, mimetype CLOB DEFAULT NULL, reading_time INTEGER NOT NULL, domain_name CLOB DEFAULT NULL, preview_picture CLOB DEFAULT NULL, http_status VARCHAR(3) DEFAULT NULL, headers CLOB DEFAULT NULL --(DC2Type:array)
|
||||
, language CLOB DEFAULT NULL COLLATE BINARY)');
|
||||
$this->addSql('INSERT INTO ' . $this->getTable('entry', true) . ' (id, user_id, uid, title, url, hashed_url, origin_url, given_url, hashed_given_url, is_archived, archived_at, is_starred, content, created_at, updated_at, published_at, published_by, starred_at, mimetype, language, reading_time, domain_name, preview_picture, http_status, headers) SELECT id, user_id, uid, title, url, hashed_url, origin_url, given_url, hashed_given_url, is_archived, archived_at, is_starred, content, created_at, updated_at, published_at, published_by, starred_at, mimetype, language, reading_time, domain_name, preview_picture, http_status, headers FROM __temp__wallabag_entry');
|
||||
$this->addSql('DROP TABLE __temp__wallabag_entry');
|
||||
$this->addSql('CREATE INDEX IDX_F4D18282A76ED395 ON ' . $this->getTable('entry', true) . ' (user_id)');
|
||||
$this->addSql('CREATE INDEX created_at ON ' . $this->getTable('entry', true) . ' (created_at)');
|
||||
$this->addSql('CREATE INDEX uid ON ' . $this->getTable('entry', true) . ' (uid)');
|
||||
$this->addSql('CREATE INDEX hashed_url_user_id ON ' . $this->getTable('entry', true) . ' (user_id, hashed_url)');
|
||||
$this->addSql('CREATE INDEX hashed_given_url_user_id ON ' . $this->getTable('entry', true) . ' (user_id, hashed_given_url)');
|
||||
break;
|
||||
case 'mysql':
|
||||
$this->addSql('ALTER TABLE ' . $this->getTable('entry') . ' MODIFY language LONGTEXT DEFAULT NULL');
|
||||
$this->addSql('DROP INDEX user_language ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_archived ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_created ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_starred ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX tag_label ON ' . $this->getTable('tag'));
|
||||
$this->addSql('DROP INDEX config_feed_token ON ' . $this->getTable('config'));
|
||||
break;
|
||||
case 'postgresql':
|
||||
$this->addSql('ALTER TABLE ' . $this->getTable('entry') . ' ALTER language TYPE TEXT');
|
||||
$this->addSql('DROP INDEX user_language ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_archived ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_created ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX user_starred ON ' . $this->getTable('entry'));
|
||||
$this->addSql('DROP INDEX tag_label ON ' . $this->getTable('tag'));
|
||||
$this->addSql('DROP INDEX config_feed_token ON ' . $this->getTable('config'));
|
||||
break;
|
||||
}
|
||||
}
|
||||
}
|
|
@ -11,7 +11,12 @@ use Wallabag\UserBundle\Entity\User;
|
|||
* Config.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="Wallabag\CoreBundle\Repository\ConfigRepository")
|
||||
* @ORM\Table(name="`config`")
|
||||
* @ORM\Table(
|
||||
* name="`config`",
|
||||
* indexes={
|
||||
* @ORM\Index(name="config_feed_token", columns={"feed_token"}, options={"lengths"={255}}),
|
||||
* }
|
||||
* )
|
||||
* @ORM\Entity
|
||||
*/
|
||||
class Config
|
||||
|
|
|
@ -28,7 +28,11 @@ use Wallabag\UserBundle\Entity\User;
|
|||
* @ORM\Index(name="created_at", columns={"created_at"}),
|
||||
* @ORM\Index(name="uid", columns={"uid"}),
|
||||
* @ORM\Index(name="hashed_url_user_id", columns={"user_id", "hashed_url"}, options={"lengths"={null, 40}}),
|
||||
* @ORM\Index(name="hashed_given_url_user_id", columns={"user_id", "hashed_given_url"}, options={"lengths"={null, 40}})
|
||||
* @ORM\Index(name="hashed_given_url_user_id", columns={"user_id", "hashed_given_url"}, options={"lengths"={null, 40}}),
|
||||
* @ORM\Index(name="user_language", columns={"language", "user_id"}),
|
||||
* @ORM\Index(name="user_archived", columns={"user_id", "is_archived", "archived_at"}),
|
||||
* @ORM\Index(name="user_created", columns={"user_id", "created_at"}),
|
||||
* @ORM\Index(name="user_starred", columns={"user_id", "is_starred", "starred_at"})
|
||||
* }
|
||||
* )
|
||||
* @ORM\HasLifecycleCallbacks()
|
||||
|
@ -221,7 +225,7 @@ class Entry
|
|||
/**
|
||||
* @var string
|
||||
*
|
||||
* @ORM\Column(name="language", type="text", nullable=true)
|
||||
* @ORM\Column(name="language", type="string", length=20, nullable=true)
|
||||
*
|
||||
* @Groups({"entries_for_user", "export_all"})
|
||||
*/
|
||||
|
|
|
@ -16,6 +16,9 @@ use JMS\Serializer\Annotation\XmlRoot;
|
|||
* @ORM\Table(
|
||||
* name="`tag`",
|
||||
* options={"collate"="utf8mb4_bin", "charset"="utf8mb4"},
|
||||
* indexes={
|
||||
* @ORM\Index(name="tag_label", columns={"label"}, options={"lengths"={255}}),
|
||||
* }
|
||||
* )
|
||||
* @ORM\Entity(repositoryClass="Wallabag\CoreBundle\Repository\TagRepository")
|
||||
* @ExclusionPolicy("all")
|
||||
|
|
Loading…
Reference in a new issue