diff --git a/src/DataTables/Adapters/TwoStepORMAdapater.php b/src/DataTables/Adapters/TwoStepORMAdapater.php new file mode 100644 index 00000000..39260cc9 --- /dev/null +++ b/src/DataTables/Adapters/TwoStepORMAdapater.php @@ -0,0 +1,182 @@ +. + */ + +declare(strict_types=1); + + +namespace App\DataTables\Adapters; + +use Doctrine\ORM\AbstractQuery; +use Doctrine\ORM\Query; +use Doctrine\ORM\Query\Expr\Select; +use Doctrine\ORM\Query\ResultSetMapping; +use Doctrine\ORM\QueryBuilder; +use Doctrine\ORM\Tools\Pagination\CountOutputWalker; +use Doctrine\ORM\Tools\Pagination\Paginator; +use Omines\DataTablesBundle\Adapter\AdapterQuery; +use Omines\DataTablesBundle\Adapter\Doctrine\Event\ORMAdapterQueryEvent; +use Omines\DataTablesBundle\Adapter\Doctrine\ORMAdapter; +use Omines\DataTablesBundle\Adapter\Doctrine\ORMAdapterEvents; +use Omines\DataTablesBundle\Column\AbstractColumn; +use Symfony\Component\OptionsResolver\Options; +use Symfony\Component\OptionsResolver\OptionsResolver; + +/** + * This adapter fetches entities from the database in two steps: + * In the first step, it uses a simple query (filter_query option), which returns only the ids of the main entity, + * to get the count of results, doing filtering and pagination. + * + * In the next step the IDs are passed to the detail_query callback option, which then can do a more complex queries (like fetch join) + * to get the entities and related stuff in an efficient way. + * This way we save the overhead of the fetch join query for the count and counting, which can be very slow, cause + * no indexes can be used. + */ +class TwoStepORMAdapater extends ORMAdapter +{ + private \Closure $detailQueryCallable; + + private bool $use_simple_total; + + protected function configureOptions(OptionsResolver $resolver): void + { + parent::configureOptions($resolver); + + $resolver->setRequired('filter_query'); + $resolver->setDefault('query', function (Options $options) { + return $options['filter_query']; + }); + + $resolver->setRequired('detail_query'); + $resolver->setAllowedTypes('detail_query', \Closure::class); + + /* + * Add the possibility to replace the query for total entity count through a very simple one, to improve performance. + * You can only use this option, if you did not apply any criteria to your total count. + */ + $resolver->setDefault('simple_total_query', false); + + } + + protected function afterConfiguration(array $options): void + { + parent::afterConfiguration($options); + $this->detailQueryCallable = $options['detail_query']; + $this->use_simple_total = $options['simple_total_query']; + } + + protected function prepareQuery(AdapterQuery $query): void + { + //Like the parent class, but we add the possibility to use the simple total query + + $state = $query->getState(); + $query->set('qb', $builder = $this->createQueryBuilder($state)); + $query->set('rootAlias', $rootAlias = $builder->getDQLPart('from')[0]->getAlias()); + + // Provide default field mappings if needed + foreach ($state->getDataTable()->getColumns() as $column) { + if (null === $column->getField() && isset($this->metadata->fieldMappings[$name = $column->getName()])) { + $column->setOption('field', "{$rootAlias}.{$name}"); + } + } + + /** @var Query\Expr\From $fromClause */ + $fromClause = $builder->getDQLPart('from')[0]; + $identifier = "{$fromClause->getAlias()}.{$this->metadata->getSingleIdentifierFieldName()}"; + + // Use simpler (faster) total count query if the user wanted so... + if ($this->use_simple_total) { + $query->setTotalRows($this->getSimpleTotalCount($builder)); + } else { + $query->setTotalRows($this->getCount($builder, $identifier)); + } + + // Get record count after filtering + $this->buildCriteria($builder, $state); + $query->setFilteredRows($this->getCount($builder, $identifier)); + + // Perform mapping of all referred fields and implied fields + $aliases = $this->getAliases($query); + $query->set('aliases', $aliases); + $query->setIdentifierPropertyPath($this->mapFieldToPropertyPath($identifier, $aliases)); + } + + protected function getCount(QueryBuilder $queryBuilder, $identifier): int + { + //Check if the queryBuilder is having a HAVING clause, which would make the count query invalid + if (empty($queryBuilder->getDQLPart('having'))) { + //If not, we can use the simple count query + return parent::getCount($queryBuilder, $identifier); + } + + //Otherwise Use the paginator, which uses a subquery to get the right count even with HAVING clauses + return (new Paginator($queryBuilder, false))->count(); + } + + protected function getResults(AdapterQuery $query): \Traversable + { + //Very similar to the parent class + /** @var QueryBuilder $builder */ + $builder = $query->get('qb'); + $state = $query->getState(); + + // Apply definitive view state for current 'page' of the table + foreach ($state->getOrderBy() as list($column, $direction)) { + /** @var AbstractColumn $column */ + if ($column->isOrderable()) { + $builder->addOrderBy($column->getOrderField(), $direction); + } + } + if (null !== $state->getLength()) { + $builder + ->setFirstResult($state->getStart()) + ->setMaxResults($state->getLength()) + ; + } + + $id_query = $builder->getQuery(); + $event = new ORMAdapterQueryEvent($id_query); + $state->getDataTable()->getEventDispatcher()->dispatch($event, ORMAdapterEvents::PRE_QUERY); + + //In the first step we only get the ids of the main entity... + $ids = $id_query->getArrayResult(); + + //Which is then passed to the detailQuery, which filters for the entities based on the IDs + $detail_qb = $this->manager->createQueryBuilder(); + $this->detailQueryCallable->__invoke($detail_qb, $ids); + + $detail_query = $detail_qb->getQuery(); + + //We pass the results of the detail query to the datatable for view rendering + foreach ($detail_query->getResult() as $item) { + yield $item; + } + } + + protected function getSimpleTotalCount(QueryBuilder $queryBuilder): int + { + /** The paginator count queries can be rather slow, so when query for total count (100ms or longer), + * just return the entity count. + */ + /** @var Query\Expr\From $from_expr */ + $from_expr = $queryBuilder->getDQLPart('from')[0]; + + return $this->manager->getRepository($from_expr->getFrom())->count([]); + } +} \ No newline at end of file diff --git a/src/DataTables/Filters/Constraints/Part/LessThanDesiredConstraint.php b/src/DataTables/Filters/Constraints/Part/LessThanDesiredConstraint.php index 3bdd7cf8..eed37b8b 100644 --- a/src/DataTables/Filters/Constraints/Part/LessThanDesiredConstraint.php +++ b/src/DataTables/Filters/Constraints/Part/LessThanDesiredConstraint.php @@ -41,9 +41,9 @@ class LessThanDesiredConstraint extends BooleanConstraint //If value is true, we want to filter for parts with stock < desired stock if ($this->value) { - $queryBuilder->andHaving('amountSum < part.minamount'); + $queryBuilder->andHaving('amountSum < minamount'); } else { - $queryBuilder->andHaving('amountSum >= part.minamount'); + $queryBuilder->andHaving('amountSum >= minamount'); } } } diff --git a/src/DataTables/PartsDataTable.php b/src/DataTables/PartsDataTable.php index fcbe4982..18eee1b5 100644 --- a/src/DataTables/PartsDataTable.php +++ b/src/DataTables/PartsDataTable.php @@ -23,11 +23,13 @@ declare(strict_types=1); namespace App\DataTables; use App\DataTables\Adapters\FetchResultsAtOnceORMAdapter; +use App\DataTables\Adapters\TwoStepORMAdapater; use App\DataTables\Column\EnumColumn; use App\Entity\Parts\ManufacturingStatus; use Doctrine\ORM\Mapping\ClassMetadata; use Doctrine\ORM\Mapping\ClassMetadataInfo; use Doctrine\ORM\Query; +use Doctrine\ORM\Tools\Pagination\Paginator; use Omines\DataTablesBundle\Adapter\Doctrine\Event\ORMAdapterQueryEvent; use Omines\DataTablesBundle\Adapter\Doctrine\ORMAdapterEvents; use Symfony\Bundle\SecurityBundle\Security; @@ -269,10 +271,9 @@ final class PartsDataTable implements DataTableTypeInterface ]) ->addOrderBy('name') - ->createAdapter(FetchResultsAtOnceORMAdapter::class, [ - 'query' => function (QueryBuilder $builder): void { - $this->getQuery($builder); - }, + ->createAdapter(TwoStepORMAdapater::class, [ + 'filter_query' => $this->getFilterQuery(...), + 'detail_query' => $this->getDetailQuery(...), 'entity' => Part::class, 'hydrate' => Query::HYDRATE_OBJECT, 'criteria' => [ @@ -282,38 +283,18 @@ final class PartsDataTable implements DataTableTypeInterface new SearchCriteriaProvider(), ], ]); - - $dataTable->addEventListener(ORMAdapterEvents::PRE_QUERY, $this->preQueryEventHandler(...)); } - private function preQueryEventHandler(ORMAdapterQueryEvent $event): void - { - $query = $event->getQuery(); - //Eager fetch the associations of the part entity (we can only fetch toOne associations that way) - $query->setFetchMode(Part::class, 'category', ClassMetadataInfo::FETCH_EAGER); - $query->setFetchMode(Part::class, 'footprint', ClassMetadata::FETCH_EAGER); - $query->setFetchMode(Part::class, 'manufacturer', ClassMetadata::FETCH_EAGER); - $query->setFetchMode(Part::class, 'partUnit', ClassMetadata::FETCH_EAGER); - $query->setFetchMode(Part::class, 'master_picture_attachment', ClassMetadata::FETCH_EAGER); - } - - private function getQuery(QueryBuilder $builder): void + private function getFilterQuery(QueryBuilder $builder): void { - //Distinct is very slow here, do not add this here (also I think this is not needed here, as the id column is always distinct) + /* In the filter query we only select the IDs. The fetching of the full entities is done in the detail query. + * We only need to join the entities here, so we can filter by them. + * The filter conditions are added to this QB in the buildCriteria method. + */ $builder - //->distinct() - ->select('part') - /*->addSelect('category') - ->addSelect('footprint') - ->addSelect('manufacturer') - ->addSelect('partUnit') - ->addSelect('master_picture_attachment') - ->addSelect('footprint_attachment') - ->addSelect('partLots') - ->addSelect('orderdetails') - ->addSelect('attachments') - ->addSelect('storelocations')*/ + ->select('part.id') + ->addSelect('part.minamount AS HIDDEN minamount') //Calculate amount sum using a subquery, so we can filter and sort by it ->addSelect( '( @@ -338,10 +319,63 @@ final class PartsDataTable implements DataTableTypeInterface ->leftJoin('part.partUnit', 'partUnit') ->leftJoin('part.parameters', 'parameters') - //We have to group by all elements, or only the first sub elements of an association is fetched! (caused issue #190) + //This must be the only group by, or the paginator will not work correctly ->addGroupBy('part.id') - //->addGroupBy('part') - /*->addGroupBy('partLots') + ; + } + + private function getDetailQuery(QueryBuilder $builder, array $ids): void + { + /* + * In this query we take the IDs which were filtered, paginated and sorted in the filter query, and fetch the + * full entities. + * We can do complex fetch joins, as we do not need to filter or sort here (which would kill the performance). + * The only condition should be for the IDs. + * It is important that elements are ordered the same way, as the IDs are passed, or ordering will be wrong. + */ + $builder + ->select('part') + ->addSelect('category') + ->addSelect('footprint') + ->addSelect('manufacturer') + ->addSelect('partUnit') + ->addSelect('master_picture_attachment') + ->addSelect('footprint_attachment') + ->addSelect('partLots') + ->addSelect('orderdetails') + ->addSelect('attachments') + ->addSelect('storelocations') + //Calculate amount sum using a subquery, so we can filter and sort by it + ->addSelect( + '( + SELECT IFNULL(SUM(partLot.amount), 0.0) + FROM '. PartLot::class. ' partLot + WHERE partLot.part = part.id + AND partLot.instock_unknown = false + AND (partLot.expiration_date IS NULL OR partLot.expiration_date > CURRENT_DATE()) + ) AS HIDDEN amountSum' + ) + ->from(Part::class, 'part') + ->leftJoin('part.category', 'category') + ->leftJoin('part.master_picture_attachment', 'master_picture_attachment') + ->leftJoin('part.partLots', 'partLots') + ->leftJoin('partLots.storage_location', 'storelocations') + ->leftJoin('part.footprint', 'footprint') + ->leftJoin('footprint.master_picture_attachment', 'footprint_attachment') + ->leftJoin('part.manufacturer', 'manufacturer') + ->leftJoin('part.orderdetails', 'orderdetails') + ->leftJoin('orderdetails.supplier', 'suppliers') + ->leftJoin('part.attachments', 'attachments') + ->leftJoin('part.partUnit', 'partUnit') + ->leftJoin('part.parameters', 'parameters') + + ->where('part.id IN (:ids)') + ->orderBy('FIELD(part.id, :ids)') + ->setParameter('ids', $ids) + + //We have to group by all elements, or only the first sub elements of an association is fetched! (caused issue #190) + ->addGroupBy('part') + ->addGroupBy('partLots') ->addGroupBy('category') ->addGroupBy('master_picture_attachment') ->addGroupBy('storelocations') @@ -352,7 +386,7 @@ final class PartsDataTable implements DataTableTypeInterface ->addGroupBy('suppliers') ->addGroupBy('attachments') ->addGroupBy('partUnit') - ->addGroupBy('parameters')*/ + ->addGroupBy('parameters') ; }