[1] | 1 | .. _joins_exercises: |
---|
| 2 | |
---|
| 3 | Section 13: Spatial Joins Exercises |
---|
| 4 | =================================== |
---|
| 5 | |
---|
| 6 | Here's a reminder of some of the functions we have seen. Hint: they should be useful for the exercises! |
---|
| 7 | |
---|
| 8 | * :command:`sum(expression)`: aggregate to return a sum for a set of records |
---|
| 9 | * :command:`count(expression)`: aggregate to return the size of a set of records |
---|
| 10 | * :command:`ST_Area(geometry)` returns the area of the polygons |
---|
| 11 | * :command:`ST_AsText(geometry)` returns WKT ``text`` |
---|
| 12 | * :command:`ST_Contains(geometry A, geometry B)` returns the true if geometry A contains geometry B |
---|
| 13 | * :command:`ST_Distance(geometry A, geometry B)` returns the minimum distance between geometry A and geometry B |
---|
| 14 | * :command:`ST_DWithin(geometry A, geometry B, radius)` returns the true if geometry A is radius distance or less from geometry B |
---|
| 15 | * :command:`ST_GeomFromText(text)` returns ``geometry`` |
---|
| 16 | * :command:`ST_Intersects(geometry A, geometry B)` returns the true if geometry A intersects geometry B |
---|
| 17 | * :command:`ST_Length(linestring)` returns the length of the linestring |
---|
| 18 | * :command:`ST_Touches(geometry A, geometry B)` returns the true if the boundary of geometry A touches geometry B |
---|
| 19 | * :command:`ST_Within(geometry A, geometry B)` returns the true if geometry A is within geometry B |
---|
| 20 | |
---|
| 21 | Also remember the tables we have available: |
---|
| 22 | |
---|
| 23 | * ``nyc_census_blocks`` |
---|
| 24 | |
---|
| 25 | * name, popn_total, boroname, the_geom |
---|
| 26 | |
---|
| 27 | * ``nyc_streets`` |
---|
| 28 | |
---|
| 29 | * name, type, the_geom |
---|
| 30 | |
---|
| 31 | * ``nyc_subway_stations`` |
---|
| 32 | |
---|
| 33 | * name, routes, the_geom |
---|
| 34 | |
---|
| 35 | * ``nyc_neighborhoods`` |
---|
| 36 | |
---|
| 37 | * name, boroname, the_geom |
---|
| 38 | |
---|
| 39 | Exercises |
---|
| 40 | --------- |
---|
| 41 | |
---|
| 42 | * **"What subway station is in 'Little Italy'? What subway route is it on?"** |
---|
| 43 | |
---|
| 44 | .. code-block:: sql |
---|
| 45 | |
---|
| 46 | SELECT s.name, s.routes |
---|
| 47 | FROM nyc_subway_stations AS s |
---|
| 48 | JOIN nyc_neighborhoods AS n |
---|
| 49 | ON ST_Contains(n.the_geom, s.the_geom) |
---|
| 50 | WHERE n.name = 'Little Italy'; |
---|
| 51 | |
---|
| 52 | :: |
---|
| 53 | |
---|
| 54 | name | routes |
---|
| 55 | -----------+-------- |
---|
| 56 | Spring St | 6 |
---|
| 57 | |
---|
| 58 | * **"What are all the neighborhoods served by the 6-train?"** (Hint: The ``routes`` column in the ``nyc_subway_stations`` table has values like 'B,D,6,V' and 'C,6') |
---|
| 59 | |
---|
| 60 | .. code-block:: sql |
---|
| 61 | |
---|
| 62 | SELECT DISTINCT n.name, n.boroname |
---|
| 63 | FROM nyc_subway_stations AS s |
---|
| 64 | JOIN nyc_neighborhoods AS n |
---|
| 65 | ON ST_Contains(n.the_geom, s.the_geom) |
---|
| 66 | WHERE strpos(s.routes,'6') > 0; |
---|
| 67 | |
---|
| 68 | :: |
---|
| 69 | |
---|
| 70 | name | boroname |
---|
| 71 | --------------------+----------- |
---|
| 72 | Midtown | Manhattan |
---|
| 73 | Hunts Point | The Bronx |
---|
| 74 | Gramercy | Manhattan |
---|
| 75 | Little Italy | Manhattan |
---|
| 76 | Financial District | Manhattan |
---|
| 77 | South Bronx | The Bronx |
---|
| 78 | Yorkville | Manhattan |
---|
| 79 | Murray Hill | Manhattan |
---|
| 80 | Mott Haven | The Bronx |
---|
| 81 | Upper East Side | Manhattan |
---|
| 82 | Chinatown | Manhattan |
---|
| 83 | East Harlem | Manhattan |
---|
| 84 | Greenwich Village | Manhattan |
---|
| 85 | Parkchester | The Bronx |
---|
| 86 | Soundview | The Bronx |
---|
| 87 | |
---|
| 88 | .. note:: |
---|
| 89 | |
---|
| 90 | We used the ``DISTINCT`` keyword to remove duplicate values from our result set where there were more than one subway station in a neighborhood. |
---|
| 91 | |
---|
| 92 | * **"After 9/11, the 'Battery Park' neighborhood was off limits for several days. How many people had to be evacuated?"** |
---|
| 93 | |
---|
| 94 | .. code-block:: sql |
---|
| 95 | |
---|
| 96 | SELECT Sum(popn_total) |
---|
| 97 | FROM nyc_neighborhoods AS n |
---|
| 98 | JOIN nyc_census_blocks AS c |
---|
| 99 | ON ST_Intersects(n.the_geom, c.the_geom) |
---|
| 100 | WHERE n.name = 'Battery Park'; |
---|
| 101 | |
---|
| 102 | :: |
---|
| 103 | |
---|
| 104 | 9928 |
---|
| 105 | |
---|
| 106 | * **"What are the population density (people / km^2) of the 'Upper West Side' and 'Upper East Side'?"** (Hint: There are 1000000 m^2 in one km^2.) |
---|
| 107 | |
---|
| 108 | .. code-block:: sql |
---|
| 109 | |
---|
| 110 | SELECT |
---|
| 111 | n.name, |
---|
| 112 | Sum(c.popn_total) / (ST_Area(n.the_geom) / 1000000.0) AS popn_per_sqkm |
---|
| 113 | FROM nyc_census_blocks AS c |
---|
| 114 | JOIN nyc_neighborhoods AS n |
---|
| 115 | ON ST_Intersects(c.the_geom, n.the_geom) |
---|
| 116 | WHERE n.name = 'Upper West Side' |
---|
| 117 | OR n.name = 'Upper East Side' |
---|
| 118 | GROUP BY n.name, n.the_geom; |
---|
| 119 | |
---|
| 120 | :: |
---|
| 121 | |
---|
| 122 | name | popn_per_sqkm |
---|
| 123 | -----------------+------------------ |
---|
| 124 | Upper East Side | 47943.3590089405 |
---|
| 125 | Upper West Side | 39729.5779474286 |
---|
| 126 | |
---|
| 127 | |
---|