mirror of
https://github.com/osm-search/Nominatim.git
synced 2026-02-16 15:47:58 +00:00
replace SQL code in PlaceLookup with content of search's get_details
This commit is contained in:
@@ -8,7 +8,7 @@ class PlaceLookup
|
||||
{
|
||||
protected $oDB;
|
||||
|
||||
protected $aLangPrefOrder = array();
|
||||
protected $aLangPrefOrderSql = "''";
|
||||
|
||||
protected $bAddressDetails = false;
|
||||
protected $bExtraTags = false;
|
||||
@@ -21,15 +21,41 @@ class PlaceLookup
|
||||
protected $bIncludePolygonAsSVG = false;
|
||||
protected $fPolygonSimplificationThreshold = 0.0;
|
||||
|
||||
protected $sAnchorSql = null;
|
||||
protected $sAddressRankListSql = null;
|
||||
protected $sAllowedTypesSQLList = null;
|
||||
protected $bDeDupe = true;
|
||||
|
||||
|
||||
public function __construct(&$oDB)
|
||||
{
|
||||
$this->oDB =& $oDB;
|
||||
}
|
||||
|
||||
public function setAnchorSql($sPoint)
|
||||
{
|
||||
$this->sAnchorSql = $sPoint;
|
||||
}
|
||||
|
||||
public function setDeDupe($bDeDupe)
|
||||
{
|
||||
$this->bDeDupe = $bDeDupe;
|
||||
}
|
||||
|
||||
public function setAddressRankList($aList)
|
||||
{
|
||||
$this->sAddressRankListSql = '('.join(',', $aList).')';
|
||||
}
|
||||
|
||||
public function setAllowedTypesSQLList($sSql)
|
||||
{
|
||||
$this->sAllowedTypesSQLList = $sSql;
|
||||
}
|
||||
|
||||
public function setLanguagePreference($aLangPrefOrder)
|
||||
{
|
||||
$this->aLangPrefOrder = $aLangPrefOrder;
|
||||
$this->aLangPrefOrderSql =
|
||||
'ARRAY['.join(',', array_map('getDBQuoted', $aLangPrefOrder)).']';
|
||||
}
|
||||
|
||||
public function setIncludeAddressDetails($bAddressDetails = true)
|
||||
@@ -77,9 +103,25 @@ class PlaceLookup
|
||||
$this->fPolygonSimplificationThreshold = $f;
|
||||
}
|
||||
|
||||
private function languagePrefSql()
|
||||
private function addressImportanceSql($sGeometry, $sPlaceId)
|
||||
{
|
||||
return 'ARRAY['.join(',', array_map('getDBQuoted', $this->aLangPrefOrder)).']';
|
||||
if ($this->sAnchorSql) {
|
||||
$sSQL = 'ST_Distance('.$this->sAnchorSql.','.$sGeometry.')';
|
||||
} else {
|
||||
$sSQL = '(SELECT max(ai_p.importance * (ai_p.rank_address + 2))';
|
||||
$sSQL .= ' FROM place_addressline ai_s, placex ai_p';
|
||||
$sSQL .= ' WHERE ai_s.place_id = '.$sPlaceId;
|
||||
$sSQL .= ' AND ai_p.place_id = ai_s.address_place_id ';
|
||||
$sSQL .= ' AND ai_s.isaddress ';
|
||||
$sSQL .= ' AND ai_p.importance is not null)';
|
||||
}
|
||||
|
||||
return $sSQL.' AS addressimportance,';
|
||||
}
|
||||
|
||||
private function langAddressSql($sHousenumber)
|
||||
{
|
||||
return 'get_address_by_language(place_id,'.$sHousenumber.','.$this->aLangPrefOrderSql.') AS langaddress,';
|
||||
}
|
||||
|
||||
public function lookupOSMID($sType, $iID)
|
||||
@@ -94,115 +136,330 @@ class PlaceLookup
|
||||
return $this->lookup(new Result($iPlaceID));
|
||||
}
|
||||
|
||||
public function lookup($oResult)
|
||||
public function lookup($oResult, $iMinRank = 0, $iMaxRank = 30)
|
||||
{
|
||||
if ($oResult === null) {
|
||||
return null;
|
||||
}
|
||||
|
||||
$sLanguagePrefArraySQL = $this->languagePrefSql();
|
||||
$iPlaceID = $oResult->iId;
|
||||
$aResults = array($oResult->iId => $oResult);
|
||||
|
||||
if ($oResult->iTable == Result::TABLE_TIGER) {
|
||||
$sSQL = "select place_id,partition, 'T' as osm_type, place_id as osm_id, 'place' as class, 'house' as type, null as admin_level,";
|
||||
$sSQL .= $oResult->iHouseNumber.' as housenumber, postcode,';
|
||||
$sSQL .= " 'us' as country_code, parent_place_id, null as linked_place_id, 30 as rank_address, 30 as rank_search,";
|
||||
$sSQL .= " coalesce(null,0.75-(30::float/40)) as importance, null as indexed_status, null as indexed_date, null as wikipedia, 'us' as country_code, ";
|
||||
$sSQL .= " get_address_by_language(place_id,".$oResult->iHouseNumber.", $sLanguagePrefArraySQL) as langaddress,";
|
||||
$sSQL .= " null as placename,";
|
||||
$sSQL .= " null as ref,";
|
||||
if ($this->bExtraTags) $sSQL .= " null as extra,";
|
||||
if ($this->bNameDetails) $sSQL .= " null as names,";
|
||||
$sSQL .= " ST_X(point) as lon, ST_Y(point) as lat";
|
||||
$sSQL .= " FROM (select *, ST_LineInterpolatePoint(linegeo, (".$oResult->iHouseNumber."-startnumber::float)/(endnumber-startnumber)::float) as point ";
|
||||
$sSQL .= " FROM location_property_tiger where place_id = ".$iPlaceID.") as blub";
|
||||
} elseif ($oResult->iTable == Result::TABLE_OSMLINE) {
|
||||
$sSQL = "select place_id, partition, 'W' as osm_type, osm_id, 'place' as class, 'house' as type, null admin_level,";
|
||||
$sSQL .= $oResult->iHouseNumber.' as housenumber, postcode,';
|
||||
$sSQL .= " country_code, parent_place_id, null as linked_place_id, 30 as rank_address, 30 as rank_search,";
|
||||
$sSQL .= " (0.75-(30::float/40)) as importance, null as indexed_status, null as indexed_date, null as wikipedia, country_code, ";
|
||||
$sSQL .= " get_address_by_language(place_id,".$oResult->iHouseNumber.", $sLanguagePrefArraySQL) as langaddress,";
|
||||
$sSQL .= " null as placename,";
|
||||
$sSQL .= " null as ref,";
|
||||
if ($this->bExtraTags) $sSQL .= " null as extra,";
|
||||
if ($this->bNameDetails) $sSQL .= " null as names,";
|
||||
$sSQL .= " ST_X(point) as lon, ST_Y(point) as lat ";
|
||||
$sSQL .= " FROM (select *, ST_LineInterpolatePoint(linegeo, (".$oResult->iHouseNumber."-startnumber::float)/(endnumber-startnumber)::float) as point ";
|
||||
$sSQL .= " from location_property_osmline where place_id = ".$iPlaceID.") as blub";
|
||||
// testcase: interpolationtype=odd, startnumber=1000, endnumber=1006, fInterpolFraction=1 => housenumber=1007 => error in st_lineinterpolatepoint
|
||||
// but this will never happen, because if the searched point is that close to the endnumber, the endnumber house will be directly taken from placex (in ReverseGeocode.php line 220)
|
||||
// and not interpolated
|
||||
} else {
|
||||
$sSQL = "select placex.place_id, partition, osm_type, osm_id, class,";
|
||||
$sSQL .= " type, admin_level, housenumber, postcode, country_code,";
|
||||
$sSQL .= " parent_place_id, linked_place_id, rank_address, rank_search, ";
|
||||
$sSQL .= " coalesce(importance,0.75-(rank_search::float/40)) as importance, indexed_status, indexed_date, wikipedia, country_code, ";
|
||||
$sSQL .= " get_address_by_language(place_id, -1, $sLanguagePrefArraySQL) as langaddress,";
|
||||
$sSQL .= " get_name_by_language(name, $sLanguagePrefArraySQL) as placename,";
|
||||
$sSQL .= " get_name_by_language(name, ARRAY['ref']) as ref,";
|
||||
if ($this->bExtraTags) $sSQL .= " hstore_to_json(extratags) as extra,";
|
||||
if ($this->bNameDetails) $sSQL .= " hstore_to_json(name) as names,";
|
||||
$sSQL .= " (case when centroid is null then st_y(st_centroid(geometry)) else st_y(centroid) end) as lat,";
|
||||
$sSQL .= " (case when centroid is null then st_x(st_centroid(geometry)) else st_x(centroid) end) as lon";
|
||||
$sSQL .= " from placex where place_id = ".$iPlaceID;
|
||||
$aSubSelects = array();
|
||||
|
||||
$sPlaceIDs = Result::joinIdsByTable($aResults, Result::TABLE_PLACEX);
|
||||
if (CONST_Debug) var_dump('PLACEX', $sPlaceIDs);
|
||||
if ($sPlaceIDs) {
|
||||
$sSQL = 'SELECT ';
|
||||
$sSQL .= ' osm_type,';
|
||||
$sSQL .= ' osm_id,';
|
||||
$sSQL .= ' class,';
|
||||
$sSQL .= ' type,';
|
||||
$sSQL .= ' admin_level,';
|
||||
$sSQL .= ' rank_search,';
|
||||
$sSQL .= ' rank_address,';
|
||||
$sSQL .= ' min(place_id) AS place_id,';
|
||||
$sSQL .= ' min(parent_place_id) AS parent_place_id,';
|
||||
$sSQL .= ' housenumber,';
|
||||
$sSQL .= ' country_code,';
|
||||
$sSQL .= $this->langAddressSql('-1');
|
||||
$sSQL .= ' get_name_by_language(name,'.$this->aLangPrefOrderSql.') AS placename,';
|
||||
$sSQL .= " get_name_by_language(name, ARRAY['ref']) AS ref,";
|
||||
if ($this->bExtraTags) {
|
||||
$sSQL .= 'hstore_to_json(extratags)::text AS extra,';
|
||||
}
|
||||
if ($this->bNameDetails) {
|
||||
$sSQL .= 'hstore_to_json(name)::text AS names,';
|
||||
}
|
||||
$sSQL .= ' avg(ST_X(centroid)) AS lon, ';
|
||||
$sSQL .= ' avg(ST_Y(centroid)) AS lat, ';
|
||||
$sSQL .= ' COALESCE(importance,0.75-(rank_search::float/40)) AS importance, ';
|
||||
$sSQL .= $this->addressImportanceSql(
|
||||
'centroid',
|
||||
'min(CASE WHEN placex.rank_search < 28 THEN placex.place_id ELSE placex.parent_place_id END)'
|
||||
);
|
||||
$sSQL .= " (extratags->'place') AS extra_place ";
|
||||
$sSQL .= ' FROM placex';
|
||||
$sSQL .= " WHERE place_id in ($sPlaceIDs) ";
|
||||
$sSQL .= ' AND (';
|
||||
$sSQL .= " placex.rank_address between $iMinRank and $iMaxRank ";
|
||||
if (14 >= $iMinRank && 14 <= $iMaxRank) {
|
||||
$sSQL .= " OR (extratags->'place') = 'city'";
|
||||
}
|
||||
if ($this->sAddressRankListSql) {
|
||||
$sSQL .= ' OR placex.rank_address in '.$this->sAddressRankListSql;
|
||||
}
|
||||
$sSQL .= " ) ";
|
||||
if ($this->sAllowedTypesSQLList) {
|
||||
$sSQL .= 'AND placex.class in '.$this->sAllowedTypesSQLList;
|
||||
}
|
||||
$sSQL .= ' AND linked_place_id is null ';
|
||||
$sSQL .= ' GROUP BY ';
|
||||
$sSQL .= ' osm_type, ';
|
||||
$sSQL .= ' osm_id, ';
|
||||
$sSQL .= ' class, ';
|
||||
$sSQL .= ' type, ';
|
||||
$sSQL .= ' admin_level, ';
|
||||
$sSQL .= ' rank_search, ';
|
||||
$sSQL .= ' rank_address, ';
|
||||
$sSQL .= ' housenumber,';
|
||||
$sSQL .= ' country_code, ';
|
||||
$sSQL .= ' importance, ';
|
||||
if (!$this->bDeDupe) $sSQL .= 'place_id,';
|
||||
$sSQL .= ' langaddress, ';
|
||||
$sSQL .= ' placename, ';
|
||||
$sSQL .= ' ref, ';
|
||||
if ($this->bExtraTags) $sSQL .= 'extratags, ';
|
||||
if ($this->bNameDetails) $sSQL .= 'name, ';
|
||||
$sSQL .= " extratags->'place' ";
|
||||
|
||||
$aSubSelects[] = $sSQL;
|
||||
}
|
||||
|
||||
$aPlace = chksql($this->oDB->getRow($sSQL), "Could not lookup place");
|
||||
// postcode table
|
||||
$sPlaceIDs = Result::joinIdsByTable($aResults, Result::TABLE_POSTCODE);
|
||||
if ($sPlaceIDs) {
|
||||
$sSQL = 'SELECT';
|
||||
$sSQL .= " 'P' as osm_type,";
|
||||
$sSQL .= " (SELECT osm_id from placex p WHERE p.place_id = lp.parent_place_id) as osm_id,";
|
||||
$sSQL .= " 'place' as class, 'postcode' as type,";
|
||||
$sSQL .= ' null as admin_level, rank_search, rank_address,';
|
||||
$sSQL .= ' place_id, parent_place_id,';
|
||||
$sSQL .= ' null as housenumber,';
|
||||
$sSQL .= ' country_code,';
|
||||
$sSQL .= $this->langAddressSql('-1');
|
||||
$sSQL .= " postcode as placename,";
|
||||
$sSQL .= " postcode as ref,";
|
||||
if ($this->bExtraTags) $sSQL .= "null AS extra,";
|
||||
if ($this->bNameDetails) $sSQL .= "null AS names,";
|
||||
$sSQL .= " ST_x(geometry) AS lon, ST_y(geometry) AS lat,";
|
||||
$sSQL .= " (0.75-(rank_search::float/40)) AS importance, ";
|
||||
$sSQL .= $this->addressImportanceSql('geometry', 'lp.parent_place_id');
|
||||
$sSQL .= " null AS extra_place ";
|
||||
$sSQL .= "FROM location_postcode lp";
|
||||
$sSQL .= " WHERE place_id in ($sPlaceIDs) ";
|
||||
$sSQL .= " AND lp.rank_address between $iMinRank and $iMaxRank";
|
||||
|
||||
if (!$aPlace['place_id']) return null;
|
||||
|
||||
if ($this->bAddressDetails) {
|
||||
// to get addressdetails for tiger data, the housenumber is needed
|
||||
$aPlace['aAddress'] = $this->getAddressNames($aPlace['place_id'], $oResult->iHouseNumber);
|
||||
$aSubSelects[] = $sSQL;
|
||||
}
|
||||
|
||||
if ($this->bExtraTags) {
|
||||
if ($aPlace['extra']) {
|
||||
$aPlace['sExtraTags'] = json_decode($aPlace['extra']);
|
||||
} else {
|
||||
$aPlace['sExtraTags'] = (object) array();
|
||||
// All other tables are rank 30 only.
|
||||
if ($iMaxRank == 30) {
|
||||
// TIGER table
|
||||
if (CONST_Use_US_Tiger_Data) {
|
||||
$sPlaceIDs = Result::joinIdsByTable($aResults, Result::TABLE_TIGER);
|
||||
if ($sPlaceIDs) {
|
||||
$sHousenumbers = Result::sqlHouseNumberTable($aResults, Result::TABLE_TIGER);
|
||||
// Tiger search only if a housenumber was searched and if it was found
|
||||
// (realized through a join)
|
||||
$sSQL = " SELECT ";
|
||||
$sSQL .= " 'T' AS osm_type, ";
|
||||
$sSQL .= " (SELECT osm_id from placex p WHERE p.place_id=blub.parent_place_id) as osm_id, ";
|
||||
$sSQL .= " 'place' AS class, ";
|
||||
$sSQL .= " 'house' AS type, ";
|
||||
$sSQL .= ' null AS admin_level, ';
|
||||
$sSQL .= ' 30 AS rank_search, ';
|
||||
$sSQL .= ' 30 AS rank_address, ';
|
||||
$sSQL .= ' place_id, ';
|
||||
$sSQL .= ' parent_place_id, ';
|
||||
$sSQL .= ' housenumber_for_place as housenumber,';
|
||||
$sSQL .= " 'us' AS country_code, ";
|
||||
$sSQL .= $this->langAddressSql('housenumber_for_place');
|
||||
$sSQL .= " null AS placename, ";
|
||||
$sSQL .= " null AS ref, ";
|
||||
if ($this->bExtraTags) $sSQL .= "null AS extra,";
|
||||
if ($this->bNameDetails) $sSQL .= "null AS names,";
|
||||
$sSQL .= " st_x(centroid) AS lon, ";
|
||||
$sSQL .= " st_y(centroid) AS lat,";
|
||||
$sSQL .= " -1.15 AS importance, ";
|
||||
$sSQL .= $this->addressImportanceSql('centroid', 'blub.parent_place_id');
|
||||
$sSQL .= " null AS extra_place ";
|
||||
$sSQL .= " FROM (";
|
||||
$sSQL .= " SELECT place_id, "; // interpolate the Tiger housenumbers here
|
||||
$sSQL .= " ST_LineInterpolatePoint(linegeo, (housenumber_for_place-startnumber::float)/(endnumber-startnumber)::float) AS centroid, ";
|
||||
$sSQL .= " parent_place_id, ";
|
||||
$sSQL .= " housenumber_for_place";
|
||||
$sSQL .= " FROM (";
|
||||
$sSQL .= " location_property_tiger ";
|
||||
$sSQL .= " JOIN (values ".$sHousenumbers.") AS housenumbers(place_id, housenumber_for_place) USING(place_id)) ";
|
||||
$sSQL .= " WHERE ";
|
||||
$sSQL .= " housenumber_for_place >= startnumber";
|
||||
$sSQL .= " AND housenumber_for_place <= endnumber";
|
||||
$sSQL .= " ) AS blub"; //postgres wants an alias here
|
||||
|
||||
$aSubSelects[] = $sSQL;
|
||||
}
|
||||
}
|
||||
|
||||
// osmline - interpolated housenumbers
|
||||
$sPlaceIDs = Result::joinIdsByTable($aResults, Result::TABLE_OSMLINE);
|
||||
if ($sPlaceIDs) {
|
||||
$sHousenumbers = Result::sqlHouseNumberTable($aResults, Result::TABLE_OSMLINE);
|
||||
// interpolation line search only if a housenumber was searched
|
||||
// (realized through a join)
|
||||
$sSQL = "SELECT ";
|
||||
$sSQL .= " 'W' AS osm_type, ";
|
||||
$sSQL .= " osm_id, ";
|
||||
$sSQL .= " 'place' AS class, ";
|
||||
$sSQL .= " 'house' AS type, ";
|
||||
$sSQL .= ' 15 AS admin_level, ';
|
||||
$sSQL .= ' 30 AS rank_search, ';
|
||||
$sSQL .= ' 30 AS rank_address, ';
|
||||
$sSQL .= ' place_id, ';
|
||||
$sSQL .= ' parent_place_id, ';
|
||||
$sSQL .= ' housenumber_for_place as housenumber,';
|
||||
$sSQL .= ' country_code, ';
|
||||
$sSQL .= $this->langAddressSql('housenumber_for_place');
|
||||
$sSQL .= ' null AS placename, ';
|
||||
$sSQL .= ' null AS ref, ';
|
||||
if ($this->bExtraTags) $sSQL .= 'null AS extra, ';
|
||||
if ($this->bNameDetails) $sSQL .= 'null AS names, ';
|
||||
$sSQL .= ' st_x(centroid) AS lon, ';
|
||||
$sSQL .= ' st_y(centroid) AS lat, ';
|
||||
// slightly smaller than the importance for normal houses
|
||||
$sSQL .= " -0.1 AS importance, ";
|
||||
$sSQL .= $this->addressImportanceSql('centroid', 'blub.parent_place_id');
|
||||
$sSQL .= " null AS extra_place ";
|
||||
$sSQL .= " FROM (";
|
||||
$sSQL .= " SELECT ";
|
||||
$sSQL .= " osm_id, ";
|
||||
$sSQL .= " place_id, ";
|
||||
$sSQL .= " country_code, ";
|
||||
$sSQL .= " CASE "; // interpolate the housenumbers here
|
||||
$sSQL .= " WHEN startnumber != endnumber ";
|
||||
$sSQL .= " THEN ST_LineInterpolatePoint(linegeo, (housenumber_for_place-startnumber::float)/(endnumber-startnumber)::float) ";
|
||||
$sSQL .= " ELSE ST_LineInterpolatePoint(linegeo, 0.5) ";
|
||||
$sSQL .= " END as centroid, ";
|
||||
$sSQL .= " parent_place_id, ";
|
||||
$sSQL .= " housenumber_for_place ";
|
||||
$sSQL .= " FROM (";
|
||||
$sSQL .= " location_property_osmline ";
|
||||
$sSQL .= " JOIN (values ".$sHousenumbers.") AS housenumbers(place_id, housenumber_for_place) USING(place_id)";
|
||||
$sSQL .= " ) ";
|
||||
$sSQL .= " WHERE housenumber_for_place >= 0 ";
|
||||
$sSQL .= " ) as blub"; //postgres wants an alias here
|
||||
|
||||
$aSubSelects[] = $sSQL;
|
||||
}
|
||||
|
||||
if (CONST_Use_Aux_Location_data) {
|
||||
$sPlaceIDs = Result::joinIdsByTable($aResults, Result::TABLE_AUX);
|
||||
if ($sPlaceIDs) {
|
||||
$sHousenumbers = Result::sqlHouseNumberTable($aResults, Result::TABLE_AUX);
|
||||
$sSQL = " SELECT ";
|
||||
$sSQL .= " 'L' AS osm_type, ";
|
||||
$sSQL .= " place_id AS osm_id, ";
|
||||
$sSQL .= " 'place' AS class,";
|
||||
$sSQL .= " 'house' AS type, ";
|
||||
$sSQL .= ' null AS admin_level, ';
|
||||
$sSQL .= ' 30 AS rank_search,';
|
||||
$sSQL .= ' 30 AS rank_address, ';
|
||||
$sSQL .= ' place_id,';
|
||||
$sSQL .= ' parent_place_id, ';
|
||||
$sSQL .= ' housenumber,';
|
||||
$sSQL .= " 'us' AS country_code, ";
|
||||
$sSQL .= $this->langAddressSql('-1');
|
||||
$sSQL .= " null AS placename, ";
|
||||
$sSQL .= " null AS ref, ";
|
||||
if ($this->bExtraTags) $sSQL .= "null AS extra, ";
|
||||
if ($this->bNameDetails) $sSQL .= "null AS names, ";
|
||||
$sSQL .= " ST_X(centroid) AS lon, ";
|
||||
$sSQL .= " ST_Y(centroid) AS lat, ";
|
||||
$sSQL .= " -1.10 AS importance, ";
|
||||
$sSQL .= $this->addressImportanceSql(
|
||||
'centroid',
|
||||
'location_property_aux.parent_place_id'
|
||||
);
|
||||
$sSQL .= " null AS extra_place ";
|
||||
$sSQL .= " FROM location_property_aux ";
|
||||
$sSQL .= " WHERE place_id in ($sPlaceIDs) ";
|
||||
|
||||
$aSubSelects[] = $sSQL;
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
if ($this->bNameDetails) {
|
||||
if ($aPlace['names']) {
|
||||
$aPlace['sNameDetails'] = json_decode($aPlace['names']);
|
||||
} else {
|
||||
$aPlace['sNameDetails'] = (object) array();
|
||||
if (CONST_Debug) var_dump($aSubSelects);
|
||||
|
||||
if (!sizeof($aSubSelects)) {
|
||||
return null;
|
||||
}
|
||||
|
||||
$aPlaces = chksql(
|
||||
$this->oDB->getAll(join(' UNION ', $aSubSelects)),
|
||||
"Could not lookup place"
|
||||
);
|
||||
|
||||
if (!sizeof($aPlaces)) {
|
||||
return null;
|
||||
}
|
||||
|
||||
if (CONST_Debug) var_dump($aPlaces);
|
||||
|
||||
foreach ($aPlaces as &$aPlace) {
|
||||
if ($this->bAddressDetails) {
|
||||
// to get addressdetails for tiger data, the housenumber is needed
|
||||
$aPlace['aAddress'] = $this->getAddressNames(
|
||||
$aPlace['place_id'],
|
||||
$aPlace['housenumber']
|
||||
);
|
||||
}
|
||||
|
||||
if ($this->bExtraTags) {
|
||||
if ($aPlace['extra']) {
|
||||
$aPlace['sExtraTags'] = json_decode($aPlace['extra']);
|
||||
} else {
|
||||
$aPlace['sExtraTags'] = (object) array();
|
||||
}
|
||||
}
|
||||
|
||||
if ($this->bNameDetails) {
|
||||
if ($aPlace['names']) {
|
||||
$aPlace['sNameDetails'] = json_decode($aPlace['names']);
|
||||
} else {
|
||||
$aPlace['sNameDetails'] = (object) array();
|
||||
}
|
||||
}
|
||||
|
||||
$aClassType = getClassTypes();
|
||||
$sAddressType = '';
|
||||
$sClassType = $aPlace['class'].':'.$aPlace['type'].':'.$aPlace['admin_level'];
|
||||
if (isset($aClassType[$sClassType]) && isset($aClassType[$sClassType]['simplelabel'])) {
|
||||
$sAddressType = $aClassType[$aClassType]['simplelabel'];
|
||||
} else {
|
||||
$sClassType = $aPlace['class'].':'.$aPlace['type'];
|
||||
if (isset($aClassType[$sClassType]) && isset($aClassType[$sClassType]['simplelabel']))
|
||||
$sAddressType = $aClassType[$sClassType]['simplelabel'];
|
||||
else $sAddressType = $aPlace['class'];
|
||||
}
|
||||
|
||||
$aPlace['addresstype'] = $sAddressType;
|
||||
}
|
||||
|
||||
$aClassType = getClassTypes();
|
||||
$sAddressType = '';
|
||||
$sClassType = $aPlace['class'].':'.$aPlace['type'].':'.$aPlace['admin_level'];
|
||||
if (isset($aClassType[$sClassType]) && isset($aClassType[$sClassType]['simplelabel'])) {
|
||||
$sAddressType = $aClassType[$aClassType]['simplelabel'];
|
||||
} else {
|
||||
$sClassType = $aPlace['class'].':'.$aPlace['type'];
|
||||
if (isset($aClassType[$sClassType]) && isset($aClassType[$sClassType]['simplelabel']))
|
||||
$sAddressType = $aClassType[$sClassType]['simplelabel'];
|
||||
else $sAddressType = $aPlace['class'];
|
||||
}
|
||||
if (CONST_Debug) var_dump($aPlaces);
|
||||
|
||||
$aPlace['addresstype'] = $sAddressType;
|
||||
|
||||
return $aPlace;
|
||||
return reset($aPlaces);
|
||||
}
|
||||
|
||||
public function getAddressDetails($iPlaceID, $bAll = false, $housenumber = -1)
|
||||
private function getAddressDetails($iPlaceID, $bAll, $sHousenumber)
|
||||
{
|
||||
$sLanguagePrefArraySQL = "ARRAY[".join(',', array_map("getDBQuoted", $this->aLangPrefOrder))."]";
|
||||
|
||||
$sSQL = "select *,get_name_by_language(name,$sLanguagePrefArraySQL) as localname from get_addressdata(".$iPlaceID.",".$housenumber.")";
|
||||
if (!$bAll) $sSQL .= " WHERE isaddress OR type = 'country_code'";
|
||||
$sSQL .= " order by rank_address desc,isaddress desc";
|
||||
$sSQL = 'SELECT *,';
|
||||
$sSQL .= ' get_name_by_language(name,'.$this->aLangPrefOrderSql.') as localname';
|
||||
$sSQL .= ' FROM get_addressdata('.$iPlaceID.','.$sHousenumber.')';
|
||||
if (!$bAll) {
|
||||
$sSQL .= " WHERE isaddress OR type = 'country_code'";
|
||||
}
|
||||
$sSQL .= ' ORDER BY rank_address desc,isaddress DESC';
|
||||
|
||||
return chksql($this->oDB->getAll($sSQL));
|
||||
}
|
||||
|
||||
public function getAddressNames($iPlaceID, $housenumber = -1)
|
||||
public function getAddressNames($iPlaceID, $sHousenumber = null)
|
||||
{
|
||||
$aAddressLines = $this->getAddressDetails($iPlaceID, false, $housenumber);
|
||||
$aAddressLines = $this->getAddressDetails(
|
||||
$iPlaceID,
|
||||
false,
|
||||
$sHousenumber === null ? -1 : $sHousenumber
|
||||
);
|
||||
|
||||
$aAddress = array();
|
||||
$aFallback = array();
|
||||
|
||||
Reference in New Issue
Block a user