Skip to content

HTTPS clone URL

Subversion checkout URL

You can clone with HTTPS or Subversion.

Download ZIP
Browse files

Initial version.

  • Loading branch information...
commit 9668dd948efc9884ad69737be6f342188c88edc9 0 parents
@tvondra authored
65 INSTALL
@@ -0,0 +1,65 @@
+To build it, just do this:
+
+ make
+ make installcheck
+ make install
+
+If you encounter an error such as:
+
+ "Makefile", line 8: Need an operator
+
+You need to use GNU make, which may well be installed on your system as
+`gmake`:
+
+ gmake
+ gmake install
+ gmake installcheck
+
+If you encounter an error such as:
+
+ make: pg_config: Command not found
+
+Be sure that you have `pg_config` installed and in your path. If you used a
+package management system such as RPM to install PostgreSQL, be sure that the
+`-devel` package is also installed. If necessary tell the build process where
+to find it:
+
+ env PG_CONFIG=/path/to/pg_config make && make installcheck && make install
+
+And finally, if all that fails (and if you're on PostgreSQL 8.1 or lower, it
+likely will), copy the entire distribution directory to the `contrib/`
+subdirectory of the PostgreSQL source tree and try it there without
+`pg_config`:
+
+ env NO_PGXS=1 make && make installcheck && make install
+
+If you encounter an error such as:
+
+ ERROR: must be owner of database regression
+
+You need to run the test suite using a super user, such as the default
+"postgres" super user:
+
+ make installcheck PGUSER=postgres
+
+Once geoip is installed, you can add it to a database. If you're running
+PostgreSQL 9.1.0 or greater, it's a simple as connecting to a database as a
+super user and running:
+
+ CREATE EXTENSION geoip;
+
+If you've upgraded your cluster to PostgreSQL 9.1 and already had geoip
+installed, you can upgrade it to a properly packaged extension with:
+
+ CREATE EXTENSION geoip FROM unpackaged;
+
+For versions of PostgreSQL less than 9.1.0, you'll need to run the
+installation script:
+
+ psql -d mydb -f /path/to/pgsql/share/contrib/geoip.sql
+
+If you want to install geoip and all of its supporting objects into a specific
+schema, use the `PGOPTIONS` environment variable to specify the schema, like
+so:
+
+ PGOPTIONS=--search_path=extensions psql -d mydb -f geoip.sql
25 LICENSE
@@ -0,0 +1,25 @@
+Copyright 2012, Tomas Vondra (tv@fuzzy.cz). All rights reserved.
+
+Redistribution and use in source and binary forms, with or without modification, are
+permitted provided that the following conditions are met:
+
+ 1. Redistributions of source code must retain the above copyright notice, this list of
+ conditions and the following disclaimer.
+
+ 2. Redistributions in binary form must reproduce the above copyright notice, this list
+ of conditions and the following disclaimer in the documentation and/or other materials
+ provided with the distribution.
+
+THIS SOFTWARE IS PROVIDED BY TOMAS VONDRA ''AS IS'' AND ANY EXPRESS OR IMPLIED
+WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND
+FITNESS FOR A PARTICULAR PURPOSE ARE DISCLAIMED. IN NO EVENT SHALL TOMAS VONDRA OR
+CONTRIBUTORS BE LIABLE FOR ANY DIRECT, INDIRECT, INCIDENTAL, SPECIAL, EXEMPLARY, OR
+CONSEQUENTIAL DAMAGES (INCLUDING, BUT NOT LIMITED TO, PROCUREMENT OF SUBSTITUTE GOODS OR
+SERVICES; LOSS OF USE, DATA, OR PROFITS; OR BUSINESS INTERRUPTION) HOWEVER CAUSED AND ON
+ANY THEORY OF LIABILITY, WHETHER IN CONTRACT, STRICT LIABILITY, OR TORT (INCLUDING
+NEGLIGENCE OR OTHERWISE) ARISING IN ANY WAY OUT OF THE USE OF THIS SOFTWARE, EVEN IF
+ADVISED OF THE POSSIBILITY OF SUCH DAMAGE.
+
+The views and conclusions contained in the software and documentation are those of the
+authors and should not be interpreted as representing official policies, either expressed
+or implied, of Tomas Vondra.
41 META.json
@@ -0,0 +1,41 @@
+{
+ "name": "geoip",
+ "abstract": "Geolocation using GeoIP.",
+ "description": "Provides geolocation (determining country, city etc. from an IP address) using GeoIP data.",
+ "version": "0.0.1",
+ "maintainer": "Tomas Vondra <tv@fuzzy.cz>",
+ "license": "bsd",
+
+ "provides": {
+ "geoip": {
+ "file": "sql/geoip--0.0.1.sql",
+ "docfile": "doc/README.md",
+ "version": "0.0.1"
+ }
+ },
+
+ "prereqs": {
+ "runtime": {
+ "requires": {
+ "PostgreSQL": "8.3.0"
+ }
+ }
+ },
+
+ "release_status": "testing",
+
+ "resources": {
+ "repository": {
+ "url": "https://tvondra@github.com/tvondra/geoip.git",
+ "web": "http://github.com/tvondra/geoip",
+ "type": "git"
+ }
+ },
+
+ "tags" : ["geolocation", "geoip", "ip"],
+
+ "meta-spec": {
+ "version": "1.0.0",
+ "url": "http://pgxn.org/meta/spec.txt"
+ }
+}
12 Makefile
@@ -0,0 +1,12 @@
+EXTENSION = geoip
+
+DATA = $(wildcard sql/*.sql)
+DOCS = $(wildcard doc/*.md)
+TESTS = $(wildcard test/sql/*.sql)
+REGRESS = $(patsubst test/sql/%.sql,%,$(TESTS))
+REGRESS_OPTS = --inputdir=test --load-language=plpgsql
+PG_CONFIG = pg_config
+PG91 = $(shell $(PG_CONFIG) --version | grep -qE " 8\.| 9\.0" && echo no || echo yes)
+
+PGXS := $(shell $(PG_CONFIG) --pgxs)
+include $(PGXS)
159 README.md
@@ -0,0 +1,159 @@
+geoip
+=====
+
+This extension provides IP-based geolocation, i.e. you provide an IPv4
+address and the extension looks for info about country, city, GPS etc.
+
+To operate, the extension needs data mapping IP addresses to the other
+info, but these data are not part of the extension. A good free dataset
+is GeoLite from MaxMind (available at www.maxmind.com).
+
+Installation
+------------
+
+To install the extension, basically all you need to do is this
+
+ make install
+
+and then (if you're on PostgreSQL 9.1 or above)
+
+ CREATE EXTENSION geoip;
+
+For versions of PostgreSQL less than 9.1.0, you'll need to run the
+installation script manually:
+
+ psql -d mydb -f /path/to/pgsql/share/contrib/geoip.sql
+
+Now you're ready to use the extension. More details about the installation
+options and issues are available in the INSTALL file.
+
+
+Using the extension
+-------------------
+
+The extension allows you to search for country, city and ASN. All of that
+is encapsulated into these functions:
+
+ * geoip_country_code(inet) - returns country code (2 chars)
+ * geoip_country(inet) - returns all country info (code, name, ...)
+ * geoip_city_location(inet) - returns just location ID (INT)
+ * geoip_city(inet) - returns all the city info (GPS, ZIP code, ...)
+ * geoip_asn(inet) - retusn ASN name and IP range
+
+Using the functions is quite straightforward, especially for functions that
+return a single value
+
+ db=# SELECT geoip_country_code('78.45.133.255'::inet);
+
+ geoip_country_code
+ --------------------
+ CZ
+ (1 row)
+
+ db=# SELECT geoip_city_location('78.45.133.255'::inet);
+
+ geoip_city_location
+ ---------------------
+ 21235
+ (1 row)
+
+The functions that return a tuple are a bit more complicated. Probably the
+best way to call them is like a SRF:
+
+ db=# SELECT * FROM geoip_city('78.45.133.255'::inet);
+
+ loc_id | country | region | city | latitude | longitude | ...
+ --------+---------+--------+--------+----------+-----------+-----
+ 21235 | CZ | 52 | Prague | 50.0833 | 14.4667 | ...
+
+ db=# SELECT * FROM geoip_country('78.45.133.255'::inet);
+
+ begin_ip | end_ip | country | name
+ -----------+---------------+---------+----------------
+ 78.44.0.0 | 78.45.255.255 | CZ | Czech Republic
+ (1 row)
+
+ db=# SELECT * FROM geoip_asn('78.45.133.255'::inet);
+
+ begin_ip | end_ip | name
+ -----------+---------------+-----------------------------------
+ 78.44.0.0 | 78.45.255.255 | AS6830 UPC Broadband Holding B.V.
+ (1 row)
+
+Sure, you can access the data directly through the tables.
+
+Loading the data
+----------------
+This extension requires manual downloading and loading the data. Once
+you have the extension installed (so that the tables exist), go to
+http://www.maxmind.com and download the CSV files
+
+ * http://www.maxmind.com/app/geolitecountry - GeoIPCountryCSV.zip
+ * http://www.maxmind.com/app/geolitecity - GeoLiteCity_20120207.zip
+ * http://www.maxmind.com/app/asnum - GeoIPASNum2.zip
+
+Now we need to preprocess the CSV files so that it's possible to load
+them into the tables with a COPY. First, unzip the GeoIPCountryCSV.zip
+and remove the two columns with IP addresses encoded as INT values.
+
+ $ unzip GeoIPCountryCSV.zip
+ $ sed 's/^\("[^"]*","[^"]*",\)"[^"]*","[^"]*",\("[^"]*","[^"]*"\)/\1\2/' \
+ GeoIPCountryWhois.csv > countries.csv
+
+Now unzip the GeoLite city data and remove the first two rows (header)
+
+ $ tail -$((`wc -l GeoLiteCity-Blocks.csv | awk '{print $1}'`-2)) \
+ GeoLiteCity-Blocks.csv > blocks.csv
+
+ $ tail -$((`wc -l GeoLiteCity-Location.csv | awk '{print $1}'`-2)) \
+ GeoLiteCity-Location.csv > locations.csv
+
+It's time to load the data into the database. There's still a bit of
+transforming that needs to be done (and doing it in shell would be
+awkward), so we'll create a few temporary tables. So log in to the
+database and do this (the PATH needs to be replaced with an actual
+absolute path to the files).
+
+ COPY geoip_country FROM 'PATH/countries.csv'
+ WITH csv DELIMITER ',' NULL '' QUOTE '"' ENCODING 'ISO-8859-2';
+
+ CREATE TEMPORARY TABLE geoip_city_block_tmp (
+ begin_ip BIGINT NOT NULL,
+ end_ip BIGINT NOT NULL,
+ loc_id INTEGER NOT NULL
+ );
+
+ CREATE TEMPORARY TABLE geoip_asn_tmp (
+ begin_ip BIGINT NOT NULL,
+ end_ip BIGINT NOT NULL,
+ name TEXT NOT NULL
+ );
+
+ COPY geoip_city_block_tmp FROM 'PATH/blocks.csv'
+ WITH csv DELIMITER ',' NULL '' QUOTE '"' ENCODING 'ISO-8859-2';
+
+ COPY geoip_city_location FROM 'PATH/locations.csv'
+ WITH csv DELIMITER ',' NULL '' QUOTE '"' ENCODING 'ISO-8859-2';
+
+ COPY geoip_asn_tmp FROM 'PATH/GeoIPASNum2.csv'
+ WITH csv DELIMITER ',' NULL '' QUOTE '"' ENCODING 'ISO-8859-2';
+
+ INSERT INTO geoip_city_block
+ SELECT geoip_bigint_to_inet(begin_ip),
+ geoip_bigint_to_inet(end_ip), loc_id
+ FROM geoip_city_block_tmp;
+
+ INSERT INTO geoip_asn
+ SELECT geoip_bigint_to_inet(begin_ip),
+ geoip_bigint_to_inet(end_ip), name
+ FROM geoip_asn_tmp;
+
+ ANALYZE;
+
+Now the data is loaded.
+
+
+Copyright and License
+---------------------
+Copyright (c) 2012 Tomas Vondra
+The extension is distributed under BSD license (see the LICENSE file)
33 doc/geoip.md
@@ -0,0 +1,33 @@
+geoip
+=====
+
+Synopsis
+--------
+
+ Show a brief synopsis of the extension.
+
+Description
+-----------
+
+A long description
+
+Usage
+-----
+
+ Show usage.
+
+Support
+-------
+
+ There is issues tracker? Github? Put this information here.
+
+Author
+------
+
+[The maintainer's name]
+
+Copyright and License
+---------------------
+
+Copyright (c) 2012 The maintainer's name.
+
5 geoip.control
@@ -0,0 +1,5 @@
+# geoip extension
+comment = 'An IP geolocation extension (a wrapper around the MaxMind GeoLite dataset)'
+default_version = '0.0.1'
+module_pathname = '$libdir/geoip'
+relocatable = true
185 sql/geoip--0.0.1.sql
@@ -0,0 +1,185 @@
+/*
+ * Author: Tomas Vondra
+ * Created at: Sat Mar 31 22:51:21 +0200 2012
+ *
+ */
+
+CREATE TABLE geoip_country (
+ begin_ip INET NOT NULL,
+ end_ip INET NOT NULL,
+ country CHAR(2) NOT NULL,
+ name VARCHAR(100) NOT NULL,
+ CONSTRAINT valid_range CHECK (begin_ip <= end_ip)
+);
+
+CREATE TABLE geoip_city_location (
+ loc_id INTEGER PRIMARY KEY,
+ country CHAR(2) NOT NULL,
+ region CHAR(2),
+ city VARCHAR(100),
+ postal_code VARCHAR(10),
+ latitude DOUBLE PRECISION,
+ longitude DOUBLE PRECISION,
+ metro_code INT,
+ area_code INT
+);
+
+CREATE TABLE geoip_city_block (
+ begin_ip INET NOT NULL,
+ end_ip INET NOT NULL,
+ loc_id INTEGER NOT NULL REFERENCES geoip_city_location(loc_id)
+);
+
+CREATE TABLE geoip_asn (
+ begin_ip INET NOT NULL,
+ end_ip INET NOT NULL,
+ name TEXT NOT NULL
+);
+
+-- indexes (might be improved to handle index-only scans)
+CREATE INDEX geoip_country_ip_idx ON geoip_country (begin_ip DESC);
+CREATE INDEX geoip_city_block_ip_idx ON geoip_city_block (begin_ip DESC);
+CREATE INDEX geoip_asn_ip_idx ON geoip_asn (begin_ip DESC);
+
+/** functions used to search data by IP **/
+
+-- search country, returns just the country code (2 characters)
+CREATE OR REPLACE FUNCTION geoip_country_code(p_ip INET) RETURNS CHAR(2) AS $$
+
+ SELECT country
+ FROM geoip_country
+ WHERE $1 >= begin_ip ORDER BY begin_ip DESC LIMIT 1;
+
+$$ LANGUAGE sql;
+
+-- search city, returns just the location ID (PK of the geoip_city_location)
+CREATE OR REPLACE FUNCTION geoip_city_location(p_ip INET) RETURNS INT AS $$
+
+ SELECT loc_id
+ FROM geoip_city_block
+ WHERE $1 >= begin_ip ORDER BY begin_ip DESC LIMIT 1;
+
+$$ LANGUAGE sql;
+
+-- search city, returns all the city details (zipcode, GPS etc.)
+CREATE OR REPLACE FUNCTION geoip_city(p_ip INET, OUT loc_id INT, OUT country CHAR(2), OUT region CHAR(2),
+ OUT city VARCHAR(100), OUT postal_code VARCHAR(10),
+ OUT latitude DOUBLE PRECISION, OUT longitude DOUBLE PRECISION,
+ OUT metro_code INT, OUT area_code INT) AS $$
+
+ SELECT l.loc_id, country, region, city, postal_code, latitude, longitude, metro_code, area_code
+ FROM geoip_city_block b JOIN geoip_city_location l ON (b.loc_id = l.loc_id)
+ WHERE $1 >= begin_ip ORDER BY begin_ip DESC LIMIT 1;
+
+$$ LANGUAGE sql;
+
+-- search country, returns all the details
+CREATE OR REPLACE FUNCTION geoip_country(p_ip INET, OUT begin_ip INET, OUT end_ip INET,
+ OUT country CHAR(2), OUT name VARCHAR(100)) AS $$
+
+ SELECT begin_ip, end_ip, country, name
+ FROM geoip_country WHERE $1 >= begin_ip ORDER BY begin_ip DESC LIMIT 1;
+
+$$ LANGUAGE sql;
+
+-- search ASN, returns the IP range and ASN name
+CREATE OR REPLACE FUNCTION geoip_asn(p_ip INET, OUT begin_ip INET, OUT end_ip INET,
+ OUT name VARCHAR(100)) AS $$
+
+ SELECT begin_ip, end_ip, name
+ FROM geoip_asn WHERE $1 >= begin_ip ORDER BY begin_ip DESC LIMIT 1;
+
+$$ LANGUAGE sql;
+
+/** functions used to search data by IP **/
+
+-- check consistency of the country table
+CREATE OR REPLACE FUNCTION geoip_country_check() RETURNS BOOLEAN AS $$
+DECLARE
+ v_previous RECORD;
+ v_country RECORD;
+ v_first BOOLEAN := TRUE;
+ v_valid BOOLEAN := TRUE;
+BEGIN
+
+ FOR v_country IN SELECT * FROM geoip_country ORDER BY begin_ip ASC LOOP
+
+ IF (NOT v_first) THEN
+ v_first := FALSE;
+ IF (v_previous.end_ip + 1 != v_country.begin_ip) THEN
+ RAISE WARNING 'there''s a hole between %-% and %-%',v_previous.begin_ip,
+ v_previous.end_ip,v_country.begin_ip,v_country.end_ip;
+ v_valid := FALSE;
+ END IF;
+ END IF;
+
+ v_previous := v_country;
+
+ END LOOP;
+
+ RETURN v_valid;
+
+END;
+$$ LANGUAGE plpgsql;
+
+-- check consistency of the city table
+CREATE OR REPLACE FUNCTION geoip_city_check() RETURNS BOOLEAN AS $$
+DECLARE
+ v_previous RECORD;
+ v_block RECORD;
+ v_first BOOLEAN := TRUE;
+ v_valid BOOLEAN := TRUE;
+BEGIN
+
+ FOR v_block IN SELECT begin_ip, end_ip FROM geoip_city_block ORDER BY begin_ip ASC LOOP
+
+ IF (NOT v_first) THEN
+ v_first := FALSE;
+ IF (v_previous.end_ip + 1 != v_block.begin_ip) THEN
+ RAISE WARNING 'there''s a hole between %-% and %-%',v_previous.begin_ip,
+ v_previous.end_ip,v_block.begin_ip,v_block.end_ip;
+ v_valid := FALSE;
+ END IF;
+ END IF;
+
+ v_previous := v_block;
+
+ END LOOP;
+
+ RETURN v_valid;
+
+END;
+$$ LANGUAGE plpgsql;
+
+-- check consistency of the ASN table
+CREATE OR REPLACE FUNCTION geoip_asn_check() RETURNS BOOLEAN AS $$
+DECLARE
+ v_previous RECORD;
+ v_block RECORD;
+ v_first BOOLEAN := TRUE;
+ v_valid BOOLEAN := TRUE;
+BEGIN
+
+ FOR v_block IN SELECT begin_ip, end_ip FROM geoip_asn ORDER BY begin_ip ASC LOOP
+
+ IF (NOT v_first) THEN
+ v_first := FALSE;
+ IF (v_previous.end_ip + 1 != v_block.begin_ip) THEN
+ RAISE WARNING 'there''s a hole between %-% and %-%',v_previous.begin_ip,
+ v_previous.end_ip,v_block.begin_ip,v_block.end_ip;
+ v_valid := FALSE;
+ END IF;
+ END IF;
+
+ v_previous := v_block;
+
+ END LOOP;
+
+ RETURN v_valid;
+
+END;
+$$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION geoip_bigint_to_inet(p_ip BIGINT) RETURNS inet AS $$
+ SELECT (($1 >> 24 & 255) || '.' || ($1 >> 16 & 255) || '.' || ($1 >> 8 & 255) || '.' || ($1 & 255))::inet
+$$ LANGUAGE sql strict immutable;
0  sql/uninstall_geoip.sql
No changes.
2  test/expected/base.out
@@ -0,0 +1,2 @@
+\set ECHO 0
+ROLLBACK;
8 test/sql/base.sql
@@ -0,0 +1,8 @@
+\set ECHO 0
+BEGIN;
+\i sql/geoip.sql
+\set ECHO all
+
+-- Tests goes here.
+
+ROLLBACK;
Please sign in to comment.
Something went wrong with that request. Please try again.