geo ip 데이터 load후 api 수행하도록 구조 변경
This commit is contained in:
@@ -1,156 +1,47 @@
|
||||
SET client_min_messages TO WARNING;
|
||||
|
||||
CREATE EXTENSION IF NOT EXISTS maxminddb_fdw;
|
||||
CREATE EXTENSION IF NOT EXISTS btree_gist;
|
||||
|
||||
CREATE SERVER IF NOT EXISTS geoip_fdw
|
||||
FOREIGN DATA WRAPPER maxminddb_fdw
|
||||
OPTIONS (database '/data/GeoLite2-City.mmdb');
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS geoip;
|
||||
SET search_path TO geoip, public;
|
||||
|
||||
-- 1) FDW 원본 테이블 (읽기 전용)
|
||||
DROP FOREIGN TABLE IF EXISTS city_blocks_ipv4 CASCADE;
|
||||
CREATE FOREIGN TABLE city_blocks_ipv4 (
|
||||
network cidr,
|
||||
geoname_id integer,
|
||||
registered_country_geoname_id integer,
|
||||
represented_country_geoname_id integer,
|
||||
is_anonymous_proxy boolean,
|
||||
is_satellite_provider boolean,
|
||||
postal_code text,
|
||||
latitude double precision,
|
||||
longitude double precision,
|
||||
accuracy_radius integer,
|
||||
metro_code integer,
|
||||
time_zone text,
|
||||
is_anycast boolean
|
||||
) SERVER geoip_fdw OPTIONS (table 'City_Blocks_IPV4');
|
||||
CREATE TABLE IF NOT EXISTS geoip_metadata (
|
||||
key text PRIMARY KEY,
|
||||
value text NOT NULL,
|
||||
updated_at timestamptz NOT NULL DEFAULT now()
|
||||
);
|
||||
|
||||
DROP FOREIGN TABLE IF EXISTS city_blocks_ipv6 CASCADE;
|
||||
CREATE FOREIGN TABLE city_blocks_ipv6 (
|
||||
network cidr,
|
||||
geoname_id integer,
|
||||
registered_country_geoname_id integer,
|
||||
represented_country_geoname_id integer,
|
||||
is_anonymous_proxy boolean,
|
||||
is_satellite_provider boolean,
|
||||
postal_code text,
|
||||
latitude double precision,
|
||||
longitude double precision,
|
||||
accuracy_radius integer,
|
||||
metro_code integer,
|
||||
time_zone text,
|
||||
is_anycast boolean
|
||||
) SERVER geoip_fdw OPTIONS (table 'City_Blocks_IPV6');
|
||||
|
||||
DROP FOREIGN TABLE IF EXISTS city_locations_fdw CASCADE;
|
||||
CREATE FOREIGN TABLE city_locations_fdw (
|
||||
geoname_id integer,
|
||||
locale_code text,
|
||||
continent_code text,
|
||||
continent_name text,
|
||||
country_iso_code text,
|
||||
country_name text,
|
||||
subdivision_1_iso_code text,
|
||||
subdivision_1_name text,
|
||||
subdivision_2_iso_code text,
|
||||
subdivision_2_name text,
|
||||
city_name text,
|
||||
metro_code text,
|
||||
time_zone text,
|
||||
is_in_european_union boolean
|
||||
) SERVER geoip_fdw OPTIONS (table 'City_Locations', language 'English');
|
||||
|
||||
-- 2) 로컬 영구 테이블로 적재 (초기화 후 mmdb 없이 동작)
|
||||
DROP TABLE IF EXISTS city_blocks CASCADE;
|
||||
CREATE TABLE city_blocks (
|
||||
CREATE TABLE IF NOT EXISTS city_lookup (
|
||||
network cidr PRIMARY KEY,
|
||||
geoname_id integer,
|
||||
registered_country_geoname_id integer,
|
||||
represented_country_geoname_id integer,
|
||||
is_anonymous_proxy boolean,
|
||||
is_satellite_provider boolean,
|
||||
postal_code text,
|
||||
country text,
|
||||
country_iso_code text,
|
||||
region text,
|
||||
region_iso_code text,
|
||||
city text,
|
||||
latitude double precision,
|
||||
longitude double precision,
|
||||
accuracy_radius integer,
|
||||
metro_code integer,
|
||||
time_zone text,
|
||||
is_anycast boolean
|
||||
time_zone text
|
||||
);
|
||||
|
||||
INSERT INTO city_blocks
|
||||
SELECT * FROM city_blocks_ipv4
|
||||
UNION ALL
|
||||
SELECT * FROM city_blocks_ipv6;
|
||||
|
||||
DROP TABLE IF EXISTS city_locations CASCADE;
|
||||
CREATE TABLE city_locations (
|
||||
geoname_id integer PRIMARY KEY,
|
||||
locale_code text,
|
||||
continent_code text,
|
||||
continent_name text,
|
||||
country_iso_code text,
|
||||
country_name text,
|
||||
subdivision_1_iso_code text,
|
||||
subdivision_1_name text,
|
||||
subdivision_2_iso_code text,
|
||||
subdivision_2_name text,
|
||||
city_name text,
|
||||
metro_code text,
|
||||
time_zone text,
|
||||
is_in_european_union boolean
|
||||
);
|
||||
|
||||
INSERT INTO city_locations
|
||||
SELECT * FROM city_locations_fdw;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS city_blocks_network_gist ON city_blocks USING gist (network inet_ops);
|
||||
CREATE INDEX IF NOT EXISTS city_blocks_geoname_id_idx ON city_blocks (geoname_id);
|
||||
CREATE INDEX IF NOT EXISTS city_locations_geoname_id_idx ON city_locations (geoname_id);
|
||||
|
||||
-- 3) 조인 뷰와 조회 함수 (local table 기반)
|
||||
CREATE OR REPLACE VIEW city_block_locations AS
|
||||
SELECT
|
||||
b.network,
|
||||
l.country_iso_code,
|
||||
l.country_name,
|
||||
l.subdivision_1_iso_code AS region_iso_code,
|
||||
l.subdivision_1_name AS region_name,
|
||||
l.city_name,
|
||||
b.latitude,
|
||||
b.longitude,
|
||||
b.time_zone,
|
||||
b.accuracy_radius,
|
||||
b.metro_code
|
||||
FROM city_blocks b
|
||||
LEFT JOIN city_locations l USING (geoname_id);
|
||||
CREATE INDEX IF NOT EXISTS city_lookup_network_gist ON city_lookup USING gist (network inet_ops);
|
||||
CREATE INDEX IF NOT EXISTS city_lookup_geoname_id_idx ON city_lookup (geoname_id);
|
||||
|
||||
CREATE OR REPLACE FUNCTION lookup_city(ip inet)
|
||||
RETURNS TABLE (
|
||||
ip inet,
|
||||
country text,
|
||||
country_iso_code text,
|
||||
region text,
|
||||
region_iso_code text,
|
||||
city text,
|
||||
latitude double precision,
|
||||
longitude double precision,
|
||||
time_zone text
|
||||
) LANGUAGE sql IMMUTABLE AS $$
|
||||
longitude double precision
|
||||
) LANGUAGE sql STABLE AS $$
|
||||
SELECT
|
||||
$1::inet AS ip,
|
||||
c.country_name AS country,
|
||||
c.country_iso_code,
|
||||
c.region_name AS region,
|
||||
c.region_iso_code,
|
||||
c.city_name AS city,
|
||||
c.country,
|
||||
c.region,
|
||||
c.city,
|
||||
c.latitude,
|
||||
c.longitude,
|
||||
c.time_zone
|
||||
FROM city_block_locations c
|
||||
c.longitude
|
||||
FROM city_lookup c
|
||||
WHERE c.network >>= $1
|
||||
ORDER BY masklen(c.network) DESC
|
||||
LIMIT 1;
|
||||
|
||||
2
deploy/postgres/init/01_tuning.sql
Normal file
2
deploy/postgres/init/01_tuning.sql
Normal file
@@ -0,0 +1,2 @@
|
||||
-- Reduce checkpoint churn during bulk MMDB load
|
||||
ALTER SYSTEM SET max_wal_size = '4GB';
|
||||
Reference in New Issue
Block a user