Chapter 15 revisions

This commit is contained in:
anthonydb 2021-07-05 20:31:20 -04:00
parent 3ab5dd9846
commit e3b6beadfa
3 changed files with 77 additions and 37 deletions

View File

@ -110,17 +110,17 @@ ALTER TABLE farmers_markets ADD COLUMN geog_point geography(POINT,4326);
-- Now fill that column with the lat/long
UPDATE farmers_markets
SET geog_point = ST_SetSRID(
ST_MakePoint(longitude,latitude),4326
)::geography;
ST_MakePoint(longitude,latitude)::geography,4326
);
-- Add a GiST index
-- Add a spatial (R-Tree) index using GIST
CREATE INDEX market_pts_idx ON farmers_markets USING GIST (geog_point);
-- View the geography column
SELECT longitude,
latitude,
geog_point,
ST_AsText(geog_point)
ST_AsEWKT(geog_point)
FROM farmers_markets
WHERE longitude IS NOT NULL
LIMIT 5;
@ -153,7 +153,7 @@ SELECT market_name,
round(
(ST_Distance(geog_point,
ST_GeogFromText('POINT(-93.6204386 41.5853202)')
) / 1609.344)::numeric(8,5), 2
) / 1609.344)::numeric, 2
) AS miles_from_dt
FROM farmers_markets
WHERE ST_DWithin(geog_point,
@ -161,6 +161,19 @@ WHERE ST_DWithin(geog_point,
10000)
ORDER BY miles_from_dt ASC;
-- Listing 15-13: Using the <-> distance operator for a nearest neighbors search
SELECT market_name,
city,
st,
round(
(ST_Distance(geog_point,
ST_GeogFromText('POINT(-68.2041607 44.3876414)')
) / 1609.344)::numeric, 2
) AS miles_from_bh
FROM farmers_markets
ORDER BY geog_point <-> ST_GeogFromText('POINT(-68.2041607 44.3876414)')
LIMIT 3;
-- WORKING WITH SHAPEFILES
@ -174,14 +187,14 @@ ORDER BY miles_from_dt ASC;
-- Import (for use on command line if on macOS or Linux; see Chapter 18)
shp2pgsql -I -s 4269 -W LATIN1 tl_2019_us_county.shp us_counties_2019_shp | psql -d analysis -U postgres
-- Listing 15-13: Checking the geom column's well-known text representation
-- Listing 15-14: Checking the geom column's well-known text representation
SELECT ST_AsText(geom)
FROM us_counties_2019_shp
ORDER BY gid
LIMIT 1;
-- Listing 15-14: Find the largest counties by area using ST_Area()
-- Listing 15-15: Find the largest counties by area using ST_Area()
SELECT name,
statefp AS st,
@ -192,7 +205,7 @@ FROM us_counties_2019_shp
ORDER BY square_miles DESC
LIMIT 5;
-- Listing 15-15: Using ST_Within() to find the county belonging to a pair of coordinates
-- Listing 15-16: Using ST_Within() to find the county belonging to a pair of coordinates
SELECT sh.name,
c.state_name
@ -202,8 +215,7 @@ WHERE ST_Within(
'SRID=4269;POINT(-118.3419063 34.0977076)'::geometry, geom
);
-- Listing 15-16: Using ST_DWithin() to count people near Lincoln, Nebraska
-- Listing 15-17: Using ST_DWithin() to count people near Lincoln, Nebraska
SELECT sum(c.pop_est_2019) AS pop_est_2019
FROM us_counties_2019_shp sh JOIN us_counties_pop_est_2019 c
ON sh.statefp = c.state_fips AND sh.countyfp = c.county_fips
@ -211,7 +223,11 @@ WHERE ST_DWithin(sh.geom::geography,
ST_GeogFromText('SRID=4269;POINT(-96.699656 40.811567)'),
80467);
-- Listing 15-17: Displaying counties near Lincoln, Nebraska
-- Note: You can speed up the above query by creating a functional index
-- that covers the casting of the geom column to a geography type.
CREATE INDEX us_counties_2019_shp_geog_idx ON us_counties_2019_shp USING GIST (CAST(geom AS geography));
-- Listing 15-18: Displaying counties near Lincoln, Nebraska
SELECT sh.name,
c.state_name,
c.pop_est_2019,
@ -250,7 +266,7 @@ WHERE ST_DWithin(sh.geom::geography,
shp2pgsql -I -s 4269 -W LATIN1 tl_2019_35049_linearwater.shp santafe_linearwater_2019 | psql -d analysis -U postgres
shp2pgsql -I -s 4269 -W LATIN1 tl_2019_35049_roads.shp santafe_roads_2019 | psql -d analysis -U postgres
-- Listing 15-18: Using ST_GeometryType() to determine geometry
-- Listing 15-19: Using ST_GeometryType() to determine geometry
SELECT ST_GeometryType(geom)
FROM santafe_linearwater_2019
@ -260,7 +276,7 @@ SELECT ST_GeometryType(geom)
FROM santafe_roads_2019
LIMIT 1;
-- Listing 15-19: Spatial join with ST_Intersects() to find roads crossing the Santa Fe river
-- Listing 15-20: Spatial join with ST_Intersects() to find roads crossing the Santa Fe river
SELECT water.fullname AS waterway,
roads.rttyp,
@ -280,7 +296,7 @@ WHERE water.fullname = 'Santa Fe Riv'
AND roads.fullname IS NOT NULL
ORDER BY roads.fullname;
-- Listing 15-20: Using ST_Intersection() to show where roads cross the river
-- Listing 15-21: Using ST_Intersection() to show where roads cross the river
SELECT water.fullname AS waterway,
roads.rttyp,
@ -290,6 +306,5 @@ FROM santafe_linearwater_2019 water JOIN santafe_roads_2019 roads
ON ST_Intersects(water.geom, roads.geom)
WHERE water.fullname = 'Santa Fe Riv'
AND roads.fullname IS NOT NULL
ORDER BY roads.fullname
LIMIT 5;
ORDER BY roads.fullname;

View File

@ -25,7 +25,7 @@ FMID,MarketName,street,city,County,State,zip,longitude,latitude,Organic
1005299,29th and Wharton Farmers' Market,29th and Wharton Streets,Philadelphia,Philadelphia,Pennsylvania,19146,-75.19204,39.9373,N
1010994,2nd Street Farmers' Market,194 second street,Amherst,Amherst,Virginia,24521,-79.048573,37.583311,N
1009959,2nd Street Market - Five Rivers MetroPark,600 E. 2nd Street,Dayton,Montgomery,Ohio,45402,-84.181030,39.762593,Y
1004950,3 French Hens French Country Market,123 W. Illinois ave. ,Morris,Grundy,Illinois,60450,-88.425186,41.356383,Y
1004950,3 French Hens French Country Market,123 W. Illinois Ave.,Morris,Grundy,Illinois,60450,-88.425186,41.356383,Y
1010775,30A Farmers' Market,Rosmary Beach Town Center,Rosemary Beach,Walton,Florida,32461,-86.002754,30.279017,-
1012342,31 & Main Farmers Market at Campus Town,1928 Pennington Road,Ewing,Mercer,New Jersey,08618,-74.783264,40.267025,Y
1005636,32nd Street/Waverly Farmers Market,E. 32nd & Barclay Street,Baltimore,Baltimore,Maryland,21218,-76.611,39.3272,Y
@ -298,7 +298,7 @@ FMID,MarketName,street,city,County,State,zip,longitude,latitude,Organic
1006964,Ashley Farmers Market,"On East Main Street,",Ashley,McIntosh County,North Dakota,,-99.3684,46.0344,-
1000836,Ashley Valley Farmers' Market (Vernal),Old Dinosaur Gardens on Main Street (~240East),Vernal,Uintah,Utah,,-109.524091666667,40.4557472222222,-
1008599,Ashmont/Peabody Square Farmers Market,Ashmont MBTA Plaza,Dorchester,Suffolk,Massachusetts,02124,-71.064236,42.285528,-
1004530,Ashotn Farmers Market,Off Main Street,Ashton,Fremont,Idaho,83420,-111.446,44.0714,-
1004530,Ashton Farmers Market,Off Main Street,Ashton,Fremont,Idaho,83420,-111.446,44.0714,-
1009244,Ashtabula Farmers Market,1119 Bridge Street,Ashtabula,,Ohio,44004,-80.7998,41.8995,-
1004692,Aspen Grove Farmers' Market,7301 S Santa Fe Dr,Littleton,Arapahoe,Colorado,80120,-105.025219,39.585505,Y
1005837,Aspen Saturday Market,East Hopkins and South Hunter,Aspen,Pitkin,Colorado,81611,-106.817,39.1894,-

Can't render this file because it is too large.

View File

@ -1009,9 +1009,34 @@ FROM farmers_markets markets JOIN us_counties_2019_shp census
WHERE markets.county IS NULL
ORDER BY census.statefp, census.name;
-- Note that this query also highlights a farmer's market that is mis-geocoded.
-- Note that the query returns 496 rows; not all of the columns missing a county
-- value have values present in the geog_point, latitude, and longitude columns.
-- Also, this query highlights a farmer's market that is mis-geocoded.
-- Can you spot it?
-- 4. The nyc_yellow_taxi_trips table you created in Chapter 12 contains
-- the longitude and latitude where each trip began and ended. Use PostGIS
-- functions to turn the dropoff coordinates into a geometry type and
-- count the state/county pairs where each drop-off occurred. As with the
-- previous exercise, youll need to join to the us_counties_2019_shp table
-- and use its geom column for the spatial join.
-- Answer:
SELECT census.statefp,
census.name as county,
count(*) AS dropoffs
FROM nyc_yellow_taxi_trips taxi JOIN us_counties_2019_shp census
ON ST_Within(
ST_SetSRID(ST_MakePoint(taxi.dropoff_longitude, taxi.dropoff_latitude),4269)::geometry, census.geom
)
GROUP BY census.statefp, census.name
ORDER BY count(*) DESC;
-- Thank you to reader Eric Mortenson for suggesting this exercise.
----------------------------------------------------------------------------
-- Chapter 16: Working with JSON Data
----------------------------------------------------------------------------