Skip to content

Commit

Permalink
#75 Added COALESCE functions around 'sideofint' and 'apprdir
Browse files Browse the repository at this point in the history
' variables
  • Loading branch information
iammattlee committed Aug 2, 2022
1 parent 4b35922 commit 814e285
Show file tree
Hide file tree
Showing 4 changed files with 19 additions and 11 deletions.
Original file line number Diff line number Diff line change
Expand Up @@ -33,7 +33,8 @@ DROP TABLE IF EXISTS temp_match CASCADE;
CREATE TEMPORARY TABLE temp_match (arterycode bigint, cl_id1 bigint, cl_id2 bigint, dist1 double precision, dist2 double precision, direction character varying, sideofint character);

INSERT INTO temp_match
SELECT ad.arterycode, sc1.geo_id as cl_id1, sc2.geo_id as cl_id2, ST_HausdorffDistance(loc,sc1.geom) as dist1, ST_HausdorffDistance(loc,sc2.geom) as dist2, apprdir AS direction, sideofint
-- 2022-07-14 Added COALESCE function to apprdir and sideofint to address Issue #75
SELECT ad.arterycode, sc1.geo_id as cl_id1, sc2.geo_id as cl_id2, ST_HausdorffDistance(loc,sc1.geom) as dist1, ST_HausdorffDistance(loc,sc2.geom) as dist2, COALESCE(apprdir,'') AS direction, COALESCE(sideofint,'') AS sideofint
FROM traffic.arterydata ad
LEFT JOIN (SELECT * FROM gis.centreline WHERE geo_id NOT IN (SELECT centreline_id FROM excluded_geoids)) sc1 ON SUBSTRING(ad.linkid,'([0-9]{1,20})@?')::bigint = sc1.fnode AND SUBSTRING(linkid,'@([0-9]{1,20})')::bigint = sc1.tnode
LEFT JOIN (SELECT * FROM gis.centreline WHERE geo_id NOT IN (SELECT centreline_id FROM excluded_geoids)) sc2 ON SUBSTRING(ad.linkid,'([0-9]{1,20})@?')::bigint = sc2.tnode AND SUBSTRING(linkid,'@([0-9]{1,20})')::bigint = sc2.fnode
Expand All @@ -55,7 +56,8 @@ UPDATE SET centreline_id = EXCLUDED.centreline_id, match_on_case = EXCLUDED.matc

-- STEP 1.1: For segments with the same fnode, tnode combination, pick out the one with the closest text match using Levenshtein
INSERT INTO prj_volume.artery_tcl
SELECT DISTINCT ON (arterycode) arterycode, centreline_id, apprdir as direction, sideofint, 1 as match_on_case, 1 as artery_type
-- 2022-07-14 Added COALESCE function to apprdir and sideofint to address Issue #75
SELECT DISTINCT ON (arterycode) arterycode, centreline_id, COALESCE(apprdir,'') as direction, COALESCE(sideofint,''), 1 as match_on_case, 1 as artery_type
FROM (SELECT arterycode, levenshtein(UPPER(lf_name), CONCAT(street1,' ',street1type)) AS strscore, A.geo_id AS centreline_id, street1, lf_name, apprdir, sideofint
FROM gis.centreline A
INNER JOIN (SELECT centreline_id AS geo_id FROM excluded_geoids WHERE reason = 0) B USING (geo_id)
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -5,13 +5,13 @@ CREATE TABLE unmatched_linestrings(arterycode bigint, loc geometry, direction ch

-- Collection of Artery Codes where lines were formed, but no centreline is matched
INSERT INTO unmatched_linestrings
SELECT arterycode, loc, apprdir AS direction, arterydata.sideofint, fnode_id, tnode_id
SELECT arterycode, loc, apprdir AS direction, COALESCE(arterydata.sideofint,''), fnode_id, tnode_id
FROM prj_volume.arteries LEFT JOIN prj_volume.artery_tcl USING (arterycode) JOIN traffic.arterydata USING (arterycode)
WHERE centreline_id IS NULL and ST_GeometryType(loc) = 'ST_LineString';

-- take out segments that are obviously outside of tcl boundary
INSERT INTO prj_volume.artery_tcl
SELECT arterycode, NULL as centreline_id, direction, unmatched_linestrings.sideofint, 11 as match_on_case, 1 as artery_type
SELECT arterycode, NULL as centreline_id, direction, COALESCE(unmatched_linestrings.sideofint,''), 11 as match_on_case, 1 as artery_type
FROM unmatched_linestrings JOIN traffic.arterydata USING (arterycode)
WHERE location LIKE '%N OF STEELES%' or loc LIKE '%W OF ETOBICOKE CREEK%'
ON CONFLICT ON CONSTRAINT artery_tcl_pkey DO
Expand All @@ -25,7 +25,7 @@ DROP TABLE IF EXISTS temp_match;
CREATE TEMPORARY TABLE temp_match(arterycode bigint, centreline_id bigint, direction character varying, sideofint character varying, match_on_case smallint, shape geometry);

INSERT INTO temp_match(arterycode, centreline_id, direction, sideofint, match_on_case, shape)
SELECT arterycode, centreline_id, direction, sideofint, 2 as match_on_case, geom AS shape
SELECT arterycode, centreline_id, direction, COALESCE(sideofint,''), 2 as match_on_case, geom AS shape
FROM unmatched_linestrings A
CROSS JOIN ( SELECT geom, geo_id AS centreline_id, fnode, tnode, lf_name
FROM gis.centreline WHERE geo_id NOT IN (SELECT centreline_id FROM excluded_geoids)) B
Expand All @@ -37,7 +37,7 @@ ORDER BY arterycode;

-- Choose the longer segment in case >1 segment overlaps with arterycode
INSERT INTO prj_volume.artery_tcl
SELECT DISTINCT ON (arterycode) arterycode, centreline_id, direction, sideofint, match_on_case, 1 as artery_type
SELECT DISTINCT ON (arterycode) arterycode, centreline_id, direction, COALESCE(sideofint,''), match_on_case, 1 as artery_type
FROM temp_match
ORDER BY arterycode, ST_Length(shape) DESC
ON CONFLICT ON CONSTRAINT artery_tcl_pkey DO
Expand All @@ -50,7 +50,7 @@ WHERE unmatched_linestrings.arterycode IN (SELECT arterycode FROM temp_match);
INSERT INTO prj_volume.artery_tcl
SELECT arterycode, centreline_id, direction, sideofint, 12 as match_on_case, 1 as artery_type
FROM (
SELECT DISTINCT ON (ar.arterycode) ar.arterycode, cl.geo_id as centreline_id, ar.direction, ar.sideofint
SELECT DISTINCT ON (ar.arterycode) ar.arterycode, cl.geo_id as centreline_id, ar.direction, COALESCE(ar.sideofint,'') as sideofint
FROM unmatched_linestrings ar
CROSS JOIN ( SELECT *
FROM gis.centreline
Expand All @@ -74,7 +74,7 @@ DELETE FROM unmatched_linestrings
WHERE unmatched_linestrings.arterycode IN (SELECT arterycode FROM prj_volume.artery_tcl);

INSERT INTO prj_volume.artery_tcl(arterycode, sideofint, direction, match_on_case, artery_type)
SELECT arterycode, sideofint, direction, 9 as match_on_case, 1 as artery_type
SELECT arterycode, COALESCE(sideofint,''), direction, 9 as match_on_case, 1 as artery_type
FROM unmatched_linestrings
WHERE unmatched_linestrings.arterycode NOT IN (SELECT arterycode FROM prj_volume.artery_tcl)
ON CONFLICT ON CONSTRAINT artery_tcl_pkey DO
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -157,7 +157,7 @@ UPDATE SET centreline_id = EXCLUDED.centreline_id, match_on_case = EXCLUDED.matc

--3. insert all failed instances (not within 30m to any intersection and not within 15m to any segment) (or segments not within 200m of anything else)
INSERT INTO prj_volume.artery_tcl(arterycode, sideofint, direction, match_on_case, artery_type)
SELECT arterycode, sideofint, apprdir as direction, 9 as match_on_case, 2 as artery_type
SELECT arterycode, COALESCE(arterydata.sideofint,'') as sideofint, COALESCE(apprdir,'') as direction, 9 as match_on_case, 2 as artery_type
FROM prj_volume.arteries JOIN traffic.arterydata USING (arterycode)
WHERE arterycode NOT IN (SELECT DISTINCT arterycode FROM prj_volume.artery_tcl)
ON CONFLICT ON CONSTRAINT artery_tcl_pkey DO
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -2,7 +2,10 @@ UPDATE prj_volume.arteries
SET loc = ST_Reverse(loc)
WHERE arterycode IN (
SELECT arterycode
FROM (SELECT arterycode, loc, (ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi() AS locangle, dir_binary(text) AS textdirbin, dir_binary((ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi()) AS locdirbin,oneway_dir_code * dir_binary((ST_Azimuth(ST_StartPoint(shape),ST_EndPoint(shape))+0.292)*180/pi()) AS tcldirbin
FROM (SELECT arterycode, loc, (ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi() AS locangle,
dir_binary(text) AS textdirbin,
dir_binary((ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi()) AS locdirbin,
oneway_dir_code * dir_binary((ST_Azimuth(ST_StartPoint(shape),ST_EndPoint(shape))+0.292)*180/pi()) AS tcldirbin
FROM (SELECT loc, arterycode, (CASE direction WHEN 'Eastbound' THEN 90 WHEN 'Southbound' THEN 180 WHEN 'Westbound' THEN 270 WHEN 'Northbound' THEN 0 END) AS text, oneway_dir_code, shape
FROM prj_volume.arteries JOIN prj_volume.artery_tcl USING (arterycode) JOIN prj_volume.centreline USING (centreline_id)
WHERE ST_GeometryType(loc) = 'ST_LineString') A
Expand All @@ -13,7 +16,10 @@ UPDATE prj_volume.artery_tcl
SET direction = (CASE direction WHEN 'Eastbound' THEN 'Westbound' WHEN 'Southbound' THEN 'Northbound' WHEN 'Westbound' THEN 'Eastbound' WHEN 'Northbound' THEN 'Southbound' END)
WHERE arterycode IN (
SELECT arterycode
FROM (SELECT arterycode, loc, (ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi() AS locangle, dir_binary(text) AS textdirbin, dir_binary((ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi()) AS locdirbin,oneway_dir_code * dir_binary((ST_Azimuth(ST_StartPoint(shape),ST_EndPoint(shape))+0.292)*180/pi()) AS tcldirbin
FROM (SELECT arterycode, loc, (ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi() AS locangle,
dir_binary(text) AS textdirbin,
dir_binary((ST_Azimuth(ST_StartPoint(loc), ST_EndPoint(loc))+0.292)*180/pi()) AS locdirbin,
oneway_dir_code * dir_binary((ST_Azimuth(ST_StartPoint(shape),ST_EndPoint(shape))+0.292)*180/pi()) AS tcldirbin
FROM (SELECT loc, arterycode, (CASE direction WHEN 'Eastbound' THEN 90 WHEN 'Southbound' THEN 180 WHEN 'Westbound' THEN 270 WHEN 'Northbound' THEN 0 END) AS text, oneway_dir_code, shape
FROM prj_volume.arteries JOIN prj_volume.artery_tcl USING (arterycode) JOIN prj_volume.centreline USING (centreline_id)
WHERE ST_GeometryType(loc) = 'ST_LineString') A
Expand Down

0 comments on commit 814e285

Please sign in to comment.