3 namespace Nominatim\Setup;
5 require_once(CONST_LibDir.'/Shell.php');
13 protected $sIgnoreErrors;
14 protected $bEnableDiffUpdates;
15 protected $bEnableDebugStatements;
16 protected $bNoPartitions;
18 protected $oDB = null;
19 protected $oNominatimCmd;
21 public function __construct(array $aCMDResult)
23 // by default, use all but one processor, but never more than 15.
24 $this->iInstances = isset($aCMDResult['threads'])
25 ? $aCMDResult['threads']
26 : (min(16, getProcessorCount()) - 1);
28 if ($this->iInstances < 1) {
29 $this->iInstances = 1;
30 warn('resetting threads to '.$this->iInstances);
33 // parse database string
34 $this->aDSNInfo = \Nominatim\DB::parseDSN(getSetting('DATABASE_DSN'));
35 if (!isset($this->aDSNInfo['port'])) {
36 $this->aDSNInfo['port'] = 5432;
39 // setting member variables based on command line options stored in $aCMDResult
40 $this->bQuiet = isset($aCMDResult['quiet']) && $aCMDResult['quiet'];
41 $this->bVerbose = $aCMDResult['verbose'];
43 //setting default values which are not set by the update.php array
44 if (isset($aCMDResult['ignore-errors'])) {
45 $this->sIgnoreErrors = $aCMDResult['ignore-errors'];
47 $this->sIgnoreErrors = false;
49 if (isset($aCMDResult['enable-debug-statements'])) {
50 $this->bEnableDebugStatements = $aCMDResult['enable-debug-statements'];
52 $this->bEnableDebugStatements = false;
54 if (isset($aCMDResult['no-partitions'])) {
55 $this->bNoPartitions = $aCMDResult['no-partitions'];
57 $this->bNoPartitions = false;
59 if (isset($aCMDResult['enable-diff-updates'])) {
60 $this->bEnableDiffUpdates = $aCMDResult['enable-diff-updates'];
62 $this->bEnableDiffUpdates = false;
65 $this->bDrop = isset($aCMDResult['drop']) && $aCMDResult['drop'];
67 $this->oNominatimCmd = new \Nominatim\Shell(getSetting('NOMINATIM_TOOL'));
69 $this->oNominatimCmd->addParams('--quiet');
71 if ($this->bVerbose) {
72 $this->oNominatimCmd->addParams('--verbose');
74 $this->oNominatimCmd->addParams('--threads', $this->iInstances);
77 public function createFunctions()
79 info('Create Functions');
81 // Try accessing the C module, so we know early if something is wrong
82 $this->checkModulePresence(); // raises exception on failure
84 $this->createSqlFunctions();
87 public function createTables($bReverseOnly = false)
89 info('Create Tables');
91 $sTemplate = file_get_contents(CONST_SqlDir.'/tables.sql');
92 $sTemplate = $this->replaceSqlPatterns($sTemplate);
94 $this->pgsqlRunScript($sTemplate, false);
97 $this->dropTable('search_name');
100 (clone($this->oNominatimCmd))->addParams('refresh', '--address-levels')->run();
103 public function createTableTriggers()
105 info('Create Tables');
107 $sTemplate = file_get_contents(CONST_SqlDir.'/table-triggers.sql');
108 $sTemplate = $this->replaceSqlPatterns($sTemplate);
110 $this->pgsqlRunScript($sTemplate, false);
113 public function createPartitionTables()
115 info('Create Partition Tables');
117 $sTemplate = file_get_contents(CONST_SqlDir.'/partition-tables.src.sql');
118 $sTemplate = $this->replaceSqlPatterns($sTemplate);
120 $this->pgsqlRunPartitionScript($sTemplate);
123 public function loadData($bDisableTokenPrecalc)
125 info('Drop old Data');
129 $oDB->exec('TRUNCATE word');
131 $oDB->exec('TRUNCATE placex');
133 $oDB->exec('TRUNCATE location_property_osmline');
135 $oDB->exec('TRUNCATE place_addressline');
137 $oDB->exec('TRUNCATE location_area');
139 if (!$this->dbReverseOnly()) {
140 $oDB->exec('TRUNCATE search_name');
143 $oDB->exec('TRUNCATE search_name_blank');
145 $oDB->exec('DROP SEQUENCE seq_place');
147 $oDB->exec('CREATE SEQUENCE seq_place start 100000');
150 $sSQL = 'select distinct partition from country_name';
151 $aPartitions = $oDB->getCol($sSQL);
153 if (!$this->bNoPartitions) $aPartitions[] = 0;
154 foreach ($aPartitions as $sPartition) {
155 $oDB->exec('TRUNCATE location_road_'.$sPartition);
159 // used by getorcreate_word_id to ignore frequent partial words
160 $sSQL = 'CREATE OR REPLACE FUNCTION get_maxwordfreq() RETURNS integer AS ';
161 $sSQL .= '$$ SELECT '.getSetting('MAX_WORD_FREQUENCY').' as maxwordfreq; $$ LANGUAGE SQL IMMUTABLE';
165 // pre-create the word list
166 if (!$bDisableTokenPrecalc) {
167 info('Loading word list');
168 $this->pgsqlRunScriptFile(CONST_DataDir.'/words.sql');
172 $sColumns = 'osm_type, osm_id, class, type, name, admin_level, address, extratags, geometry';
174 $aDBInstances = array();
175 $iLoadThreads = max(1, $this->iInstances - 1);
176 for ($i = 0; $i < $iLoadThreads; $i++) {
177 // https://secure.php.net/manual/en/function.pg-connect.php
178 $DSN = getSetting('DATABASE_DSN');
179 $DSN = preg_replace('/^pgsql:/', '', $DSN);
180 $DSN = preg_replace('/;/', ' ', $DSN);
181 $aDBInstances[$i] = pg_connect($DSN, PGSQL_CONNECT_FORCE_NEW);
182 pg_ping($aDBInstances[$i]);
185 for ($i = 0; $i < $iLoadThreads; $i++) {
186 $sSQL = "INSERT INTO placex ($sColumns) SELECT $sColumns FROM place WHERE osm_id % $iLoadThreads = $i";
187 $sSQL .= " and not (class='place' and type='houses' and osm_type='W'";
188 $sSQL .= " and ST_GeometryType(geometry) = 'ST_LineString')";
189 $sSQL .= ' and ST_IsValid(geometry)';
190 if ($this->bVerbose) echo "$sSQL\n";
191 if (!pg_send_query($aDBInstances[$i], $sSQL)) {
192 fail(pg_last_error($aDBInstances[$i]));
196 // last thread for interpolation lines
197 // https://secure.php.net/manual/en/function.pg-connect.php
198 $DSN = getSetting('DATABASE_DSN');
199 $DSN = preg_replace('/^pgsql:/', '', $DSN);
200 $DSN = preg_replace('/;/', ' ', $DSN);
201 $aDBInstances[$iLoadThreads] = pg_connect($DSN, PGSQL_CONNECT_FORCE_NEW);
202 pg_ping($aDBInstances[$iLoadThreads]);
203 $sSQL = 'insert into location_property_osmline';
204 $sSQL .= ' (osm_id, address, linegeo)';
205 $sSQL .= ' SELECT osm_id, address, geometry from place where ';
206 $sSQL .= "class='place' and type='houses' and osm_type='W' and ST_GeometryType(geometry) = 'ST_LineString'";
207 if ($this->bVerbose) echo "$sSQL\n";
208 if (!pg_send_query($aDBInstances[$iLoadThreads], $sSQL)) {
209 fail(pg_last_error($aDBInstances[$iLoadThreads]));
213 for ($i = 0; $i <= $iLoadThreads; $i++) {
214 while (($hPGresult = pg_get_result($aDBInstances[$i])) !== false) {
215 $resultStatus = pg_result_status($hPGresult);
216 // PGSQL_EMPTY_QUERY, PGSQL_COMMAND_OK, PGSQL_TUPLES_OK,
217 // PGSQL_COPY_OUT, PGSQL_COPY_IN, PGSQL_BAD_RESPONSE,
218 // PGSQL_NONFATAL_ERROR and PGSQL_FATAL_ERROR
219 // echo 'Query result ' . $i . ' is: ' . $resultStatus . "\n";
220 if ($resultStatus != PGSQL_COMMAND_OK && $resultStatus != PGSQL_TUPLES_OK) {
221 $resultError = pg_result_error($hPGresult);
222 echo '-- error text ' . $i . ': ' . $resultError . "\n";
228 fail('SQL errors loading placex and/or location_property_osmline tables');
231 for ($i = 0; $i < $this->iInstances; $i++) {
232 pg_close($aDBInstances[$i]);
236 info('Reanalysing database');
237 $this->pgsqlRunScript('ANALYSE');
239 $sDatabaseDate = getDatabaseDate($oDB);
240 $oDB->exec('TRUNCATE import_status');
241 if (!$sDatabaseDate) {
242 warn('could not determine database date.');
244 $sSQL = "INSERT INTO import_status (lastimportdate) VALUES('".$sDatabaseDate."')";
246 echo "Latest data imported from $sDatabaseDate.\n";
250 public function importTigerData($sTigerPath)
252 info('Import Tiger data');
254 $aFilenames = glob($sTigerPath.'/*.sql');
255 info('Found '.count($aFilenames).' SQL files in path '.$sTigerPath);
256 if (empty($aFilenames)) {
257 warn('Tiger data import selected but no files found in path '.$sTigerPath);
260 $sTemplate = file_get_contents(CONST_SqlDir.'/tiger_import_start.sql');
261 $sTemplate = $this->replaceSqlPatterns($sTemplate);
263 $this->pgsqlRunScript($sTemplate, false);
265 $aDBInstances = array();
266 for ($i = 0; $i < $this->iInstances; $i++) {
267 // https://secure.php.net/manual/en/function.pg-connect.php
268 $DSN = getSetting('DATABASE_DSN');
269 $DSN = preg_replace('/^pgsql:/', '', $DSN);
270 $DSN = preg_replace('/;/', ' ', $DSN);
271 $aDBInstances[$i] = pg_connect($DSN, PGSQL_CONNECT_FORCE_NEW | PGSQL_CONNECT_ASYNC);
272 pg_ping($aDBInstances[$i]);
275 foreach ($aFilenames as $sFile) {
277 $hFile = fopen($sFile, 'r');
278 $sSQL = fgets($hFile, 100000);
281 for ($i = 0; $i < $this->iInstances; $i++) {
282 if (!pg_connection_busy($aDBInstances[$i])) {
283 while (pg_get_result($aDBInstances[$i]));
284 $sSQL = fgets($hFile, 100000);
286 if (!pg_send_query($aDBInstances[$i], $sSQL)) fail(pg_last_error($aDBInstances[$i]));
288 if ($iLines == 1000) {
301 for ($i = 0; $i < $this->iInstances; $i++) {
302 if (pg_connection_busy($aDBInstances[$i])) $bAnyBusy = true;
309 for ($i = 0; $i < $this->iInstances; $i++) {
310 pg_close($aDBInstances[$i]);
313 info('Creating indexes on Tiger data');
314 $sTemplate = file_get_contents(CONST_SqlDir.'/tiger_import_finish.sql');
315 $sTemplate = $this->replaceSqlPatterns($sTemplate);
317 $this->pgsqlRunScript($sTemplate, false);
320 public function calculatePostcodes($bCMDResultAll)
322 info('Calculate Postcodes');
323 $this->pgsqlRunScriptFile(CONST_SqlDir.'/postcode_tables.sql');
325 $sPostcodeFilename = CONST_InstallDir.'/gb_postcode_data.sql.gz';
326 if (file_exists($sPostcodeFilename)) {
327 $this->pgsqlRunScriptFile($sPostcodeFilename);
329 warn('optional external GB postcode table file ('.$sPostcodeFilename.') not found. Skipping.');
332 $sPostcodeFilename = CONST_InstallDir.'/us_postcode_data.sql.gz';
333 if (file_exists($sPostcodeFilename)) {
334 $this->pgsqlRunScriptFile($sPostcodeFilename);
336 warn('optional external US postcode table file ('.$sPostcodeFilename.') not found. Skipping.');
340 $this->db()->exec('TRUNCATE location_postcode');
342 $sSQL = 'INSERT INTO location_postcode';
343 $sSQL .= ' (place_id, indexed_status, country_code, postcode, geometry) ';
344 $sSQL .= "SELECT nextval('seq_place'), 1, country_code,";
345 $sSQL .= " upper(trim (both ' ' from address->'postcode')) as pc,";
346 $sSQL .= ' ST_Centroid(ST_Collect(ST_Centroid(geometry)))';
347 $sSQL .= ' FROM placex';
348 $sSQL .= " WHERE address ? 'postcode' AND address->'postcode' NOT SIMILAR TO '%(,|;)%'";
349 $sSQL .= ' AND geometry IS NOT null';
350 $sSQL .= ' GROUP BY country_code, pc';
351 $this->db()->exec($sSQL);
353 // only add postcodes that are not yet available in OSM
354 $sSQL = 'INSERT INTO location_postcode';
355 $sSQL .= ' (place_id, indexed_status, country_code, postcode, geometry) ';
356 $sSQL .= "SELECT nextval('seq_place'), 1, 'us', postcode,";
357 $sSQL .= ' ST_SetSRID(ST_Point(x,y),4326)';
358 $sSQL .= ' FROM us_postcode WHERE postcode NOT IN';
359 $sSQL .= ' (SELECT postcode FROM location_postcode';
360 $sSQL .= " WHERE country_code = 'us')";
361 $this->db()->exec($sSQL);
363 // add missing postcodes for GB (if available)
364 $sSQL = 'INSERT INTO location_postcode';
365 $sSQL .= ' (place_id, indexed_status, country_code, postcode, geometry) ';
366 $sSQL .= "SELECT nextval('seq_place'), 1, 'gb', postcode, geometry";
367 $sSQL .= ' FROM gb_postcode WHERE postcode NOT IN';
368 $sSQL .= ' (SELECT postcode FROM location_postcode';
369 $sSQL .= " WHERE country_code = 'gb')";
370 $this->db()->exec($sSQL);
372 if (!$bCMDResultAll) {
373 $sSQL = "DELETE FROM word WHERE class='place' and type='postcode'";
374 $sSQL .= 'and word NOT IN (SELECT postcode FROM location_postcode)';
375 $this->db()->exec($sSQL);
378 $sSQL = 'SELECT count(getorcreate_postcode_id(v)) FROM ';
379 $sSQL .= '(SELECT distinct(postcode) as v FROM location_postcode) p';
380 $this->db()->exec($sSQL);
383 public function index($bIndexNoanalyse)
385 $this->checkModulePresence(); // raises exception on failure
387 $oBaseCmd = (clone $this->oNominatimCmd)->addParams('index');
389 info('Index ranks 0 - 4');
390 $oCmd = (clone $oBaseCmd)->addParams('--maxrank', 4);
392 $iStatus = $oCmd->run();
394 fail('error status ' . $iStatus . ' running nominatim!');
396 if (!$bIndexNoanalyse) $this->pgsqlRunScript('ANALYSE');
398 info('Index administrative boundaries');
399 $oCmd = (clone $oBaseCmd)->addParams('--boundaries-only');
400 $iStatus = $oCmd->run();
402 fail('error status ' . $iStatus . ' running nominatim!');
405 info('Index ranks 5 - 25');
406 $oCmd = (clone $oBaseCmd)->addParams('--no-boundaries', '--minrank', 5, '--maxrank', 25);
407 $iStatus = $oCmd->run();
409 fail('error status ' . $iStatus . ' running nominatim!');
412 if (!$bIndexNoanalyse) $this->pgsqlRunScript('ANALYSE');
414 info('Index ranks 26 - 30');
415 $oCmd = (clone $oBaseCmd)->addParams('--no-boundaries', '--minrank', 26);
416 $iStatus = $oCmd->run();
418 fail('error status ' . $iStatus . ' running nominatim!');
421 info('Index postcodes');
422 $sSQL = 'UPDATE location_postcode SET indexed_status = 0';
423 $this->db()->exec($sSQL);
426 public function createSearchIndices()
428 info('Create Search indices');
430 $sSQL = 'SELECT relname FROM pg_class, pg_index ';
431 $sSQL .= 'WHERE pg_index.indisvalid = false AND pg_index.indexrelid = pg_class.oid';
432 $aInvalidIndices = $this->db()->getCol($sSQL);
434 foreach ($aInvalidIndices as $sIndexName) {
435 info("Cleaning up invalid index $sIndexName");
436 $this->db()->exec("DROP INDEX $sIndexName;");
439 $sTemplate = file_get_contents(CONST_SqlDir.'/indices.src.sql');
441 $sTemplate .= file_get_contents(CONST_SqlDir.'/indices_updates.src.sql');
443 if (!$this->dbReverseOnly()) {
444 $sTemplate .= file_get_contents(CONST_SqlDir.'/indices_search.src.sql');
446 $sTemplate = $this->replaceSqlPatterns($sTemplate);
448 $this->pgsqlRunScript($sTemplate);
451 public function createCountryNames()
453 info('Create search index for default country names');
455 $this->pgsqlRunScript("select getorcreate_country(make_standard_name('uk'), 'gb')");
456 $this->pgsqlRunScript("select getorcreate_country(make_standard_name('united states'), 'us')");
457 $this->pgsqlRunScript('select count(*) from (select getorcreate_country(make_standard_name(country_code), country_code) from country_name where country_code is not null) as x');
458 $this->pgsqlRunScript("select count(*) from (select getorcreate_country(make_standard_name(name->'name'), country_code) from country_name where name ? 'name') as x");
459 $sSQL = 'select count(*) from (select getorcreate_country(make_standard_name(v),'
460 .'country_code) from (select country_code, skeys(name) as k, svals(name) as v from country_name) x where k ';
461 $sLanguages = getSetting('LANGUAGES');
465 foreach (explode(',', $sLanguages) as $sLang) {
466 $sSQL .= $sDelim."'name:$sLang'";
471 // all include all simple name tags
472 $sSQL .= "like 'name:%'";
475 $this->pgsqlRunScript($sSQL);
479 * Return the connection to the database.
481 * @return Database object.
483 * Creates a new connection if none exists yet. Otherwise reuses the
484 * already established connection.
486 private function db()
488 if (is_null($this->oDB)) {
489 $this->oDB = new \Nominatim\DB();
490 $this->oDB->connect();
496 private function pgsqlRunScript($sScript, $bfatal = true)
506 private function createSqlFunctions()
508 $oCmd = (clone($this->oNominatimCmd))
509 ->addParams('refresh', '--functions');
511 if (!$this->bEnableDiffUpdates) {
512 $oCmd->addParams('--no-diff-updates');
515 if ($this->bEnableDebugStatements) {
516 $oCmd->addParams('--enable-debug-statements');
519 $oCmd->run(!$this->sIgnoreErrors);
522 private function pgsqlRunPartitionScript($sTemplate)
524 $sSQL = 'select distinct partition from country_name';
525 $aPartitions = $this->db()->getCol($sSQL);
526 if (!$this->bNoPartitions) $aPartitions[] = 0;
528 preg_match_all('#^-- start(.*?)^-- end#ms', $sTemplate, $aMatches, PREG_SET_ORDER);
529 foreach ($aMatches as $aMatch) {
531 foreach ($aPartitions as $sPartitionName) {
532 $sResult .= str_replace('-partition-', $sPartitionName, $aMatch[1]);
534 $sTemplate = str_replace($aMatch[0], $sResult, $sTemplate);
537 $this->pgsqlRunScript($sTemplate);
540 private function pgsqlRunScriptFile($sFilename)
542 if (!file_exists($sFilename)) fail('unable to find '.$sFilename);
544 $oCmd = (new \Nominatim\Shell('psql'))
545 ->addParams('--port', $this->aDSNInfo['port'])
546 ->addParams('--dbname', $this->aDSNInfo['database']);
548 if (!$this->bVerbose) {
549 $oCmd->addParams('--quiet');
551 if (isset($this->aDSNInfo['hostspec'])) {
552 $oCmd->addParams('--host', $this->aDSNInfo['hostspec']);
554 if (isset($this->aDSNInfo['username'])) {
555 $oCmd->addParams('--username', $this->aDSNInfo['username']);
557 if (isset($this->aDSNInfo['password'])) {
558 $oCmd->addEnvPair('PGPASSWORD', $this->aDSNInfo['password']);
561 if (preg_match('/\\.gz$/', $sFilename)) {
562 $aDescriptors = array(
563 0 => array('pipe', 'r'),
564 1 => array('pipe', 'w'),
565 2 => array('file', '/dev/null', 'a')
567 $oZcatCmd = new \Nominatim\Shell('zcat', $sFilename);
569 $hGzipProcess = proc_open($oZcatCmd->escapedCmd(), $aDescriptors, $ahGzipPipes);
570 if (!is_resource($hGzipProcess)) fail('unable to start zcat');
571 $aReadPipe = $ahGzipPipes[1];
572 fclose($ahGzipPipes[0]);
574 $oCmd->addParams('--file', $sFilename);
575 $aReadPipe = array('pipe', 'r');
577 $aDescriptors = array(
579 1 => array('pipe', 'w'),
580 2 => array('file', '/dev/null', 'a')
584 $hProcess = proc_open($oCmd->escapedCmd(), $aDescriptors, $ahPipes, null, $oCmd->aEnv);
585 if (!is_resource($hProcess)) fail('unable to start pgsql');
586 // TODO: error checking
587 while (!feof($ahPipes[1])) {
588 echo fread($ahPipes[1], 4096);
591 $iReturn = proc_close($hProcess);
593 fail("pgsql returned with error code ($iReturn)");
596 fclose($ahGzipPipes[1]);
597 proc_close($hGzipProcess);
601 private function replaceSqlPatterns($sSql)
603 $sSql = str_replace('{www-user}', getSetting('DATABASE_WEBUSER'), $sSql);
606 '{ts:address-data}' => getSetting('TABLESPACE_ADDRESS_DATA'),
607 '{ts:address-index}' => getSetting('TABLESPACE_ADDRESS_INDEX'),
608 '{ts:search-data}' => getSetting('TABLESPACE_SEARCH_DATA'),
609 '{ts:search-index}' => getSetting('TABLESPACE_SEARCH_INDEX'),
610 '{ts:aux-data}' => getSetting('TABLESPACE_AUX_DATA'),
611 '{ts:aux-index}' => getSetting('TABLESPACE_AUX_INDEX')
614 foreach ($aPatterns as $sPattern => $sTablespace) {
616 $sSql = str_replace($sPattern, 'TABLESPACE "'.$sTablespace.'"', $sSql);
618 $sSql = str_replace($sPattern, '', $sSql);
626 * Drop table with the given name if it exists.
628 * @param string $sName Name of table to remove.
632 private function dropTable($sName)
634 if ($this->bVerbose) echo "Dropping table $sName\n";
635 $this->db()->deleteTable($sName);
639 * Check if the database is in reverse-only mode.
641 * @return True if there is no search_name table and infrastructure.
643 private function dbReverseOnly()
645 return !($this->db()->tableExists('search_name'));
649 * Try accessing the C module, so we know early if something is wrong.
651 * Raises Nominatim\DatabaseError on failure
653 private function checkModulePresence()
655 $sModulePath = getSetting('DATABASE_MODULE_PATH', CONST_InstallDir.'/module');
656 $sSQL = "CREATE FUNCTION nominatim_test_import_func(text) RETURNS text AS '";
657 $sSQL .= $sModulePath . "/nominatim.so', 'transliteration' LANGUAGE c IMMUTABLE STRICT";
658 $sSQL .= ';DROP FUNCTION nominatim_test_import_func(text);';
660 $oDB = new \Nominatim\DB();
662 $oDB->exec($sSQL, null, 'Database server failed to load '.$sModulePath.'/nominatim.so module');