diff --git a/src/Bundle/ChillMainBundle/Entity/GeographicalUnit.php b/src/Bundle/ChillMainBundle/Entity/GeographicalUnit.php index fac5d9127..45a7fc54e 100644 --- a/src/Bundle/ChillMainBundle/Entity/GeographicalUnit.php +++ b/src/Bundle/ChillMainBundle/Entity/GeographicalUnit.php @@ -14,7 +14,9 @@ namespace Chill\MainBundle\Entity; use Doctrine\ORM\Mapping as ORM; /** - * @ORM\Table(name="chill_main_geographical_unit") + * @ORM\Table(name="chill_main_geographical_unit", uniqueConstraints={ + * @ORM\UniqueConstraint(name="geographical_unit_refid", columns={"unitRefId"}) + * }) * @ORM\Entity(readOnly=true) */ class GeographicalUnit diff --git a/src/Bundle/ChillMainBundle/Entity/GeographicalUnitLayer.php b/src/Bundle/ChillMainBundle/Entity/GeographicalUnitLayer.php index 76ac06e9c..54bde03ec 100644 --- a/src/Bundle/ChillMainBundle/Entity/GeographicalUnitLayer.php +++ b/src/Bundle/ChillMainBundle/Entity/GeographicalUnitLayer.php @@ -5,12 +5,13 @@ namespace Chill\MainBundle\Entity; use Doctrine\ORM\Mapping as ORM; /** - * @ORM\Table(name="chill_main_geographical_unit_layer") + * @ORM\Table(name="chill_main_geographical_unit_layer", uniqueConstraints={ + * @ORM\UniqueConstraint(name="geographical_unit_layer_refid", columns={"refId"}) + * }) * @ORM\Entity */ class GeographicalUnitLayer { - /** * @ORM\Id * @ORM\GeneratedValue diff --git a/src/Bundle/ChillMainBundle/Service/Import/GeographicalUnitBaseImporter.php b/src/Bundle/ChillMainBundle/Service/Import/GeographicalUnitBaseImporter.php new file mode 100644 index 000000000..9df865a28 --- /dev/null +++ b/src/Bundle/ChillMainBundle/Service/Import/GeographicalUnitBaseImporter.php @@ -0,0 +1,234 @@ + + */ + private array $cachingStatements = []; + + private Connection $defaultConnection; + + private bool $isInitialized = false; + + private LoggerInterface $logger; + + private array $waitingForInsert = []; + + public function __construct(Connection $defaultConnection, LoggerInterface $logger) + { + $this->defaultConnection = $defaultConnection; + $this->logger = $logger; + } + + public function finalize(): void + { + $this->doInsertPending(); + + $this->prepareForFinalize(); + + $this->updateGeographicalUnitTable(); + + $this->deleteTemporaryTable(); + + $this->isInitialized = false; + } + + public function importUnit( + string $layerKey, + array $layerName, + string $unitName, + string $unitKey, + string $geomAsWKT, + int $srid = null + ): void { + $this->initialize(); + + $this->waitingForInsert[] = [ + 'layerKey' => $layerKey, + 'layerName' => $layerName, + 'unitName' => $unitName, + 'unitKey' => $unitKey, + 'geomAsWKT' => $geomAsWKT, + 'srid' => $srid + ]; + + if (100 <= count($this->waitingForInsert)) { + $this->doInsertPending(); + } + } + + private function createTemporaryTable(): void + { + $this->defaultConnection->executeStatement("CREATE TEMPORARY TABLE geographical_unit_temp ( + layerKey TEXT DEFAULT '' NOT NULL, + layerName JSONB DEFAULT '[]'::jsonb NOT NULL, + unitName TEXT default '' NOT NULL, + unitKey TEXT default '' NOT NULL, + geom GEOMETRY(MULTIPOLYGON, 4326) + )"); + + $this->defaultConnection->executeStatement('SET work_mem TO \'50MB\''); + } + + private function deleteTemporaryTable(): void + { + $this->defaultConnection->executeStatement('DROP TABLE IF EXISTS geographical_unit_temp'); + } + + private function doInsertPending(): void + { + $forNumber = count($this->waitingForInsert); + + if (0 === $forNumber) { + return; + } + + if (!array_key_exists($forNumber, $this->cachingStatements)) { + $sql = strtr(self::INSERT, [ + '{{ values }}' => implode( + ', ', + array_fill(0, $forNumber, self::VALUE) + ), + ]); + + $this->logger->debug(self::LOG_PREFIX . ' generated sql for insert', [ + 'sql' => $sql, + 'forNumber' => $forNumber, + ]); + + $this->cachingStatements[$forNumber] = $this->defaultConnection->prepare($sql); + } + + $this->logger->debug(self::LOG_PREFIX . ' inserting pending addresses', [ + 'number' => $forNumber, + 'first' => $this->waitingForInsert[0] ?? null, + ]); + + $statement = $this->cachingStatements[$forNumber]; + try { + $i = 0; + foreach ($this->waitingForInsert as $insert) { + $statement->bindValue(++$i, $insert['layerKey'], Types::STRING); + $statement->bindValue(++$i, $insert['layerName'], Types::JSON); + $statement->bindValue(++$i, $insert['unitName'], Types::STRING); + $statement->bindValue(++$i, $insert['unitKey'], Types::STRING); + $statement->bindValue(++$i, $insert['geomAsWKT'], Types::STRING); + $statement->bindValue(++$i, $insert['srid'], Types::INTEGER); + } + + $affected = $statement->executeStatement(); + + if ($affected === 0) { + throw new \RuntimeException('no row affected'); + } + } catch (Exception $e) { + throw $e; + } finally { + $this->waitingForInsert = []; + } + } + + private function initialize(): void + { + if ($this->isInitialized) { + return; + } + + $this->deleteTemporaryTable(); + $this->createTemporaryTable(); + $this->isInitialized = true; + } + + private function prepareForFinalize(): void + { + $this->defaultConnection->executeStatement( + 'CREATE INDEX idx_ref_add_temp ON geographical_unit_temp (unitKey)' + ); + } + + private function updateGeographicalUnitTable(): void + { + $this->defaultConnection->transactional( + function() { + // 0) create new layers + $this->defaultConnection->executeStatement( + " + WITH unique_layers AS ( + SELECT DISTINCT layerKey, layerName FROM geographical_unit_temp + ) + INSERT INTO chill_main_geographical_unit_layer (id, name, refid) + SELECT + nextval('chill_main_geographical_unit_layer_id_seq'), + layerName, + layerKey + FROM unique_layers + ON CONFLICT (refid) + DO UPDATE SET name=EXCLUDED.name + "); + + //1) Add new units + $this->logger->info(self::LOG_PREFIX . 'upsert new units'); + $affected = $this->defaultConnection->executeStatement("INSERT INTO chill_main_geographical_unit + (id, geom, unitname, layer_id, unitrefid) + SELECT + nextval('chill_main_geographical_unit_id_seq'), + geom, + unitName, + layer.id, + unitKey + FROM geographical_unit_temp JOIN chill_main_geographical_unit_layer AS layer ON layer.refid = layerKey + ON CONFLICT (unitrefid) + DO UPDATE + SET geom = EXCLUDED.geom, unitname = EXCLUDED.unitname + "); + $this->logger->info(self::LOG_PREFIX . 'units upserted', ['upserted' => $affected]); + + //3) Delete units + $this->logger->info(self::LOG_PREFIX . 'soft delete adresses'); + $affected = $this->defaultConnection->executeStatement('DELETE FROM chill_main_geographical_unit + WHERE + unitrefid NOT IN (SELECT distinct unitKey FROM geographical_unit_temp) + '); + $this->logger->info(self::LOG_PREFIX . 'addresses deleted', ['deleted' => $affected]); + } + ); + } +} diff --git a/src/Bundle/ChillMainBundle/Tests/Services/Import/GeographicalUnitBaseImporterTest.php b/src/Bundle/ChillMainBundle/Tests/Services/Import/GeographicalUnitBaseImporterTest.php new file mode 100644 index 000000000..bc66c3691 --- /dev/null +++ b/src/Bundle/ChillMainBundle/Tests/Services/Import/GeographicalUnitBaseImporterTest.php @@ -0,0 +1,89 @@ +connection = self::$container->get(Connection::class); + $this->entityManager = self::$container->get(EntityManagerInterface::class); + } + + public function testImportUnit(): void + { + $importer = new GeographicalUnitBaseImporter( + $this->connection, + new NullLogger() + ); + + $importer->importUnit( + 'test', + ['fr' => 'Test Layer'], + 'Layer one', + 'layer_one', + 'MULTIPOLYGON (((30 20, 45 40, 10 40, 30 20)),((15 5, 40 10, 10 20, 5 10, 15 5)))', + 3812 + ); + + $importer->finalize(); + + $unit = $this->connection->executeQuery(" + SELECT unitname, unitrefid, cmgul.refid AS layerrefid, cmgul.name AS layername, ST_AsText(ST_snapToGrid(ST_Transform(u.geom, 3812), 1)) AS geom + FROM chill_main_geographical_unit u JOIN chill_main_geographical_unit_layer cmgul on u.layer_id = cmgul.id + WHERE u.unitrefid = ?", ['layer_one']); + + $results = $unit->fetchAssociative(); + + $this->assertEquals($results['unitrefid'], 'layer_one'); + $this->assertEquals($results['unitname'], 'Layer one'); + $this->assertEquals(json_decode($results['layername'], true), ['fr' => 'Test Layer']); + $this->assertEquals($results['layerrefid'], 'test'); + $this->assertEquals($results['geom'], 'MULTIPOLYGON(((30 20,45 40,10 40,30 20)),((15 5,40 10,10 20,5 10,15 5)))'); + + $importer = new GeographicalUnitBaseImporter( + $this->connection, + new NullLogger() + ); + + $importer->importUnit( + 'test', + ['fr' => 'Test Layer fixed'], + 'Layer one fixed', + 'layer_one', + 'MULTIPOLYGON (((130 120, 45 40, 10 40, 130 120)),((0 0, 15 5, 40 10, 10 20, 0 0)))', + 3812 + ); + + $importer->finalize(); + + $unit = $this->connection->executeQuery(" + SELECT unitname, unitrefid, cmgul.refid AS layerrefid, cmgul.name AS layername, ST_AsText(ST_snapToGrid(ST_Transform(u.geom, 3812), 1)) AS geom + FROM chill_main_geographical_unit u JOIN chill_main_geographical_unit_layer cmgul on u.layer_id = cmgul.id + WHERE u.unitrefid = ?", ['layer_one']); + + $results = $unit->fetchAssociative(); + + $this->assertEquals($results['unitrefid'], 'layer_one'); + $this->assertEquals($results['unitname'], 'Layer one fixed'); + $this->assertEquals(json_decode($results['layername'], true), ['fr' => 'Test Layer fixed']); + $this->assertEquals($results['layerrefid'], 'test'); + $this->assertEquals($results['geom'], 'MULTIPOLYGON(((130 120,45 40,10 40,130 120)),((0 0,15 5,40 10,10 20,0 0)))'); + + } + +} \ No newline at end of file diff --git a/src/Bundle/ChillMainBundle/migrations/Version20221003132620.php b/src/Bundle/ChillMainBundle/migrations/Version20221003132620.php new file mode 100644 index 000000000..39b01a0bc --- /dev/null +++ b/src/Bundle/ChillMainBundle/migrations/Version20221003132620.php @@ -0,0 +1,30 @@ +addSql('CREATE UNIQUE INDEX geographical_unit_layer_refid ON chill_main_geographical_unit_layer (refId)'); + $this->addSql('CREATE UNIQUE INDEX geographical_unit_refid ON chill_main_geographical_unit (unitRefId)'); + $this->addSql('CREATE INDEX chill_internal_geographical_unit_layer_geom_idx ON chill_main_geographical_unit USING GIST (geom)'); + } + + public function down(Schema $schema): void + { + $this->addSql('DROP INDEX geographical_unit_layer_refid'); + $this->addSql('DROP INDEX geographical_unit_refid'); + $this->addSql('DROP INDEX chill_internal_geographical_unit_layer_geom_idx'); + } +}