diff --git a/ example/environment /sphinx.conf b/ example/environment /sphinx.conf index e64f191..0b965cc 100644 --- a/ example/environment /sphinx.conf +++ b/ example/environment /sphinx.conf @@ -33,7 +33,25 @@ source peer : yggstate (SELECT GROUP_CONCAT(DISTINCT `peerRemotePort`.`name`) \ FROM `peerRemote` \ JOIN `peerRemotePort` ON (`peerRemotePort`.`peerRemotePortId` = `peerRemote`.`peerRemotePortId`) \ - WHERE `peerRemote`.`peerId` = `peer`.`peerId`) AS `peerRemotePort` \ + WHERE `peerRemote`.`peerId` = `peer`.`peerId`) AS `peerRemotePort`, \ + (SELECT GROUP_CONCAT(DISTINCT `geoCountry`.`isoCode`) \ + FROM `peerRemote` \ + JOIN `geo` ON (`geo`.`geoId` = `peerRemote`.`geoId`) \ + JOIN `geoCountry` ON (`geoCountry`.`geoCountryId` = `geo`.`geoCountryId`) \ + WHERE `peerRemote`.`peerId` = `peer`.`peerId` \ + ) AS `geoCountryIsoCode`, \ + (SELECT GROUP_CONCAT(DISTINCT `geoCountry`.`name`) \ + FROM `peerRemote` \ + JOIN `geo` ON (`geo`.`geoId` = `peerRemote`.`geoId`) \ + JOIN `geoCountry` ON (`geoCountry`.`geoCountryId` = `geo`.`geoCountryId`) \ + WHERE `peerRemote`.`peerId` = `peer`.`peerId` \ + ) AS `geoCountryName`, \ + (SELECT GROUP_CONCAT(DISTINCT `geoCity`.`name`) \ + FROM `peerRemote` \ + JOIN `geo` ON (`geo`.`geoId` = `peerRemote`.`geoId`) \ + JOIN `geoCity` ON (`geoCity`.`geoCityId` = `geo`.`geoCityId`) \ + WHERE `peerRemote`.`peerId` = `peer`.`peerId` \ + ) AS `geoCityName` \ FROM `peer`\ sql_field_string = peerAddress @@ -43,6 +61,9 @@ source peer : yggstate sql_field_string = peerRemoteScheme sql_field_string = peerRemoteHost sql_field_string = peerRemotePort + sql_field_string = geoCountryIsoCode + sql_field_string = geoCountryName + sql_field_string = geoCityName } index peer diff --git a/.gitignore b/.gitignore index c4930c3..f35fda1 100644 --- a/.gitignore +++ b/.gitignore @@ -2,6 +2,7 @@ /vendor/ /database/yggstate.mwb.bak +/storage/GeoLite2/* /src/config/app.php diff --git a/composer.json b/composer.json index 3c62bbf..876c015 100644 --- a/composer.json +++ b/composer.json @@ -7,7 +7,8 @@ "yggverse/yggdrasilctl": ">=0.1.0", "yggverse/parser": ">=0.1.0", "yggverse/graph": ">=0.1.0", - "yggverse/cache": ">=0.3.0" + "yggverse/cache": ">=0.3.0", + "geoip2/geoip2": "~2.0" }, "license": "MIT", "autoload": { diff --git a/database/yggstate.mwb b/database/yggstate.mwb index 941019f..9a2e43c 100644 Binary files a/database/yggstate.mwb and b/database/yggstate.mwb differ diff --git a/media/db-prototype.png b/media/db-prototype.png index 9a09e5d..3707538 100644 Binary files a/media/db-prototype.png and b/media/db-prototype.png differ diff --git a/src/config/app.php.example b/src/config/app.php.example index a2d53a6..35bc19e 100644 --- a/src/config/app.php.example +++ b/src/config/app.php.example @@ -58,6 +58,10 @@ define('MEMCACHED_HOST', 'localhost'); define('MEMCACHED_NAMESPACE', 'yggstate'); define('MEMCACHED_TIMEOUT', 60 * 5); +// GeoIp2 integration by https://www.maxmind.com +define('GEOIP_LITE_2_COUNTRY_DB', __DIR__ . '/../../storage/GeoLite2/GeoLite2-Country.mmdb'); +define('GEOIP_LITE_2_CITY_DB', __DIR__ . '/../../storage/GeoLite2/GeoLite2-City.mmdb'); + // Webapp define('WEBSITE_URL', ''); define('WEBSITE_NAME', 'YGGstate'); diff --git a/src/crontab/crawler.php b/src/crontab/crawler.php index 632092b..957b5f8 100644 --- a/src/crontab/crawler.php +++ b/src/crontab/crawler.php @@ -80,11 +80,31 @@ $debug = [ 'insert' => 0, ], ], + ], + 'geo' => [ + 'total' => [ + 'insert' => 0, + ], + 'country' => [ + 'total' => [ + 'insert' => 0, + ], + ], + 'city' => [ + 'total' => [ + 'insert' => 0, + ], + ], + 'coordinate' => [ + 'total' => [ + 'insert' => 0, + ], + ], ] ] ]; -// Connect database +// Connect DB try { $db = new MySQL(DB_HOST, DB_PORT, DB_NAME, DB_USERNAME, DB_PASSWORD); @@ -96,8 +116,21 @@ try { exit; } +// GeoIp2 +try { + + $geoIp2Country = new GeoIp2\Database\Reader(GEOIP_LITE_2_COUNTRY_DB); + $geoIp2City = new GeoIp2\Database\Reader(GEOIP_LITE_2_CITY_DB); + +} catch(Exception $e) { + + var_dump($e); + + exit; +} + // Collect connected peers -if ($connectedPeers = \Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { +if ($connectedPeers = Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { foreach ($connectedPeers as $connectedPeerAddress => $connectedPeerInfo) { @@ -203,7 +236,7 @@ if ($connectedPeers = \Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { } // Init peer remote - if ($connectedPeerRemoteUrl = \Yggverse\Parser\Url::parse($connectedPeerInfo->remote)) { + if ($connectedPeerRemoteUrl = Yggverse\Parser\Url::parse($connectedPeerInfo->remote)) { // Init peer scheme if ($dbPeerRemoteScheme = $db->findPeerRemoteScheme($connectedPeerRemoteUrl->host->scheme)) { @@ -244,8 +277,90 @@ if ($connectedPeers = \Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { } } + // Init geo data + + /// Country + $countryIsoCode = $geoIp2Country->country($connectedPeerRemoteUrl->host->name)->country->isoCode; + $countryName = $geoIp2Country->country($connectedPeerRemoteUrl->host->name)->country->name; + + $dbGeoCountryId = null; + + if (!empty($countryIsoCode) && !empty($countryName)) { + + if ($dbGeoCountry = $db->findGeoCountryByIsoCode($countryIsoCode)) { + + $dbGeoCountryId = $dbGeoCountry->geoCountryId; + + } else { + + if ($dbGeoCountryId = $db->addGeoCountry($countryIsoCode, $countryName)) { + + $debug['yggdrasil']['geo']['country']['total']['insert']++; + } + } + } + + /// City + $cityName = $geoIp2City->city($connectedPeerRemoteUrl->host->name)->city->name; + + $dbGeoCityId = null; + + if (!empty($cityName)) { + + if ($dbGeoCity = $db->findGeoCityByName($cityName)) { + + $dbGeoCityId = $dbGeoCity->geoCityId; + + } else { + + if ($dbGeoCityId = $db->addGeoCity($cityName)) { + + $debug['yggdrasil']['geo']['city']['total']['insert']++; + } + } + } + + /// Coordinate + $latitude = $geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->latitude; + $longitude = $geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->longitude; + + $dbGeoCoordinateId = null; + + if (!empty($latitude) && !empty($longitude)) { + + if ($dbGeoCoordinate = $db->findGeoCoordinate($geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->latitude, + $geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->longitude)) { + $dbGeoCoordinateId = $dbGeoCoordinate->geoCoordinateId; + + } else { + + if ($dbGeoCoordinateId = $db->addGeoCoordinate($geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->latitude, + $geoIp2City->city($connectedPeerRemoteUrl->host->name)->location->longitude)) { + + $debug['yggdrasil']['geo']['coordinate']['total']['insert']++; + } + } + } + + /// Geo + $dbGeoId = null; + + if ($dbGeo = $db->findGeo($dbGeoCountryId, $dbGeoCityId, $dbGeoCoordinateId)) { + + $dbGeoId = $dbGeo->geoId; + + } else { + + if ($dbGeoId = $db->addGeo($dbGeoCountryId, $dbGeoCityId, $dbGeoCoordinateId)) { + + $debug['yggdrasil']['geo']['total']['insert']++; + } + } + + // Init peer remote if ($dbPeerRemote = $db->findPeerRemote($dbPeerId, + $dbGeoId, $dbPeerRemoteSchemeId, $dbPeerRemoteHostId, $dbPeerRemotePortId)) { @@ -255,6 +370,7 @@ if ($connectedPeers = \Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { } else { if ($dbPeerRemoteId = $db->addPeerRemote($dbPeerId, + $dbGeoId, $dbPeerRemoteSchemeId, $dbPeerRemoteHostId, $dbPeerRemotePortId, @@ -267,6 +383,8 @@ if ($connectedPeers = \Yggverse\Yggdrasilctl\Yggdrasil::getPeers()) { // If something went wrong with URL parse, skip next operations for this peer } else { + $db->rollBack(); + continue; } diff --git a/src/library/mysql.php b/src/library/mysql.php index 204ce33..5372047 100644 --- a/src/library/mysql.php +++ b/src/library/mysql.php @@ -114,29 +114,127 @@ class MySQL { return $query->fetchAll(); } + // Geo + public function findGeo(mixed $geoCountryId, mixed $geoCityId, mixed $geoCoordinateId) { // int|null + + $this->_debug->query->select->total++; + + // @TODO + // UNIQUE keys does not applying for the NULL values, + // another problem that MySQL return no results for = NULL condition + // if someone have better solution, feel free to PR this issue https://github.com/YGGverse/YGGstate/pulls + $query = $this->_db->query("SELECT * FROM `geo` + WHERE `geoCountryId` " . (empty($geoCountryId) ? " IS NULL " : " = " . (int) $geoCountryId ) . " + AND `geoCityId` " . (empty($geoCityId) ? " IS NULL " : " = " . (int) $geoCityId ) . " + AND `geoCoordinateId` " . (empty($geoCoordinateId) ? " IS NULL " : " = " . (int) $geoCoordinateId) . " + LIMIT 1"); + + return $query->fetch(); + } + + public function addGeo(mixed $geoCountryId, mixed $geoCityId, mixed $geoCoordinateId) { + + $this->_debug->query->insert->total++; + + $query = $this->_db->prepare('INSERT INTO `geo` SET `geoCountryId` = ?, + `geoCityId` = ?, + `geoCoordinateId` = ?'); + + $query->execute([$geoCountryId, $geoCityId, $geoCoordinateId]); + + return $this->_db->lastInsertId(); + } + + public function findGeoCountryByIsoCode(string $isoCode) { + + $this->_debug->query->select->total++; + + $query = $this->_db->prepare('SELECT * FROM `geoCountry` WHERE `isoCode` = ? LIMIT 1'); + + $query->execute([$isoCode]); + + return $query->fetch(); + } + + public function addGeoCountry(string $isoCode, string $name) { + + $this->_debug->query->insert->total++; + + $query = $this->_db->prepare('INSERT INTO `geoCountry` SET `isoCode` = ?, `name` = ?'); + + $query->execute([$isoCode, $name]); + + return $this->_db->lastInsertId(); + } + + public function findGeoCityByName(string $name) { + + $this->_debug->query->select->total++; + + $query = $this->_db->prepare('SELECT * FROM `geoCity` WHERE `name` = ? LIMIT 1'); + + $query->execute([$name]); + + return $query->fetch(); + } + + public function addGeoCity(string $name) { + + $this->_debug->query->insert->total++; + + $query = $this->_db->prepare('INSERT INTO `geoCity` SET `name` = ?'); + + $query->execute([$name]); + + return $this->_db->lastInsertId(); + } + + public function findGeoCoordinate(float $latitude, float $longitude) { + + $this->_debug->query->select->total++; + + $query = $this->_db->prepare('SELECT * FROM `geoCoordinate` WHERE `point` = POINT(?, ?) LIMIT 1'); + + $query->execute([$latitude, $longitude]); + + return $query->fetch(); + } + + public function addGeoCoordinate(float $latitude, float $longitude) { + + $this->_debug->query->insert->total++; + + $query = $this->_db->prepare('INSERT INTO `geoCoordinate` SET `point` = POINT(?, ?)'); + + $query->execute([$latitude, $longitude]); + + return $this->_db->lastInsertId(); + } + // Peer remote - public function addPeerRemote(int $peerId, int $peerRemoteSchemeId, int $peerRemoteHostId, int $peerRemotePortId, int $timeAdded) { + public function addPeerRemote(int $peerId, int $geoId, int $peerRemoteSchemeId, int $peerRemoteHostId, int $peerRemotePortId, int $timeAdded) { $this->_debug->query->insert->total++; $query = $this->_db->prepare('INSERT INTO `peerRemote` SET `peerId` = ?, + `geoId` = ?, `peerRemoteSchemeId` = ?, `peerRemoteHostId` = ?, `peerRemotePortId` = ?, `timeAdded` = ?'); - $query->execute([$peerId, $peerRemoteSchemeId, $peerRemoteHostId, $peerRemotePortId, $timeAdded]); + $query->execute([$peerId, $geoId, $peerRemoteSchemeId, $peerRemoteHostId, $peerRemotePortId, $timeAdded]); return $this->_db->lastInsertId(); } - public function findPeerRemote(int $peerId, int $peerRemoteSchemeId, int $peerRemoteHostId, int $peerRemotePortId) { + public function findPeerRemote(int $peerId, int $geoId, int $peerRemoteSchemeId, int $peerRemoteHostId, int $peerRemotePortId) { $this->_debug->query->select->total++; - $query = $this->_db->prepare('SELECT * FROM `peerRemote` WHERE `peerId` = ? AND `peerRemoteSchemeId` = ? AND `peerRemoteHostId` = ? AND `peerRemotePortId` = ? LIMIT 1'); + $query = $this->_db->prepare('SELECT * FROM `peerRemote` WHERE `peerId` = ? AND `geoId` = ? AND `peerRemoteSchemeId` = ? AND `peerRemoteHostId` = ? AND `peerRemotePortId` = ? LIMIT 1'); - $query->execute([$peerId, $peerRemoteSchemeId, $peerRemoteHostId, $peerRemotePortId]); + $query->execute([$peerId, $geoId, $peerRemoteSchemeId, $peerRemoteHostId, $peerRemotePortId]); return $query->fetch(); } @@ -189,9 +287,21 @@ class MySQL { $this->_debug->query->select->total++; - $query = $this->_db->prepare('SELECT * FROM `peerRemotePort` WHERE `name` = ? LIMIT 1'); + // @TODO + // UNIQUE keys does not applying for the NULL values, + // another problem that MySQL return no results for = NULL condition + // if someone have better solution, feel free to PR this issue https://github.com/YGGverse/YGGstate/pulls + if (empty($name)) { + + $query = $this->_db->query('SELECT * FROM `peerRemotePort` WHERE `name` IS NULL LIMIT 1'); + + } else { + + $query = $this->_db->prepare('SELECT * FROM `peerRemotePort` WHERE `name` = ? LIMIT 1'); + + $query->execute([$name]); + } - $query->execute([$name]); return $query->fetch(); } @@ -517,6 +627,13 @@ class MySQL { `peerCoordinate`.`port` AS `connectionPort`, + ( + SELECT GROUP_CONCAT(`port` SEPARATOR ' → ') + FROM `peerCoordinateRoute` + WHERE `peerCoordinateRoute`.`peerCoordinateId` = `peerConnection`.`peerCoordinateId` + ORDER BY `peerCoordinateRoute`.`level` ASC + ) AS `route`, + CONCAT ( IF (`peerRemotePort`.`name` IS NOT NULL, @@ -525,12 +642,9 @@ class MySQL { ) ) AS `remote`, - ( - SELECT GROUP_CONCAT(`port` SEPARATOR ' → ') - FROM `peerCoordinateRoute` - WHERE `peerCoordinateRoute`.`peerCoordinateId` = `peerConnection`.`peerCoordinateId` - ORDER BY `peerCoordinateRoute`.`level` ASC - ) AS `route` + `geoCountry`.`isoCode` AS `geoCountryIsoCode`, + `geoCountry`.`name` `geoCountryName`, + `geoCity`.`name` AS `geoCityName` FROM `peerConnection` @@ -544,6 +658,10 @@ class MySQL { JOIN `peer` ON (`peer`.`peerId` = `peerRemote`.`peerId`) + LEFT JOIN `geo` ON (`geo`.`geoId` = `peerRemote`.`geoId`) + LEFT JOIN `geoCountry` ON (`geoCountry`.`geoCountryId` = `geo`.`geoCountryId`) + LEFT JOIN `geoCity` ON (`geoCity`.`geoCityId` = `geo`.`geoCityId`) + WHERE `peerRemote`.`peerId` = :peerId GROUP BY `peerConnection`.`peerConnectionId` diff --git a/src/library/sphinxql.php b/src/library/sphinxql.php index 65de5ed..154880e 100644 --- a/src/library/sphinxql.php +++ b/src/library/sphinxql.php @@ -66,7 +66,7 @@ class SphinxQL { } return sprintf( - '@peerAddress "%s" | @peerKey "%s" | @peerCoordinatePort "%s" | @peerCoordinateRoute "%s" | @peerRemoteScheme "%s" | @peerRemoteHost "%s" | @peerRemotePort "%s"', + '@peerAddress "%s" | @peerKey "%s" | @peerCoordinatePort "%s" | @peerCoordinateRoute "%s" | @peerRemoteScheme "%s" | @peerRemoteHost "%s" | @peerRemotePort "%s" | @geoCountryIsoCode "%s" | @geoCountryName "%s" | @geoCityName "%s"', preg_replace('/[^A-z0-9\:\[\]]/', '', $peerAddress), preg_replace('/[^A-z0-9]/', '', $keyword), preg_replace('/[^\d]/', '', $keyword), @@ -74,6 +74,9 @@ class SphinxQL { preg_replace('/[^A-z]/', '', $peerRemoteScheme), preg_replace('/[^A-z0-9\.\:\[\]]/', '', $peerRemoteHost), preg_replace('/[^\d]/', '', $peerRemotePort), + preg_replace('/[^A-z]/', '', $keyword), + preg_replace('/[^A-z]/', '', $keyword), + preg_replace('/[^A-z]/', '', $keyword), ); } } diff --git a/src/public/index.php b/src/public/index.php index ff2d1af..b6f09f7 100644 --- a/src/public/index.php +++ b/src/public/index.php @@ -181,7 +181,7 @@ $peers = $memory->getByMethodCallback(
diff --git a/src/public/peer.php b/src/public/peer.php index 908e196..b488351 100644 --- a/src/public/peer.php +++ b/src/public/peer.php @@ -135,7 +135,7 @@ $peerInfo = $memory->getByMethodCallback($db, 'getPeerInfo', [$requestPeerId]); @@ -173,6 +173,9 @@ $peerInfo = $memory->getByMethodCallback($db, 'getPeerInfo', [$requestPeerId]);