├── README.md ├── composer.json └── src └── Doctrine └── MySql ├── IndexHint.php └── UseIndexHintHandler.php /README.md: -------------------------------------------------------------------------------- 1 | ## MySQL index hints for Doctrine 2 | 3 | This library provides a simple way to incorporate [MySQL's index hints](https://dev.mysql.com/doc/refman/8.0/en/index-hints.html) 4 | into SELECT queries written in [Doctrine Query Language](https://www.doctrine-project.org/projects/doctrine-orm/en/2.9/reference/dql-doctrine-query-language.html) 5 | via [custom SqlWalker](https://www.doctrine-project.org/projects/doctrine-orm/en/2.9/cookbook/dql-custom-walkers.html#modify-the-output-walker-to-generate-vendor-specific-sql). 6 | No need for native queries anymore. 7 | 8 | ### Installation: 9 | 10 | ```sh 11 | composer require shipmonk/doctrine-mysql-index-hints 12 | ``` 13 | 14 | ### Simple usage: 15 | 16 | ```php 17 | $result = $em->createQueryBuilder() 18 | ->select('u.id') 19 | ->from(User::class, 'u') 20 | ->andWhere('u.id = 1') 21 | ->getQuery() 22 | ->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, HintDrivenSqlWalker::class) 23 | ->setHint(UseIndexHintHandler::class, [IndexHint::force(User::IDX_FOO, User::TABLE_NAME)]) 24 | ->getResult(); 25 | ``` 26 | 27 | Which produces following SQL: 28 | 29 | ```mysql 30 | SELECT u0_.id AS id_0 31 | FROM user u0_ FORCE INDEX (IDX_FOO) 32 | WHERE u0_.id = 1 33 | ``` 34 | 35 | See the used entity (it makes sense to put table names and index names into public constants to bind it together and reference it easily): 36 | 37 | ```php 38 | #[ORM\Table(name: self::TABLE_NAME)] 39 | #[ORM\Index(name: self::IDX_FOO, columns: ['id'])] 40 | #[ORM\Entity] 41 | class User 42 | { 43 | public const TABLE_NAME = 'user'; 44 | public const IDX_FOO = 'IDX_FOO'; 45 | 46 | // ... 47 | } 48 | ``` 49 | 50 | ### Combining multiple hints: 51 | 52 | You might need to give MySQL a list of possible indexes or hint it not to use some indices. 53 | As you can see, hinting joined tables is equally simple. 54 | 55 | ```php 56 | ->from(User::class, 'u') 57 | ->join('u.account', 'a') 58 | ->getQuery() 59 | ->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, HintDrivenSqlWalker::class) 60 | ->setHint(UseIndexHintHandler::class, [ 61 | IndexHint::use(Account::IDX_1, Account::TABLE_NAME), 62 | IndexHint::use(Account::IDX_2, Account::TABLE_NAME), 63 | IndexHint::ignore(Account::IDX_3, Account::TABLE_NAME), 64 | IndexHint::ignore(Account::IDX_4, Account::TABLE_NAME), 65 | ]) 66 | ``` 67 | 68 | Produces this SQL: 69 | 70 | ```mysql 71 | FROM user u0_ 72 | JOIN account a1_ IGNORE INDEX (IDX_3, IDX_4) USE INDEX (IDX_1, IDX_2) ON (...) 73 | ``` 74 | 75 | ### Hinting table joined multiple times: 76 | 77 | You might need to hint only specific join of certain table. Just add which DQL alias specifies it as third argument. 78 | 79 | ```php 80 | ->from(User::class, 'u') 81 | ->join('u.account', 'a1') 82 | ->join('u.anotherAccount', 'a2') 83 | ->getQuery() 84 | ->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, HintDrivenSqlWalker::class) 85 | ->setHint(UseIndexHintHandler::class, [ 86 | IndexHint::use(Account::IDX_1, Account::TABLE_NAME, 'a1'), // alias needed 87 | ]) 88 | ``` 89 | 90 | Produces this SQL: 91 | 92 | ```mysql 93 | FROM user u0_ 94 | JOIN account a1_ USE INDEX (IDX_1) ON (...) 95 | JOIN account a2_ ON (...) 96 | ``` 97 | 98 | ### Advanced usage notes 99 | - Subselects are also supported 100 | - It works even for tables that are not present in the DQL, but are present in SQL! 101 | - For example parent table from [class table inheritance](https://www.doctrine-project.org/projects/doctrine-orm/en/2.9/reference/inheritance-mapping.html#class-table-inheritance) when selecting children 102 | - Any invalid usage is checked in runtime 103 | - Table name existence is checked, so you just cannot swap `tableName` and `indexName` parameters by accident or use non-existing DQL alias 104 | - Forgotten hint or invalid arguments are also checked 105 | - Since those checks cannot be caught by any static analysis tool, it is recommended to have a test for every query 106 | 107 | ### Combining with optimizer hints: 108 | 109 | Since 3.0.0, you can combine this library with [shipmonk/doctrine-mysql-optimizer-hints](https://github.com/shipmonk-rnd/doctrine-mysql-optimizer-hints): 110 | 111 | ```php 112 | $result = $em->createQueryBuilder() 113 | ->select('u.id') 114 | ->from(User::class, 'u') 115 | ->andWhere('u.id = 1') 116 | ->getQuery() 117 | ->setHint(Query::HINT_CUSTOM_OUTPUT_WALKER, HintDrivenSqlWalker::class) 118 | ->setHint(OptimizerHintsHintHandler::class, ['MAX_EXECUTION_TIME(1000)']) 119 | ->setHint(UseIndexHintHandler::class, [IndexHint::force(User::IDX_FOO, User::TABLE_NAME)]) 120 | ->getResult(); 121 | ``` 122 | 123 | -------------------------------------------------------------------------------- /composer.json: -------------------------------------------------------------------------------- 1 | { 2 | "name": "shipmonk/doctrine-mysql-index-hints", 3 | "description": "Custom SQL walker for Doctrine allowing usage of MySQL index hints without need of native queries", 4 | "license": [ 5 | "MIT" 6 | ], 7 | "require": { 8 | "php": "^8.1", 9 | "doctrine/orm": "^3.0.0", 10 | "shipmonk/doctrine-hint-driven-sql-walker": "^2.0.0" 11 | }, 12 | "require-dev": { 13 | "doctrine/collections": "^2.1", 14 | "doctrine/dbal": "^3.7", 15 | "doctrine/event-manager": "^2.0", 16 | "editorconfig-checker/editorconfig-checker": "^10.7.0", 17 | "ergebnis/composer-normalize": "^2.47.0", 18 | "phpstan/phpstan": "^2.1.16", 19 | "phpstan/phpstan-phpunit": "^2.0.6", 20 | "phpstan/phpstan-strict-rules": "^2.0.4", 21 | "phpunit/phpunit": "^10.5.46", 22 | "shipmonk/composer-dependency-analyser": "^1.8.3", 23 | "shipmonk/dead-code-detector": "^0.12.1", 24 | "shipmonk/phpstan-rules": "^4.1.3", 25 | "slevomat/coding-standard": "^8.15.0" 26 | }, 27 | "autoload": { 28 | "psr-4": { 29 | "ShipMonk\\": "src/" 30 | } 31 | }, 32 | "autoload-dev": { 33 | "psr-4": { 34 | "ShipMonk\\": "tests/" 35 | } 36 | }, 37 | "config": { 38 | "allow-plugins": { 39 | "dealerdirect/phpcodesniffer-composer-installer": false, 40 | "ergebnis/composer-normalize": true, 41 | "ocramius/package-versions": false 42 | }, 43 | "sort-packages": true 44 | }, 45 | "scripts": { 46 | "check": [ 47 | "@check:composer", 48 | "@check:ec", 49 | "@check:cs", 50 | "@check:types", 51 | "@check:tests", 52 | "@check:dependencies" 53 | ], 54 | "check:composer": "composer normalize --dry-run --no-check-lock --no-update-lock", 55 | "check:cs": "phpcs", 56 | "check:dependencies": [ 57 | "composer dump-autoload --classmap-authoritative", 58 | "composer-dependency-analyser" 59 | ], 60 | "check:ec": "ec src tests", 61 | "check:tests": "phpunit tests", 62 | "check:types": "phpstan analyse -vvv", 63 | "fix:cs": "phpcbf" 64 | } 65 | } 66 | -------------------------------------------------------------------------------- /src/Doctrine/MySql/IndexHint.php: -------------------------------------------------------------------------------- 1 | type = $type; 19 | $this->indexName = $indexName; 20 | $this->tableName = $tableName; 21 | $this->dqlAlias = $dqlAlias; 22 | } 23 | 24 | public static function use(string $indexName, string $tableName, ?string $dqlAlias = null): self 25 | { 26 | return new self('USE', $indexName, $tableName, $dqlAlias); 27 | } 28 | 29 | public static function force(string $indexName, string $tableName, ?string $dqlAlias = null): self 30 | { 31 | return new self('FORCE', $indexName, $tableName, $dqlAlias); 32 | } 33 | 34 | public static function ignore(string $indexName, string $tableName, ?string $dqlAlias = null): self 35 | { 36 | return new self('IGNORE', $indexName, $tableName, $dqlAlias); 37 | } 38 | 39 | public function getType(): string 40 | { 41 | return $this->type; 42 | } 43 | 44 | public function getIndexName(): string 45 | { 46 | return $this->indexName; 47 | } 48 | 49 | public function getTableName(): string 50 | { 51 | return $this->tableName; 52 | } 53 | 54 | public function getDqlAlias(): ?string 55 | { 56 | return $this->dqlAlias; 57 | } 58 | 59 | } 60 | -------------------------------------------------------------------------------- /src/Doctrine/MySql/UseIndexHintHandler.php: -------------------------------------------------------------------------------- 1 | 26 | */ 27 | public function getNodes(): array 28 | { 29 | return [SqlNode::SelectStatement, SqlNode::UpdateStatement, SqlNode::DeleteStatement]; 30 | } 31 | 32 | public function processNode(SqlNode $sqlNode, string $sql): string 33 | { 34 | $selfClass = static::class; 35 | $sqlWalker = $this->getDoctrineSqlWalker(); 36 | $query = $sqlWalker->getQuery(); 37 | $platform = $query->getEntityManager()->getConnection()->getDatabasePlatform(); 38 | 39 | if (!is_a($platform, 'Doctrine\DBAL\Platforms\AbstractMySQLPlatform')) { 40 | throw new LogicException(sprintf('Only MySQL platform is supported, %s given', $platform::class)); 41 | } 42 | 43 | if (!$query->getAST() instanceof SelectStatement) { 44 | throw new LogicException("Only SELECT queries are currently supported by {$selfClass}"); 45 | } 46 | 47 | $hints = $this->getHintValue(); 48 | 49 | if (!is_array($hints)) { 50 | $type = is_object($hints) ? $hints::class : gettype($hints); 51 | throw new LogicException("Unexpected hint, expecting array of IndexHint objects, {$type} given"); 52 | } 53 | 54 | /** @var array> $replacements */ 55 | $replacements = []; 56 | 57 | foreach ($hints as $index => $hint) { 58 | if (!$hint instanceof IndexHint) { 59 | $type = is_object($hint) ? $hint::class : gettype($hint); 60 | throw new LogicException("Unexpected hint, expecting array of IndexHint objects, element #{$index} is {$type}"); 61 | } 62 | 63 | $delimiter = '~'; 64 | $tableName = preg_quote($hint->getTableName(), $delimiter); 65 | $tableAlias = $hint->getDqlAlias() !== null 66 | ? preg_quote($sqlWalker->getSQLTableAlias($hint->getTableName(), $hint->getDqlAlias()), $delimiter) 67 | : '\S+'; // doctrine always adds some alias 68 | $tableWithAliasRegex = "{$delimiter}{$tableName}\s+{$tableAlias}{$delimiter}i"; 69 | 70 | if (preg_match($tableWithAliasRegex, $sql) === 0) { 71 | $aliasInfo = $hint->getDqlAlias() !== null ? " with DQL alias {$hint->getDqlAlias()}" : ''; 72 | throw new LogicException("Invalid hint for index {$hint->getIndexName()}, table {$tableName}{$aliasInfo} is not present in the query."); 73 | } 74 | 75 | if ($hint->getDqlAlias() === null && preg_match_all($tableWithAliasRegex, $sql) !== 1) { 76 | throw new LogicException("Invalid hint for index {$hint->getIndexName()}, table {$tableName} is present multiple times in the query, please specify DQL alias to apply index on a proper place."); 77 | } 78 | 79 | $replacements[$tableWithAliasRegex][$hint->getType()][] = $hint->getIndexName(); 80 | } 81 | 82 | foreach ($replacements as $tableRegex => $indexHints) { 83 | foreach ($indexHints as $indexType => $indexNames) { 84 | $indexList = implode(', ', $indexNames); 85 | $sqlWithIndexHints = preg_replace($tableRegex, "\\0 {$indexType} INDEX ({$indexList})", $sql); 86 | 87 | if ($sqlWithIndexHints === null) { 88 | throw new LogicException('Regex replace failure: ' . preg_last_error()); 89 | } 90 | 91 | $sql = $sqlWithIndexHints; 92 | } 93 | } 94 | 95 | return $sql; 96 | } 97 | 98 | } 99 | --------------------------------------------------------------------------------