mirror of
https://github.com/Part-DB/Part-DB-server.git
synced 2025-06-21 01:25:55 +02:00
Add database indices to improve performance
This commit is contained in:
parent
9d069149d7
commit
ed91ffc60a
17 changed files with 193 additions and 18 deletions
126
migrations/Version20220925162725.php
Normal file
126
migrations/Version20220925162725.php
Normal file
|
@ -0,0 +1,126 @@
|
|||
<?php
|
||||
|
||||
declare(strict_types=1);
|
||||
|
||||
namespace DoctrineMigrations;
|
||||
|
||||
use App\Migration\AbstractMultiPlatformMigration;
|
||||
use Doctrine\DBAL\Schema\Schema;
|
||||
use Doctrine\Migrations\AbstractMigration;
|
||||
|
||||
/**
|
||||
* Auto-generated Migration: Please modify to your needs!
|
||||
*/
|
||||
final class Version20220925162725 extends AbstractMultiPlatformMigration
|
||||
{
|
||||
public function getDescription(): string
|
||||
{
|
||||
return 'Add indices to improve performance';
|
||||
}
|
||||
|
||||
public function mySQLUp(Schema $schema): void
|
||||
{
|
||||
// this up() migration is auto-generated, please modify it to your needs
|
||||
$this->addSql('ALTER TABLE attachments CHANGE type_id type_id INT NOT NULL');
|
||||
$this->addSql('CREATE INDEX attachments_idx_id_element_id_class_name ON attachments (id, element_id, class_name)');
|
||||
$this->addSql('CREATE INDEX attachments_idx_class_name_id ON attachments (class_name, id)');
|
||||
$this->addSql('CREATE INDEX attachment_name_idx ON attachments (name)');
|
||||
$this->addSql('CREATE INDEX attachment_element_idx ON attachments (class_name, element_id)');
|
||||
$this->addSql('ALTER TABLE categories CHANGE partname_regex partname_regex LONGTEXT NOT NULL, CHANGE partname_hint partname_hint LONGTEXT NOT NULL, CHANGE default_description default_description LONGTEXT NOT NULL, CHANGE default_comment default_comment LONGTEXT NOT NULL');
|
||||
$this->addSql('CREATE INDEX name_idx ON categories (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON categories (parent_id, name)');
|
||||
$this->addSql('ALTER TABLE currencies CHANGE exchange_rate exchange_rate NUMERIC(11, 5) DEFAULT NULL COMMENT \'(DC2Type:big_decimal)\'');
|
||||
$this->addSql('CREATE INDEX name_idx ON currencies (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON currencies (parent_id, name)');
|
||||
$this->addSql('ALTER TABLE device_parts CHANGE mountnames mountnames LONGTEXT NOT NULL');
|
||||
$this->addSql('CREATE INDEX name_idx ON footprints (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON footprints (parent_id, name)');
|
||||
$this->addSql('CREATE INDEX name_idx ON groups (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON groups (parent_id, name)');
|
||||
$this->addSql('ALTER TABLE log CHANGE level level TINYINT(4) NOT NULL');
|
||||
$this->addSql('CREATE INDEX log_idx_type ON log (type)');
|
||||
$this->addSql('CREATE INDEX log_idx_type_target ON log (type, target_type, target_id)');
|
||||
$this->addSql('CREATE INDEX log_idx_datetime ON log (datetime)');
|
||||
$this->addSql('CREATE INDEX name_idx ON manufacturers (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON manufacturers (parent_id, name)');
|
||||
$this->addSql('CREATE INDEX name_idx ON measurement_units (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON measurement_units (parent_id, name)');
|
||||
$this->addSql('CREATE INDEX orderdetails_supplier_part_nr ON orderdetails (supplierpartnr)');
|
||||
$this->addSql('CREATE INDEX parameter_name_idx ON parameters (name)');
|
||||
$this->addSql('CREATE INDEX parameter_group_idx ON parameters (param_group)');
|
||||
$this->addSql('CREATE INDEX parameter_type_element_idx ON parameters (type, element_id)');
|
||||
$this->addSql('CREATE INDEX part_lots_idx_instock_un_expiration_id_part ON part_lots (instock_unknown, expiration_date, id_part)');
|
||||
$this->addSql('CREATE INDEX part_lots_idx_needs_refill ON part_lots (needs_refill)');
|
||||
$this->addSql('ALTER TABLE parts CHANGE description description LONGTEXT NOT NULL, CHANGE comment comment LONGTEXT NOT NULL');
|
||||
$this->addSql('CREATE INDEX parts_idx_datet_name_last_id_needs ON parts (datetime_added, name, last_modified, id, needs_review)');
|
||||
$this->addSql('CREATE INDEX parts_idx_name ON parts (name)');
|
||||
$this->addSql('ALTER TABLE pricedetails CHANGE price price NUMERIC(11, 5) NOT NULL COMMENT \'(DC2Type:big_decimal)\'');
|
||||
$this->addSql('CREATE INDEX pricedetails_idx_min_discount ON pricedetails (min_discount_quantity)');
|
||||
$this->addSql('CREATE INDEX pricedetails_idx_min_discount_price_qty ON pricedetails (min_discount_quantity, price_related_quantity)');
|
||||
$this->addSql('CREATE INDEX name_idx ON storelocations (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON storelocations (parent_id, name)');
|
||||
$this->addSql('ALTER TABLE suppliers CHANGE shipping_costs shipping_costs NUMERIC(11, 5) DEFAULT NULL COMMENT \'(DC2Type:big_decimal)\'');
|
||||
$this->addSql('CREATE INDEX name_idx ON suppliers (name)');
|
||||
$this->addSql('CREATE INDEX parent_name_idx ON suppliers (parent_id, name)');
|
||||
$this->addSql('ALTER TABLE users CHANGE config_instock_comment_w config_instock_comment_w LONGTEXT NOT NULL, CHANGE config_instock_comment_a config_instock_comment_a LONGTEXT NOT NULL');
|
||||
$this->addSql('CREATE INDEX user_idx_username ON users (name)');
|
||||
}
|
||||
|
||||
public function mySQLDown(Schema $schema): void
|
||||
{
|
||||
// this down() migration is auto-generated, please modify it to your needs
|
||||
$this->addSql('DROP INDEX attachments_idx_id_element_id_class_name ON `attachments`');
|
||||
$this->addSql('DROP INDEX attachments_idx_class_name_id ON `attachments`');
|
||||
$this->addSql('DROP INDEX attachment_name_idx ON `attachments`');
|
||||
$this->addSql('DROP INDEX attachment_element_idx ON `attachments`');
|
||||
$this->addSql('ALTER TABLE `attachments` CHANGE type_id type_id INT DEFAULT NULL');
|
||||
$this->addSql('DROP INDEX name_idx ON `categories`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `categories`');
|
||||
$this->addSql('ALTER TABLE `categories` CHANGE partname_hint partname_hint TEXT NOT NULL, CHANGE partname_regex partname_regex TEXT NOT NULL, CHANGE default_description default_description TEXT NOT NULL, CHANGE default_comment default_comment TEXT NOT NULL');
|
||||
$this->addSql('DROP INDEX name_idx ON currencies');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON currencies');
|
||||
$this->addSql('ALTER TABLE currencies CHANGE exchange_rate exchange_rate NUMERIC(11, 5) DEFAULT NULL');
|
||||
$this->addSql('ALTER TABLE `device_parts` CHANGE mountnames mountnames MEDIUMTEXT NOT NULL');
|
||||
$this->addSql('DROP INDEX name_idx ON `footprints`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `footprints`');
|
||||
$this->addSql('DROP INDEX name_idx ON `groups`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `groups`');
|
||||
$this->addSql('DROP INDEX log_idx_type ON log');
|
||||
$this->addSql('DROP INDEX log_idx_type_target ON log');
|
||||
$this->addSql('DROP INDEX log_idx_datetime ON log');
|
||||
$this->addSql('ALTER TABLE log CHANGE level level TINYINT(1) NOT NULL');
|
||||
$this->addSql('DROP INDEX name_idx ON `manufacturers`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `manufacturers`');
|
||||
$this->addSql('DROP INDEX name_idx ON `measurement_units`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `measurement_units`');
|
||||
$this->addSql('DROP INDEX orderdetails_supplier_part_nr ON `orderdetails`');
|
||||
$this->addSql('DROP INDEX parameter_name_idx ON parameters');
|
||||
$this->addSql('DROP INDEX parameter_group_idx ON parameters');
|
||||
$this->addSql('DROP INDEX parameter_type_element_idx ON parameters');
|
||||
$this->addSql('DROP INDEX parts_idx_datet_name_last_id_needs ON `parts`');
|
||||
$this->addSql('DROP INDEX parts_idx_name ON `parts`');
|
||||
$this->addSql('ALTER TABLE `parts` CHANGE description description MEDIUMTEXT NOT NULL, CHANGE comment comment MEDIUMTEXT NOT NULL');
|
||||
$this->addSql('DROP INDEX part_lots_idx_instock_un_expiration_id_part ON part_lots');
|
||||
$this->addSql('DROP INDEX part_lots_idx_needs_refill ON part_lots');
|
||||
$this->addSql('DROP INDEX pricedetails_idx_min_discount ON `pricedetails`');
|
||||
$this->addSql('DROP INDEX pricedetails_idx_min_discount_price_qty ON `pricedetails`');
|
||||
$this->addSql('ALTER TABLE `pricedetails` CHANGE price price NUMERIC(11, 5) NOT NULL');
|
||||
$this->addSql('DROP INDEX name_idx ON `storelocations`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `storelocations`');
|
||||
$this->addSql('DROP INDEX name_idx ON `suppliers`');
|
||||
$this->addSql('DROP INDEX parent_name_idx ON `suppliers`');
|
||||
$this->addSql('ALTER TABLE `suppliers` CHANGE shipping_costs shipping_costs NUMERIC(11, 5) DEFAULT NULL');
|
||||
$this->addSql('DROP INDEX user_idx_username ON `users`');
|
||||
$this->addSql('ALTER TABLE `users` CHANGE config_instock_comment_a config_instock_comment_a TEXT NOT NULL, CHANGE config_instock_comment_w config_instock_comment_w TEXT NOT NULL');
|
||||
}
|
||||
|
||||
public function sqLiteUp(Schema $schema): void
|
||||
{
|
||||
|
||||
}
|
||||
|
||||
public function sqLiteDown(Schema $schema): void
|
||||
{
|
||||
// TODO: Implement sqLiteDown() method.
|
||||
}
|
||||
}
|
|
@ -34,7 +34,12 @@ use LogicException;
|
|||
* Class Attachment.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\AttachmentRepository")
|
||||
* @ORM\Table(name="`attachments`")
|
||||
* @ORM\Table(name="`attachments`", indexes={
|
||||
* @ORM\Index(name="attachments_idx_id_element_id_class_name", columns={"id", "element_id", "class_name"}),
|
||||
* @ORM\Index(name="attachments_idx_class_name_id", columns={"class_name", "id"}),
|
||||
* @ORM\Index(name="attachment_name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="attachment_element_idx", columns={"class_name", "element_id"})
|
||||
* })
|
||||
* @ORM\InheritanceType("SINGLE_TABLE")
|
||||
* @ORM\DiscriminatorColumn(name="class_name", type="string")
|
||||
* @ORM\DiscriminatorMap({
|
||||
|
@ -104,7 +109,7 @@ abstract class Attachment extends AbstractNamedDBElement
|
|||
/**
|
||||
* @var AttachmentType
|
||||
* @ORM\ManyToOne(targetEntity="AttachmentType", inversedBy="attachments_with_type")
|
||||
* @ORM\JoinColumn(name="type_id", referencedColumnName="id")
|
||||
* @ORM\JoinColumn(name="type_id", referencedColumnName="id", nullable=false)
|
||||
* @Selectable()
|
||||
* @Assert\NotNull(message="validator.attachment.must_not_be_null")
|
||||
*/
|
||||
|
|
|
@ -71,7 +71,11 @@ use Psr\Log\LogLevel;
|
|||
* This entity describes a entry in the event log.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\LogEntryRepository")
|
||||
* @ORM\Table("log")
|
||||
* @ORM\Table("log", indexes={
|
||||
* @ORM\Index(name="log_idx_type", columns={"type"}),
|
||||
* @ORM\Index(name="log_idx_type_target", columns={"type", "target_type", "target_id"}),
|
||||
* @ORM\Index(name="log_idx_datetime", columns={"datetime"}),
|
||||
* })
|
||||
* @ORM\InheritanceType("SINGLE_TABLE")
|
||||
* @ORM\DiscriminatorColumn(name="type", type="smallint")
|
||||
* @ORM\DiscriminatorMap({
|
||||
|
|
|
@ -34,7 +34,11 @@ use function sprintf;
|
|||
|
||||
/**
|
||||
* @ORM\Entity(repositoryClass="App\Repository\ParameterRepository")
|
||||
* @ORM\Table("parameters")
|
||||
* @ORM\Table("parameters", indexes={
|
||||
* @ORM\Index(name="parameter_name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parameter_group_idx", columns={"param_group"}),
|
||||
* @ORM\Index(name="parameter_type_element_idx", columns={"type", "element_id"})
|
||||
* })
|
||||
* @ORM\InheritanceType("SINGLE_TABLE")
|
||||
* @ORM\DiscriminatorColumn(name="type", type="smallint")
|
||||
* @ORM\DiscriminatorMap({
|
||||
|
@ -91,7 +95,6 @@ abstract class AbstractParameter extends AbstractNamedDBElement
|
|||
|
||||
/**
|
||||
* @var string The unit in which the value values are given (e.g. V)
|
||||
* @Assert\Length(max=5)
|
||||
* @ORM\Column(type="string", nullable=false)
|
||||
*/
|
||||
protected string $unit = '';
|
||||
|
|
|
@ -33,7 +33,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class AttachmentType.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\CategoryRepository")
|
||||
* @ORM\Table(name="`categories`")
|
||||
* @ORM\Table(name="`categories`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Category extends AbstractPartsContainingDBElement
|
||||
{
|
||||
|
|
|
@ -61,7 +61,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class Footprint.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\FootprintRepository")
|
||||
* @ORM\Table("`footprints`")
|
||||
* @ORM\Table("`footprints`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Footprint extends AbstractPartsContainingDBElement
|
||||
{
|
||||
|
|
|
@ -61,7 +61,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class Manufacturer.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\ManufacturerRepository")
|
||||
* @ORM\Table("`manufacturers`")
|
||||
* @ORM\Table("`manufacturers`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Manufacturer extends AbstractCompany
|
||||
{
|
||||
|
|
|
@ -55,7 +55,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* This could be something like N, grams, meters, etc...
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\MeasurementUnitRepository")
|
||||
* @ORM\Table(name="`measurement_units`")
|
||||
* @ORM\Table(name="`measurement_units`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
* @UniqueEntity("unit")
|
||||
*/
|
||||
class MeasurementUnit extends AbstractPartsContainingDBElement
|
||||
|
|
|
@ -75,7 +75,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Otherwise this class would be too big, to be maintained.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\PartRepository")
|
||||
* @ORM\Table("`parts`")
|
||||
* @ORM\Table("`parts`", indexes={
|
||||
* @ORM\Index(name="parts_idx_datet_name_last_id_needs", columns={"datetime_added", "name", "last_modified", "id", "needs_review"}),
|
||||
* @ORM\Index(name="parts_idx_name", columns={"name"}),
|
||||
* })
|
||||
*/
|
||||
class Part extends AttachmentContainingDBElement
|
||||
{
|
||||
|
|
|
@ -58,7 +58,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* It is the connection between a part and its store locations.
|
||||
*
|
||||
* @ORM\Entity()
|
||||
* @ORM\Table(name="part_lots")
|
||||
* @ORM\Table(name="part_lots", indexes={
|
||||
* @ORM\Index(name="part_lots_idx_instock_un_expiration_id_part", columns={"instock_unknown", "expiration_date", "id_part"}),
|
||||
* @ORM\Index(name="part_lots_idx_needs_refill", columns={"needs_refill"}),
|
||||
* })
|
||||
* @ORM\HasLifecycleCallbacks()
|
||||
* @ValidPartLot()
|
||||
*/
|
||||
|
|
|
@ -61,7 +61,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class Store location.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\StorelocationRepository")
|
||||
* @ORM\Table("`storelocations`")
|
||||
* @ORM\Table("`storelocations`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Storelocation extends AbstractPartsContainingDBElement
|
||||
{
|
||||
|
|
|
@ -65,7 +65,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class Supplier.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\Parts\SupplierRepository")
|
||||
* @ORM\Table("`suppliers`")
|
||||
* @ORM\Table("`suppliers`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Supplier extends AbstractCompany
|
||||
{
|
||||
|
|
|
@ -59,7 +59,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
*
|
||||
* @UniqueEntity("iso_code")
|
||||
* @ORM\Entity()
|
||||
* @ORM\Table(name="currencies")
|
||||
* @ORM\Table(name="currencies", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Currency extends AbstractStructuralDBElement
|
||||
{
|
||||
|
|
|
@ -66,7 +66,9 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
/**
|
||||
* Class Orderdetail.
|
||||
*
|
||||
* @ORM\Table("`orderdetails`")
|
||||
* @ORM\Table("`orderdetails`", indexes={
|
||||
* @ORM\Index(name="orderdetails_supplier_part_nr", columns={"supplierpartnr"}),
|
||||
* })
|
||||
* @ORM\Entity()
|
||||
* @ORM\HasLifecycleCallbacks()
|
||||
* @UniqueEntity({"supplierpartnr", "supplier", "part"})
|
||||
|
|
|
@ -66,7 +66,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Class Pricedetail.
|
||||
*
|
||||
* @ORM\Entity()
|
||||
* @ORM\Table("`pricedetails`")
|
||||
* @ORM\Table("`pricedetails`", indexes={
|
||||
* @ORM\Index(name="pricedetails_idx_min_discount", columns={"min_discount_quantity"}),
|
||||
* @ORM\Index(name="pricedetails_idx_min_discount_price_qty", columns={"min_discount_quantity", "price_related_quantity"}),
|
||||
* })
|
||||
* @ORM\HasLifecycleCallbacks()
|
||||
* @UniqueEntity(fields={"min_discount_quantity", "orderdetail"})
|
||||
*/
|
||||
|
|
|
@ -56,7 +56,10 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* This entity represents an user group.
|
||||
*
|
||||
* @ORM\Entity()
|
||||
* @ORM\Table("`groups`")
|
||||
* @ORM\Table("`groups`", indexes={
|
||||
* @ORM\Index(name="name_idx", columns={"name"}),
|
||||
* @ORM\Index(name="parent_name_idx", columns={"parent_id", "name"}),
|
||||
* })
|
||||
*/
|
||||
class Group extends AbstractStructuralDBElement implements HasPermissionsInterface
|
||||
{
|
||||
|
|
|
@ -80,7 +80,9 @@ use Symfony\Component\Validator\Constraints as Assert;
|
|||
* Also this entity is able to save some informations about the user, like the names, email-address and other info.
|
||||
*
|
||||
* @ORM\Entity(repositoryClass="App\Repository\UserRepository")
|
||||
* @ORM\Table("`users`")
|
||||
* @ORM\Table("`users`", indexes={
|
||||
* @ORM\Index(name="user_idx_username", columns={"name"})
|
||||
* })
|
||||
* @ORM\EntityListeners({"App\EntityListeners\TreeCacheInvalidationListener"})
|
||||
* @UniqueEntity("name", message="validator.user.username_already_used")
|
||||
*/
|
||||
|
|
Loading…
Add table
Add a link
Reference in a new issue