Add materialized view and repository methods for address search

Introduced a materialized view `view_chill_main_address_reference` to optimize address search queries and added corresponding repository methods `findBySearchString` and `countBySearchString`. Also included test coverage for the repository to validate the new functionality.
This commit is contained in:
Julien Fastré 2025-02-16 22:31:57 +01:00
parent 0a34f9086f
commit 841c547276
Signed by: julienfastre
GPG Key ID: BDE2190974723FCB
3 changed files with 204 additions and 0 deletions

View File

@ -14,8 +14,10 @@ namespace Chill\MainBundle\Repository;
use Chill\MainBundle\Entity\AddressReference;
use Chill\MainBundle\Entity\PostalCode;
use Chill\MainBundle\Search\SearchApiQuery;
use Doctrine\DBAL\Types\Types;
use Doctrine\ORM\EntityManagerInterface;
use Doctrine\ORM\EntityRepository;
use Doctrine\ORM\NativeQuery;
use Doctrine\ORM\Query\ResultSetMapping;
use Doctrine\ORM\Query\ResultSetMappingBuilder;
use Doctrine\Persistence\ObjectRepository;
@ -65,6 +67,85 @@ final readonly class AddressReferenceRepository implements ObjectRepository
return $this->repository->findAll();
}
/**
* @return iterable<AddressReference>
*/
public function findBySearchString(string $search, PostalCode|int|null $postalCode = null, int $firstResult = 0, int $maxResults = 50): iterable
{
$terms = $this->buildTermsFromSearchString($search);
if ([] === $terms) {
return [];
}
$rsm = new ResultSetMappingBuilder($this->entityManager);
$rsm->addRootEntityFromClassMetadata(AddressReference::class, 'ar');
$baseSql = 'SELECT '.$rsm->generateSelectClause(['ar' => 'ar']).' FROM chill_main_address_reference ar JOIN
view_chill_main_address_reference var ON var.address_id = ar.id';
$nql = $this->buildQueryBySearchString($rsm, $baseSql, $terms, $postalCode);
$orderBy = [];
$pertinence = [];
foreach ($terms as $k => $term) {
$pertinence[] =
"(EXISTS (SELECT 1 FROM unnest(string_to_array(address, ' ')) AS t WHERE starts_with(t, UNACCENT(LOWER(:order{$k})))))::int";
$pertinence[] = "(address LIKE UNACCENT(LOWER(:order{$k})))::int";
$nql->setParameter('order'.$k, $term);
}
$orderBy[] = implode(' + ', $pertinence).' ASC';
$orderBy[] = implode('row_number ASC', $orderBy);
$nql->setSQL($nql->getSQL().' ORDER BY '.implode(', ', $orderBy));
return $nql->toIterable();
}
public function countBySearchString(string $search, PostalCode|int|null $postalCode = null): int
{
$terms = $this->buildTermsFromSearchString($search);
if ([] === $terms) {
return 0;
}
$rsm = new ResultSetMappingBuilder($this->entityManager);
$rsm->addScalarResult('c', 'c', Types::INTEGER);
$nql = $this->buildQueryBySearchString($rsm, 'SELECT COUNT(var.*) AS c FROM view_chill_main_address_reference var', $terms, $postalCode);
return $nql->getSingleScalarResult();
}
private function buildTermsFromSearchString(string $search): array
{
return array_filter(
array_map(
static fn (string $term) => trim($term),
explode(' ', $search)
),
static fn (string $term) => '' !== $term
);
}
private function buildQueryBySearchString(ResultSetMapping $rsm, string $select, array $terms, PostalCode|int|null $postalCode = null): NativeQuery
{
$nql = $this->entityManager->createNativeQuery('', $rsm);
$sql = $select.' WHERE ';
$wheres = [];
foreach ($terms as $k => $term) {
$wheres[] = "var.address like :w{$k}";
$nql->setParameter("w{$k}", '%'.$term.'%', Types::STRING);
}
if (null !== $postalCode) {
$wheres[] = 'var.postcode_id = :postalCode';
$nql->setParameter('postalCode', $postalCode instanceof PostalCode ? $postalCode->getId() : $postalCode);
}
$nql->setSQL($sql.implode(' AND ', $wheres));
return $nql;
}
/**
* @param mixed|null $limit
* @param mixed|null $offset

View File

@ -0,0 +1,74 @@
<?php
declare(strict_types=1);
/*
* Chill is a software for social workers
*
* For the full copyright and license information, please view
* the LICENSE file that was distributed with this source code.
*/
namespace Chill\MainBundle\Tests\Repository;
use Chill\MainBundle\Entity\AddressReference;
use Chill\MainBundle\Entity\PostalCode;
use Chill\MainBundle\Repository\AddressReferenceRepository;
use Doctrine\ORM\EntityManagerInterface;
use Symfony\Bundle\FrameworkBundle\Test\KernelTestCase;
/**
* @internal
*
* @coversNothing
*/
class AddressReferenceRepositoryTest extends KernelTestCase
{
private static AddressReferenceRepository $repository;
public static function setUpBeforeClass(): void
{
static::bootKernel();
static::$repository = static::getContainer()->get(AddressReferenceRepository::class);
}
/**
* @dataProvider generateSearchString
*/
public function testFindBySearchString(string $search, int|PostalCode|null $postalCode, string $text, ?array $expected = null): void
{
$actual = static::$repository->findBySearchString($search, $postalCode);
self::assertIsIterable($actual, $text);
if (null !== $expected) {
self::assertEquals($expected, iterator_to_array($actual));
}
}
/**
* @dataProvider generateSearchString
*/
public function testCountBySearchString(string $search, int|PostalCode|null $postalCode, string $text, ?array $expected = null): void
{
$actual = static::$repository->countBySearchString($search, $postalCode);
self::assertIsInt($actual, $text);
}
public static function generateSearchString(): iterable
{
self::bootKernel();
$em = static::getContainer()->get(EntityManagerInterface::class);
/** @var AddressReference $ar */
$ar = $em->createQuery('SELECT ar FROM '.AddressReference::class.' ar')
->setMaxResults(1)
->getSingleResult();
yield ['', null, 'search with empty string', []];
yield [' ', null, 'search with spaces only', []];
yield ['rue des moulins', null, 'search contains an empty string'];
yield ['rue des moulins', $ar->getPostcode()->getId(), 'search with postal code as an id'];
yield ['rue des moulins', $ar->getPostcode(), 'search with postal code instance'];
}
}

View File

@ -0,0 +1,49 @@
<?php
declare(strict_types=1);
/*
* Chill is a software for social workers
*
* For the full copyright and license information, please view
* the LICENSE file that was distributed with this source code.
*/
namespace Chill\Migrations\Main;
use Doctrine\DBAL\Schema\Schema;
use Doctrine\Migrations\AbstractMigration;
final class Version20250214154310 extends AbstractMigration
{
public function getDescription(): string
{
return 'Create view for searching address reference';
}
public function up(Schema $schema): void
{
$this->addSql(<<<'SQL'
create materialized view IF NOT EXISTS view_chill_main_address_reference as
SELECT row_number() OVER () AS row_number,
cmar.id AS address_id,
lower(unaccent(cmar.street || ' '::text || cmar.streetnumber || ' '::text || cmpc.code::text || ' '::text ||
cmpc.label::text)) AS address,
cmpc.id AS postcode_id
FROM chill_main_address_reference cmar
JOIN chill_main_postal_code cmpc ON cmar.postcode_id = cmpc.id
WHERE cmar.deletedat IS NULL
ORDER BY ((cmpc.code::text || ' '::text) || cmpc.label::text), cmar.street, (lpad(cmar.streetnumber, 10, '0'::text));
SQL);
$this->addSql(<<<'SQL'
create index if not exists view_chill_internal_address_reference_trgm
on view_chill_main_address_reference using gist (postcode_id, address public.gist_trgm_ops);
SQL);
}
public function down(Schema $schema): void
{
$this->addSql('DROP MATERIALIZED VIEW view_chill_main_address_reference');
}
}