Permalink
Browse files

use ip2location database when available

  • Loading branch information...
1 parent b87e0ee commit db4ecb69609c483a60fcfcd581cb9e876eb9d761 @aaronsw aaronsw committed Oct 3, 2012
Showing with 92 additions and 22 deletions.
  1. +21 −1 app/models/signature.rb
  2. +1 −21 db/schema.rb
  3. +70 −0 script/import_ip2location
View
@@ -66,9 +66,29 @@ def prepopulate(member)
s.email = member.try(:email)
end
end
+
+ def fetch_location ip
+ def ip2bigint ip
+ # > ip2bigint '161.132.13.1'
+ # => 2709785857
+ a, b, c, d = ip.split('.').map(&:to_i)
+ return a*256**3 + b*256**2 + c*256 + d
+ end
+
+ c = ActiveRecord::Base.connection
+ if c.table_exists? 'ip_locations'
+ q1 = c.quote(ip2bigint(ip))
+ result = c.execute "SELECT * FROM ip_locations WHERE box(point(ip_from,ip_from),point(ip_to,ip_to)) @> box(point (#{q1},#{q1}), point(#{q1},#{q1}))"
+ out = OpenStruct.new(result.first)
+ out.state = out.region
+ return out
+ else
+ return Geocoder.search(ip).first
+ end
+ end
def geolocate
- return unless place = Geocoder.search(ip_address).first
+ return unless place = fetch_location(ip_address)
self.city = place.city
self.metrocode = place.metrocode
self.state = place.state
View
@@ -133,8 +133,8 @@
t.datetime "created_at", :null => false
t.datetime "updated_at", :null => false
t.integer "signature_id"
- t.datetime "opened_at"
t.datetime "clicked_at"
+ t.datetime "opened_at"
end
add_index "sent_emails", ["created_at"], :name => "index_sent_emails_on_created_at"
@@ -208,26 +208,6 @@
t.boolean "is_admin", :default => false, :null => false
end
- add_foreign_key "bounced_emails", "sent_emails", :name => "bounced_emails_sent_email_id_fk"
-
add_foreign_key "facebook_friends", "members", :name => "facebook_friends_member_id_fk"
- add_foreign_key "petition_images", "petitions", :name => "petition_images_petition_id_fk"
-
- add_foreign_key "petition_titles", "petitions", :name => "petition_titles_petition_id_fk"
-
- add_foreign_key "petitions", "users", :name => "petitions_owner_id_fk", :column => "owner_id"
-
- add_foreign_key "sent_emails", "members", :name => "sent_emails_member_id_fk"
- add_foreign_key "sent_emails", "petitions", :name => "sent_emails_petition_id_fk"
- add_foreign_key "sent_emails", "signatures", :name => "sent_emails_signature_id_fk"
-
- add_foreign_key "signatures", "members", :name => "signatures_member_id_fk"
- add_foreign_key "signatures", "petitions", :name => "signatures_petition_id_fk"
-
- add_foreign_key "subscribes", "members", :name => "subscribes_member_id_fk"
-
- add_foreign_key "unsubscribes", "members", :name => "unsubscribes_member_id_fk"
- add_foreign_key "unsubscribes", "sent_emails", :name => "unsubscribes_sent_email_id_fk"
-
end
View
@@ -0,0 +1,70 @@
+CREATE TABLE ip_locations (
+ ip_from bigint,
+ ip_to bigint,
+ country_code char(2),
+ country_name text,
+ region text,
+ city text
+);
+
+# iconv -f iso-8859-1 -t utf8 IP-COUNTRY-REGION-CITY.CSV >ip-utf8.csv
+
+\COPY ip_locations FROM 'ip-utf8.csv' WITH CSV QUOTE AS '"'
+
+CREATE INDEX ip2location_range_gist ON ip_locations USING gist ((box(point(ip_from,ip_from),point(ip_to,ip_to))) box_ops);
+
+
+ALTER TABLE ip_locations ADD COLUMN state_code char(2);
+UPDATE IP_LOCATIONS SET STATE_CODE = 'AL' WHERE COUNTRY_CODE = 'US' AND REGION = 'ALABAMA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'AK' WHERE COUNTRY_CODE = 'US' AND REGION = 'ALASKA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'AZ' WHERE COUNTRY_CODE = 'US' AND REGION = 'ARIZONA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'AR' WHERE COUNTRY_CODE = 'US' AND REGION = 'ARKANSAS';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'CA' WHERE COUNTRY_CODE = 'US' AND REGION = 'CALIFORNIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'CO' WHERE COUNTRY_CODE = 'US' AND REGION = 'COLORADO';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'CT' WHERE COUNTRY_CODE = 'US' AND REGION = 'CONNECTICUT';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'DE' WHERE COUNTRY_CODE = 'US' AND REGION = 'DELAWARE';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'DC' WHERE COUNTRY_CODE = 'US' AND REGION = 'DISTRICT OF COLUMBIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'FL' WHERE COUNTRY_CODE = 'US' AND REGION = 'FLORIDA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'GA' WHERE COUNTRY_CODE = 'US' AND REGION = 'GEORGIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'HI' WHERE COUNTRY_CODE = 'US' AND REGION = 'HAWAII';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'ID' WHERE COUNTRY_CODE = 'US' AND REGION = 'IDAHO';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'IL' WHERE COUNTRY_CODE = 'US' AND REGION = 'ILLINOIS';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'IN' WHERE COUNTRY_CODE = 'US' AND REGION = 'INDIANA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'IA' WHERE COUNTRY_CODE = 'US' AND REGION = 'IOWA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'KS' WHERE COUNTRY_CODE = 'US' AND REGION = 'KANSAS';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'KY' WHERE COUNTRY_CODE = 'US' AND REGION = 'KENTUCKY';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'LA' WHERE COUNTRY_CODE = 'US' AND REGION = 'LOUISIANA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'ME' WHERE COUNTRY_CODE = 'US' AND REGION = 'MAINE';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MD' WHERE COUNTRY_CODE = 'US' AND REGION = 'MARYLAND';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MA' WHERE COUNTRY_CODE = 'US' AND REGION = 'MASSACHUSETTS';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MI' WHERE COUNTRY_CODE = 'US' AND REGION = 'MICHIGAN';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MN' WHERE COUNTRY_CODE = 'US' AND REGION = 'MINNESOTA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MS' WHERE COUNTRY_CODE = 'US' AND REGION = 'MISSISSIPPI';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MO' WHERE COUNTRY_CODE = 'US' AND REGION = 'MISSOURI';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'MT' WHERE COUNTRY_CODE = 'US' AND REGION = 'MONTANA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NE' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEBRASKA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NV' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEVADA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NH' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEW HAMPSHIRE';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NJ' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEW JERSEY';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NM' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEW MEXICO';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NY' WHERE COUNTRY_CODE = 'US' AND REGION = 'NEW YORK';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'NC' WHERE COUNTRY_CODE = 'US' AND REGION = 'NORTH CAROLINA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'ND' WHERE COUNTRY_CODE = 'US' AND REGION = 'NORTH DAKOTA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'OH' WHERE COUNTRY_CODE = 'US' AND REGION = 'OHIO';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'OK' WHERE COUNTRY_CODE = 'US' AND REGION = 'OKLAHOMA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'OR' WHERE COUNTRY_CODE = 'US' AND REGION = 'OREGON';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'PA' WHERE COUNTRY_CODE = 'US' AND REGION = 'PENNSYLVANIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'RI' WHERE COUNTRY_CODE = 'US' AND REGION = 'RHODE ISLAND';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'SC' WHERE COUNTRY_CODE = 'US' AND REGION = 'SOUTH CAROLINA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'SD' WHERE COUNTRY_CODE = 'US' AND REGION = 'SOUTH DAKOTA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'TN' WHERE COUNTRY_CODE = 'US' AND REGION = 'TENNESSEE';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'TX' WHERE COUNTRY_CODE = 'US' AND REGION = 'TEXAS';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'UT' WHERE COUNTRY_CODE = 'US' AND REGION = 'UTAH';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'VT' WHERE COUNTRY_CODE = 'US' AND REGION = 'VERMONT';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'VA' WHERE COUNTRY_CODE = 'US' AND REGION = 'VIRGINIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'WA' WHERE COUNTRY_CODE = 'US' AND REGION = 'WASHINGTON';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'WV' WHERE COUNTRY_CODE = 'US' AND REGION = 'WEST VIRGINIA';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'WI' WHERE COUNTRY_CODE = 'US' AND REGION = 'WISCONSIN';
+UPDATE IP_LOCATIONS SET STATE_CODE = 'WY' WHERE COUNTRY_CODE = 'US' AND REGION = 'WYOMING';
+
+# select distinct region from ip_locations where country_code = 'US' and state_code is null;

0 comments on commit db4ecb6

Please sign in to comment.