Skip to content

Commit

Permalink
- Added basic geo IP querying using api.geoiplookup.net.
Browse files Browse the repository at this point in the history
- Added example queries to look at blocked client stats and stats by country

Signed-off-by: Ryan Conrad <[email protected]>
  • Loading branch information
Ryan Conrad authored and Ryan Conrad committed Jun 20, 2018
1 parent 63eccf8 commit a5cc203
Show file tree
Hide file tree
Showing 4 changed files with 141 additions and 0 deletions.
16 changes: 16 additions & 0 deletions Blocked Client Locations.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,16 @@
select cs.IPAddress,
cs.LastFailedLogin,
cs.UnblockDate,
cs.FailedLogins,
cs.Blocked,
cs.FirewallRule,
g.Host,
g.ISP,
g.City,
g.CountryName,
g.Latitude,
g.Longitude
from ClientStatus cs
left join GeoIP g
on g.IPAddress = cs.IPAddress
order by cs.LastFailedLogin desc
7 changes: 7 additions & 0 deletions Country Statistics.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
select g.CountryName,
sum(Blocks),
sum(LoginFailures)
from ClientStatistics c, GeoIP g
where c.IPAddress = g.IPAddress
group by g.CountryName
order by 2 desc
60 changes: 60 additions & 0 deletions LoginMonitor.ps1
Original file line number Diff line number Diff line change
Expand Up @@ -16,6 +16,64 @@ function Get-DBConnectionString
return $ConnectionString
}

function Log-GeoIP
{
[cmdletbinding()]
Param
(
[parameter(position = 0, Mandatory=$true)]
[System.Data.SQLClient.SQLConnection]
$Connection,
[parameter(position = 1, Mandatory=$true)]
[string]
$IPAddress
)

$url = "http://api.geoiplookup.net/?query=" + $IPAddress
$http_Request = [System.Net.WebClient]::new()
try
{
[xml] $Result = $http_Request.DownloadString($url)

$Hst = $Result.ip.results.result.host
$ISP = $Result.ip.results.result.isp
$City = $Result.ip.results.result.city
$CountryCode = $Result.ip.results.result.countrycode
$CountryName = $Result.ip.results.result.countryname
$Latitude = $Result.ip.results.result.latitude
$Longitude = $Result.ip.results.result.longitude

$Command = [System.Data.SqlClient.SqlCommand]::new('dbo.InsertGeoIP', $Connection)
$Command.CommandType = [System.Data.CommandType]::StoredProcedure

try
{
$null = $Command.Parameters.AddWithValue('@IPAddress', $IPAddress)
$null = $Command.Parameters.AddWithValue('@Host', $Hst)
$null = $Command.Parameters.AddWithValue('@ISP', $ISP)
$null = $Command.Parameters.AddWithValue('@City', $City)
$null = $Command.Parameters.AddWithValue('@CountryCode', $CountryCode)
$null = $Command.Parameters.AddWithValue('@CountryName', $CountryName)
$null = $Command.Parameters.AddWithValue('@Latitude', $Latitude)
$null = $Command.Parameters.AddWithValue('@Longitude', $Longitude)

$Command.ExecuteNonQuery()
}
finally
{
$Command.Dispose()
}
}
catch
{
return
}
finally
{
$http_Request.Dispose()
}
}

function Add-BlockRule
{
[cmdletbinding()]
Expand Down Expand Up @@ -396,6 +454,8 @@ function On-FailedLogin
#Firewall rule was created so the record is updated in ClientStatus
Update-BlockedClient $Connection $IPAddress $FirewallRule
}

Log-GeoIP $Connection $IPAddress
}
finally
{
Expand Down
58 changes: 58 additions & 0 deletions LoginMonitor.sql
Original file line number Diff line number Diff line change
Expand Up @@ -88,6 +88,20 @@ CREATE TABLE Whitelist
IPAddress VARCHAR(100) NOT NULL PRIMARY KEY,
Description VARCHAR(255)
);

CREATE TABLE GeoIP
(
IPAddress VARCHAR(100) NOT NULL PRIMARY KEY,
Host VARCHAR(512),
ISP VARCHAR(512),
City VARCHAR(255),
CountryCode VARCHAR(2),
CountryName VARCHAR(100),
Latitude FLOAT,
Longitude FLOAT,
LastUpdate DATETIME DEFAULT GETDATE()
);

GO

CREATE VIEW BlockedClient
Expand Down Expand Up @@ -498,6 +512,50 @@ BEGIN
END
GO

CREATE PROCEDURE InsertGeoIP
(
@IPAddress VARCHAR(100),
@Host VARCHAR(512),
@ISP VARCHAR(512),
@City VARCHAR(255),
@CountryCode VARCHAR(2),
@CountryName VARCHAR(100),
@Latitude FLOAT,
@Longitude FLOAT
)
AS
BEGIN
SET NOCOUNT ON;
MERGE INTO GeoIP AS t USING
(
VALUES(@IPAddress, @Host, @ISP, @City, @CountryCode, @CountryName, @Latitude, @Longitude)
)s(IPAddress, Host, ISP, City, CountryCode, CountryName, Latitude, Longitude)
ON t.IPAddress = s.IPAddress
WHEN NOT MATCHED THEN
INSERT(IPAddress, Host, ISP, City, CountryCode, CountryName, Latitude, Longitude)
VALUES(s.IPAddress, s.Host, s.ISP, s.City, s.CountryCode, s.CountryName, s.Latitude, s.Longitude)
WHEN MATCHED
AND (
COALESCE(s.Host, '') <> COALESCE(t.host, '')
OR COALESCE(s.ISP, '') <> COALESCE(t.ISP, '')
OR COALESCE(s.City, '') <> COALESCE(t.City, '')
OR COALESCE(s.CountryCode, '') <> COALESCE(t.CountryCode, '')
OR COALESCE(s.CountryName, '') <> COALESCE(t.CountryName, '')
OR COALESCE(s.Latitude, 0) <> COALESCE(t.Latitude, 0)
OR COALESCE(s.Longitude, 0) <> COALESCE(t.Longitude, 0)
)
THEN
UPDATE SET t.Host = s.Host,
t.ISP = s.ISP,
t.City = s.City,
t.CountryCode = s.CountryCode,
t.CountryName = s.CountryName,
t.Latitude = s.Latitude,
t.Longitude = s.Longitude,
t.LastUpdate = GETDATE();
END
GO

/*
Create role for access to unblock clients via BlockedClient/BlockedClientDtl tables
*/
Expand Down

0 comments on commit a5cc203

Please sign in to comment.