mirror of
https://gitlab.com/Chill-Projet/chill-bundles.git
synced 2025-06-07 18:44:08 +00:00
125 lines
3.6 KiB
PHP
125 lines
3.6 KiB
PHP
<?php
|
|
|
|
/**
|
|
* 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.
|
|
*/
|
|
|
|
declare(strict_types=1);
|
|
|
|
namespace Chill\MainBundle\Service\Import;
|
|
|
|
use Doctrine\DBAL\Connection;
|
|
use Doctrine\DBAL\Statement;
|
|
use Exception;
|
|
use function array_key_exists;
|
|
use function count;
|
|
|
|
/**
|
|
* Optimized way to load postal code into database.
|
|
*/
|
|
class PostalCodeBaseImporter
|
|
{
|
|
private const QUERY = <<<'SQL'
|
|
WITH g AS (
|
|
SELECT DISTINCT
|
|
country.id AS country_id,
|
|
g.*
|
|
FROM (VALUES
|
|
{{ values }}
|
|
) AS g (countrycode, label, code, refpostalcodeid, postalcodeSource, lon, lat, srid)
|
|
JOIN country ON country.countrycode = g.countrycode
|
|
)
|
|
INSERT INTO chill_main_postal_code (id, country_id, label, code, origin, refpostalcodeid, postalcodeSource, center, createdAt, updatedAt)
|
|
SELECT
|
|
nextval('chill_main_postal_code_id_seq'),
|
|
g.country_id,
|
|
g.label AS glabel,
|
|
g.code,
|
|
0,
|
|
g.refpostalcodeid,
|
|
g.postalcodeSource,
|
|
CASE WHEN (g.lon::float != 0.0 AND g.lat::float != 0.0) THEN ST_Transform(ST_setSrid(ST_point(g.lon::float, g.lat::float), g.srid::int), 4326) ELSE NULL END,
|
|
NOW(),
|
|
NOW()
|
|
FROM g
|
|
ON CONFLICT (code, refpostalcodeid, postalcodeSource) WHERE refpostalcodeid IS NOT NULL DO UPDATE SET label = excluded.label, center = excluded.center, updatedAt = NOW()
|
|
SQL;
|
|
|
|
private const VALUE = '(?, ?, ?, ?, ?, ?, ?, ?)';
|
|
|
|
/**
|
|
* @var array<int, Statement>
|
|
*/
|
|
private array $cachingStatements = [];
|
|
|
|
private Connection $defaultConnection;
|
|
|
|
private array $waitingForInsert = [];
|
|
|
|
public function __construct(
|
|
Connection $defaultConnection
|
|
) {
|
|
$this->defaultConnection = $defaultConnection;
|
|
}
|
|
|
|
public function finalize(): void
|
|
{
|
|
$this->doInsertPending();
|
|
}
|
|
|
|
public function importCode(
|
|
string $countryCode,
|
|
string $label,
|
|
string $code,
|
|
string $refPostalCodeId,
|
|
string $refPostalCodeSource,
|
|
float $centerLat,
|
|
float $centerLon,
|
|
int $centerSRID
|
|
): void {
|
|
$this->waitingForInsert[] = [
|
|
$countryCode,
|
|
$label,
|
|
$code,
|
|
$refPostalCodeId,
|
|
$refPostalCodeSource,
|
|
$centerLon,
|
|
$centerLat,
|
|
$centerSRID,
|
|
];
|
|
|
|
if (100 <= count($this->waitingForInsert)) {
|
|
$this->doInsertPending();
|
|
}
|
|
}
|
|
|
|
private function doInsertPending(): void
|
|
{
|
|
if (!array_key_exists($forNumber = count($this->waitingForInsert), $this->cachingStatements)) {
|
|
$sql = strtr(self::QUERY, [
|
|
'{{ values }}' => implode(
|
|
', ',
|
|
array_fill(0, $forNumber, self::VALUE)
|
|
),
|
|
]);
|
|
|
|
$this->cachingStatements[$forNumber] = $this->defaultConnection->prepare($sql);
|
|
}
|
|
|
|
$statement = $this->cachingStatements[$forNumber];
|
|
|
|
try {
|
|
$statement->executeStatement(array_merge(...$this->waitingForInsert));
|
|
} catch (Exception $e) {
|
|
// in some case, we can add debug code here
|
|
//dump($this->waitingForInsert);
|
|
throw $e;
|
|
} finally {
|
|
$this->waitingForInsert = [];
|
|
}
|
|
}
|
|
}
|