Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Meshcode Addition #25

Merged
merged 4 commits into from
Mar 13, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
3 changes: 3 additions & 0 deletions scripts/install.sh
Original file line number Diff line number Diff line change
Expand Up @@ -15,4 +15,7 @@ psql -U ${DBROLE} -d ${DBNAME} -f ./sql/pgGeocoder.sql
# Load reverse_geocoder function
psql -U ${DBROLE} -d ${DBNAME} -f ./sql/pgReverseGeocoder.sql

# Load latlng2jpgridcode function
psql -U ${DBROLE} -d ${DBNAME} -f ./sql/util/latlng2jpgridcode.sql

echo -e "\nDone!"
9 changes: 7 additions & 2 deletions sql/createTables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -15,8 +15,9 @@ create table pggeocoder.address_t (
lat float,
lon float,
ttable varchar(40),
code varchar(2),
code varchar(2),
geog geography('POINT'),
meshcode text,
year text
);

Expand All @@ -30,6 +31,7 @@ create table pggeocoder.address_s (
lon float,
code varchar(5),
geog geography('POINT'),
meshcode text,
year text
);

Expand All @@ -45,6 +47,7 @@ create table pggeocoder.address_o (
lon float,
code varchar(12),
geog geography('POINT'),
meshcode text,
year text
);

Expand All @@ -60,6 +63,7 @@ create table pggeocoder.address_c (
lat float,
lon float,
geog geography('POINT'),
meshcode text,
year text
);

Expand All @@ -75,7 +79,8 @@ create table pggeocoder.address_g (
go varchar(60),
lat float,
lon float,
geog geography('POINT')
geog geography('POINT'),
meshcode text
);

--
Expand Down
9 changes: 9 additions & 0 deletions sql/maintTables.sql
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,15 @@
--
update pggeocoder.address_t set ttable = 'pggeocoder.address_c';

--
-- adding meshcode information
--
update pggeocoder.address_t set meshcode = latlng2jpgridcode(lat,lon,3);
update pggeocoder.address_s set meshcode = latlng2jpgridcode(lat,lon,3);
update pggeocoder.address_o set meshcode = latlng2jpgridcode(lat,lon,3);
update pggeocoder.address_c set meshcode = latlng2jpgridcode(lat,lon,3);
update pggeocoder.address_g set meshcode = latlng2jpgridcode(lat,lon,3);

--
-- creating index for address_t
--
Expand Down
37 changes: 31 additions & 6 deletions sql/pgGeocoder.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,8 @@ CREATE TYPE geores AS (
shikuchoson character varying,
ooaza character varying,
chiban character varying,
go character varying
go character varying,
meshcode character varying
);

--
Expand Down Expand Up @@ -134,8 +135,8 @@ DECLARE
BEGIN

address := translate(paddress,
'ヶケ?ー―‐−-ーのノ1234567890〇一二三四五六七八九十丁目',
'がが---------12345678900123456789X-');
'?ー―‐−-ーのノ1234567890〇一二三四五六七八九十丁目',
'---------12345678900123456789X-');

IF strpos( address, 'X') <> 0 THEN
tmparr := string_to_array( address,'X');
Expand Down Expand Up @@ -203,12 +204,19 @@ BEGIN
address := regexp_replace(address, '^(大字|字)', '');
END IF;

--
-- Kanji correction.
--
address := translate( address,
'淵壷蛍殼惠鴬靭ッ涛',
'渕壺螢殻恵鶯靱ツ濤');

--
-- Adding Kobayashi-san's rule set
--
address := translate( address,
'榮之ノ治ヰヱ淵渕輿曽藪薮籠篭劔峯峰岡丘富冨祓桧檜莱洲冶治壇檀舘館斉斎竈竃朗鷆膳録嶋崎埼碕庄荘横橫鄕神塚塚都都德福朗郞嶽區溪縣廣斎眞槇槙莊藏龍瀧澤當邊舖萬豫禮茅礪砺',
'-の冶いえ渕淵興曾薮藪篭籠剱峰峯丘岡冨富秡檜桧来州治冶檀壇館舘斎斉釜釜郎鷏善禄島埼崎崎荘庄橫横郷神塚塚都都徳福朗郎岳区渓県広斉真槙槇荘蔵竜滝沢当辺舗万予礼芽砺礪'
'ヶケ榮之ノ治ヰヱ淵渕輿曽藪薮籠篭劔峯峰岡丘富冨祓桧檜莱洲冶治壇檀舘館斉斎竈竃朗鷆膳録嶋崎埼碕庄荘横橫鄕神塚塚都都德福朗郞嶽區溪縣廣斎眞槇槙莊藏龍瀧澤當邊舖萬豫禮茅礪砺',
'がが栄-の冶いえ渕淵興曾薮藪篭籠剱峰峯丘岡冨富秡檜桧来州治冶檀壇館舘斎斉釜釜郎鷏善禄島埼崎崎荘庄橫横郷神塚塚都都徳福朗郎岳区渓県広斉真槙槇荘蔵竜滝沢当辺舗万予礼芽砺礪'
);

--
Expand Down Expand Up @@ -292,6 +300,7 @@ BEGIN
output.code := 4;
output.address := rec.todofuken;
output.todofuken := rec.todofuken;
output.meshcode := rec.meshcode;
ELSE
output.code := 5;
END IF;
Expand Down Expand Up @@ -366,6 +375,7 @@ BEGIN
output.address := rec.todofuken || rec.shikuchoson;
output.todofuken := rec.todofuken;
output.shikuchoson:= rec.shikuchoson;
output.meshcode := rec.meshcode;
END IF;

RETURN output;
Expand Down Expand Up @@ -447,6 +457,18 @@ BEGIN
tr_shikuchoson = t_shikuchoson AND
strpos(tmpaddr,tr_ooaza) = 1
ORDER BY length DESC,year DESC LIMIT 1;

--
-- 2nd Searching for correct District ('郡')
--
IF NOT FOUND AND t_shikuchoson ~ '郡' THEN
SELECT INTO rec *,length(tr_ooaza) AS length
FROM pggeocoder.address_o WHERE
tr_shikuchoson LIKE '%郡'||split_part(t_shikuchoson,'郡',2) AND
strpos(tmpaddr,tr_ooaza) = 1
ORDER BY length DESC,year DESC LIMIT 1;
END IF;

END IF;

IF FOUND THEN
Expand All @@ -456,7 +478,8 @@ BEGIN
output.address := rec.todofuken||rec.shikuchoson||rec.ooaza;
output.todofuken := rec.todofuken;
output.shikuchoson:= rec.shikuchoson;
output.ooaza := rec.ooaza;
output.ooaza := rec.ooaza;
output.meshcode := rec.meshcode;
END IF;

RETURN output;
Expand Down Expand Up @@ -567,6 +590,7 @@ BEGIN
output.shikuchoson:= rec.shikuchoson;
output.ooaza := rec.ooaza;
output.chiban := rec.chiban;
output.meshcode := rec.meshcode;
END IF;

RETURN output;
Expand Down Expand Up @@ -641,6 +665,7 @@ BEGIN
output.ooaza := r_ooaza;
output.chiban := rec.chiban;
output.go := tmpstr3;
output.meshcode := rec.meshcode;
END IF;

RETURN output;
Expand Down
16 changes: 10 additions & 6 deletions sql/pgReverseGeocoder.sql
Original file line number Diff line number Diff line change
Expand Up @@ -41,7 +41,8 @@ CREATE TYPE geores AS (
shikuchoson character varying,
ooaza character varying,
chiban character varying,
go character varying
go character varying,
meshcode character varying
);

--
Expand Down Expand Up @@ -90,7 +91,7 @@ BEGIN
-- change, depending on the ABR dataset.
--
SELECT INTO record todofuken, shikuchoson, ooaza, chiban, go,
lon, lat,
meshcode,lon, lat,
todofuken||shikuchoson||ooaza||chiban||'-'||go AS address
FROM pggeocoder.address_g
WHERE st_dwithin(point, geog,mDist)
Expand All @@ -106,13 +107,14 @@ BEGIN
output.ooaza := record.ooaza;
output.chiban := record.chiban;
output.go := record.go;
output.meshcode := record.meshcode;
RETURN output;
END IF;

SELECT INTO o_bdry geom FROM pggeocoder.boundary_o WHERE st_intersects(point,geom);
IF FOUND THEN
SELECT INTO record todofuken, shikuchoson, ooaza, chiban,
lon, lat,
meshcode,lon, lat,
todofuken||shikuchoson||ooaza||chiban AS address,
st_distance(point::geography,geog) AS dist
FROM pggeocoder.address_c
Expand All @@ -128,11 +130,11 @@ BEGIN
output.shikuchoson:= record.shikuchoson;
output.ooaza := record.ooaza;
output.chiban := record.chiban;

output.meshcode := record.meshcode;
RETURN output;
ELSE
SELECT INTO record todofuken, shikuchoson, ooaza, NULL as chiban,
lon, lat,
meshcode,lon, lat,
todofuken||shikuchoson||ooaza AS address,
st_distance(point::geography,geog) AS dist
FROM pggeocoder.address_o
Expand All @@ -148,6 +150,7 @@ BEGIN
output.shikuchoson:= record.shikuchoson;
output.ooaza := record.ooaza;
output.chiban := record.chiban;
output.meshcode := record.meshcode;
RETURN output;
ELSE
s_flag := TRUE;
Expand All @@ -161,7 +164,7 @@ BEGIN
SELECT INTO s_bdry geom FROM pggeocoder.boundary_s WHERE st_intersects(point,geom);
IF FOUND THEN
SELECT INTO record todofuken, shikuchoson, NULL as ooaza, NULL as chiban,
lon, lat,
meshcode,lon, lat,
todofuken||shikuchoson AS address, 0 AS dist
FROM pggeocoder.address_s AS a
WHERE st_intersects(a.geog, s_bdry.geom::geography);
Expand All @@ -174,6 +177,7 @@ BEGIN
output.shikuchoson:= record.shikuchoson;
output.ooaza := record.ooaza;
output.chiban := record.chiban;
output.meshcode := record.meshcode;
RETURN output;
END IF;
END IF;
Expand Down
69 changes: 69 additions & 0 deletions sql/util/latlng2jpgridcode.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,69 @@
-- ***********************
-- * Source: https://github.com/boiledorange73/pg_jpgrid/blob/main/latlng2jpgridcode.sql
-- * License: BSD
-- ***********************

CREATE OR REPLACE FUNCTION latlng2jpgridcode(lat DOUBLE PRECISION, lng DOUBLE PRECISION, level INTEGER) RETURNS TEXT AS $$
DECLARE
lats INTEGER;
lngs INTEGER;
ret TEXT;
dlatsh DOUBLE PRECISION;
dlngsh DOUBLE PRECISION;
c INTEGER;
n INTEGER;
BEGIN
IF lat < 20 OR lat > 46 OR lng < 122 OR lng > 155 THEN
RETURN NULL;
END IF;
-- 1st
lats := 3600 * lat;
lngs := 3600 * lng - 360000;
ret := LPAD((lats / 2400)::TEXT, 2, '0') || LPAD((lngs / 3600)::TEXT, 2, '0');
lats := lats % 2400;
lngs := lngs % 3600;
-- 2nd
IF level >= 2 THEN
ret := ret || LPAD((lats / 300)::TEXT, 1, '0') || LPAD((lngs / 450)::TEXT, 1, '0');
lats := lats % 300;
lngs := lngs % 450;
END IF;
-- 3rd
IF level >= 3 THEN
ret := ret || LPAD((lats / 30)::TEXT, 1, '0') || LPAD((lngs / 45)::TEXT, 1, '0');
lats := lats % 30;
lngs := lngs % 45;
END IF;
-- 4th and beyond
dlatsh := 30;
dlngsh := 45;
FOR n IN 4..level LOOP
dlatsh := 0.5 * dlatsh;
dlngsh := 0.5 * dlngsh;
c := 1;
IF lats > dlatsh THEN
c := 3;
lats := lats - dlatsh;
END IF;
IF lngs > dlngsh THEN
c := c + 1;
lngs := lngs - dlngsh;
END IF;
ret := ret || c::TEXT;
END LOOP;
-- fin
RETURN ret;
END;
$$ LANGUAGE plpgsql;

CREATE OR REPLACE FUNCTION point2jpgridcode(p GEOMETRY(POINT), level INTEGER) RETURNS TEXT AS $$
DECLARE
lat DOUBLE PRECISION;
lng DOUBLE PRECISION;
BEGIN
IF p IS NULL THEN
RETURN NULL;
END IF;
RETURN latlng2jpgridcode(ST_Y(p), ST_X(p), level);
END;
$$ LANGUAGE plpgsql;