The Data Observatory, available for Enterprise accounts, provides access to a catalog of analyzed data methods, and enables you to apply the results to your own datasets.
The contents described in this document are subject to CARTO’s Terms of Service
Data Observatory, like any other CARTO platform’s component, requires using an API Key. From your CARTO dashboard, click Your API keys from the avatar drop-down menu to view your uniquely generated API Key for managing data with CARTO Engine.
Learn more about the basics of authorization, or dig into the details of Auth API, if you want to know more about this part of CARTO platform.
The examples in this documentation may include a placeholder for the API Key. Ensure that you modify any placeholder parameters with your own credentials.
Data Observartory uses Semantic Versioning. View our Github repository to find tags for each release.
Data Observatory Measures are the numerical location data you can access. The measure functions allow you to access individual measures to augment your own data or integrate in your analysis workflows. Measures are used by sending an identifier or a geometry (point or polygon) and receiving back a measure (an absolute value) for that location.
There are hundreds of measures and the list is growing with each release. You can currently discover and learn about measures contained in the Data Observatory by downloading our Data Catalog.
You can access measures through CARTO Builder. The same methods will work if you are using the CARTO Engine to develop your application. We encourage you to use table modifying methods (UPDATE and INSERT) over dynamic methods (SELECT).
The OBS_GetUSCensusMeasure(point, measure_name)
function returns a measure based on a subset of the US Census variables at a point location. The OBS_GetUSCensusMeasure
function is limited to only a subset of all measures that are available in the Data Observatory. To access the full list, use measure IDs with the OBS_GetMeasure
function below.
Name | Description |
---|---|
point | a WGS84 point geometry (the_geom) |
measure_name | a human-readable name of a US Census variable. The list of measure_names is available in the Glossary. |
normalize | for measures that are sums (e.g. population) the default normalization is ‘area’ and response comes back as a rate per square kilometer. Other options are ‘denominator’, which will use the denominator specified in the Data Catalog (optional) |
boundary_id | source of geometries to pull measure from (e.g., ‘us.census.tiger.census_tract’) |
time_span | time span of interest (e.g., 2010 - 2014) |
A NUMERIC value
Key | Description |
---|---|
value | the raw or normalized measure |
Add a measure to an empty numeric column based on point locations in your table.
1
2
UPDATE tablename
SET total_population = OBS_GetUSCensusMeasure(the_geom, 'Total Population')
The OBS_GetUSCensusMeasure(polygon, measure_name)
function returns a measure based on a subset of the US Census variables within a given polygon. The OBS_GetUSCensusMeasure
function is limited to only a subset of all measures that are available in the Data Observatory. To access the full list, use the OBS_GetMeasure
function below.
Name | Description |
---|---|
polygon | a WGS84 polygon geometry (the_geom) |
measure_name | a human readable string name of a US Census variable. The list of measure_names is available in the Glossary. |
normalize | for measures that are sums (e.g. population) the default normalization is ‘none’ and response comes back as a raw value. Other options are ‘denominator’, which will use the denominator specified in the Data Catalog (optional) |
boundary_id | source of geometries to pull measure from (e.g., ‘us.census.tiger.census_tract’) |
time_span | time span of interest (e.g., 2010 - 2014) |
A NUMERIC value
Key | Description |
---|---|
value | the raw or normalized measure |
Add a measure to an empty numeric column based on polygons in your table
1
2
UPDATE tablename
SET local_male_population = OBS_GetUSCensusMeasure(the_geom, 'Male Population')
The OBS_GetMeasure(point, measure_id)
function returns any Data Observatory measure at a point location. You can browse all available Measures in the Catalog.
Name | Description |
---|---|
point | a WGS84 point geometry (the_geom) |
measure_id | a measure identifier from the Data Observatory (see available measures). It is important to note that these are different than ‘measure_name’ used in the Census based functions above. |
normalize | for measures that are sums (e.g. population) the default normalization is ‘area’ and response comes back as a rate per square kilometer. The other option is ‘denominator’, which will use the denominator specified in the Data Catalog. (optional) |
boundary_id | source of geometries to pull measure from (e.g., ‘us.census.tiger.census_tract’) |
time_span | time span of interest (e.g., 2010 - 2014) |
A NUMERIC value
Key | Description |
---|---|
value | the raw or normalized measure |
Add a measure to an empty numeric column based on point locations in your table
1
2
UPDATE tablename
SET median_home_value_sqft = OBS_GetMeasure(the_geom, 'us.zillow.AllHomes_MedianValuePerSqft')
The OBS_GetMeasure(polygon, measure_id)
function returns any Data Observatory measure calculated within a polygon.
Name | Description |
---|---|
polygon_geometry | a WGS84 polygon geometry (the_geom) |
measure_id | a measure identifier from the Data Observatory (see available measures) |
normalize | for measures that are sums (e.g. population) the default normalization is ‘none’ and response comes back as a raw value. Other options are ‘denominator’, which will use the denominator specified in the Data Catalog (optional) |
boundary_id | source of geometries to pull measure from (e.g., ‘us.census.tiger.census_tract’) |
time_span | time span of interest (e.g., 2010 - 2014) |
A NUMERIC value
Key | Description |
---|---|
value | the raw or normalized measure |
Add a measure to an empty column based on polygons in your table
1
2
UPDATE tablename
SET household_count = OBS_GetMeasure(the_geom, 'us.census.acs.B11001001')
'Only valid inputs for "normalize" are "area" (default) and "denominator".
The OBS_GetMeasureById(geom_ref, measure_id, boundary_id)
function returns any Data Observatory measure that corresponds to the boundary in boundary_id
that has a geometry reference of geom_ref
.
Name | Description |
---|---|
geom_ref | a geometry reference (e.g., a US Census geoid) |
measure_id | a measure identifier from the Data Observatory (see available measures) |
boundary_id | source of geometries to pull measure from (e.g., ‘us.census.tiger.census_tract’) |
time_span (optional) | time span of interest (e.g., 2010 - 2014). If NULL is passed, the measure from the most recent data will be used. |
A NUMERIC value
Key | Description |
---|---|
value | the raw measure associated with geom_ref |
Add a measure to an empty column based on county geoids in your table
1
2
UPDATE tablename
SET household_count = OBS_GetMeasureById(geoid_column, 'us.census.acs.B11001001', 'us.census.tiger.county')
NULL
if there is a mismatch between the geometry reference and the boundary id such as using the geoid of a county with the boundary of block groupsThe OBS_GetCategory(point, category_id)
function returns any Data Observatory Category value at a point location. The Categories available are currently limited to Segmentation categories. See the Segmentation section of the Catalog for more detail.
Name | Description |
---|---|
point | a WGS84 point geometry (the_geom) |
category_id | a category identifier from the Data Observatory (see available measures). |
A TEXT value
Key | Description |
---|---|
value | a text based category found at the supplied point |
Add the Category to an empty column text column based on point locations in your table
1
2
UPDATE tablename
SET segmentation = OBS_GetCategory(the_geom, 'us.census.spielman_singleton_segments.X55')
The OBS_GetMeta(extent, metadata)
function returns a completed Data
Observatory metadata JSON Object for use in OBS_GetData(geomvals,
metadata)
or OBS_GetData(ids, metadata)
. It is not possible to pass
metadata to those functions if it is not processed by OBS_GetMeta(extent,
metadata)
first.
OBS_GetMeta
makes it possible to automatically select appropriate timespans
and boundaries for the measurement you want.
Name | Description |
---|---|
extent | A geometry of the extent of the input geometries |
metadata | A JSON array composed of metadata input objects. Each indicates one desired measure for an output column, and optionally additional parameters about that column |
num_timespan_options | How many historical time periods to include. Defaults to 1 |
num_score_options | How many alternative boundary levels to include. Defaults to 1 |
target_geoms | Target number of geometries. Boundaries with close to this many objects within extent will be ranked highest. |
The schema of the metadata input objects are as follows:
Metadata Input Key | Description |
---|---|
numer_id | The identifier for the desired measurement. If left blank, but a geom_id is specified, the column will return a geometry instead of a measurement. |
geom_id | Identifier for a desired geographic boundary level to use when calculating measures. Will be automatically assigned if undefined. If defined but numer_id is blank, then the column will return a geometry instead of a measurement. |
normalization | The desired normalization. One of ‘area’, ‘prenormalized’, or ‘denominated’. ‘Area’ will normalize the measure per square kilometer, ‘prenormalized’ will return the original value, and ‘denominated’ will normalize by a denominator. Ignored if this metadata object specifies a geometry. |
denom_id | Identifier for a desired normalization column in case normalization is ‘denominated’. Will be automatically assigned if necessary. Ignored if this metadata object specifies a geometry. |
numer_timespan | The desired timespan for the measurement. Defaults to most recent timespan available if left unspecified. |
geom_timespan | The desired timespan for the geometry. Defaults to timespan matching numer_timespan if left unspecified. |
target_area | Instead of aiming to have target_geoms in the area of the geometry passed as extent , fill this area. Unit is square degrees WGS84. Set this to 0 if you want to use the smallest source geometry for this element of metadata, for example if you’re passing in points. |
target_geoms | Override global target_geoms for this element of metadata |
max_timespan_rank | Only include timespans of this recency (for example, 1 is only the most recent timespan). No limit by default |
max_score_rank | Only include boundaries of this relevance (for example, 1 is the most relevant boundary). Is 1 by default |
A JSON array composed of metadata output objects.
Key | Description |
---|---|
meta | A JSON array with completed metadata for the requested data, including all keys below |
The schema of the metadata output objects are as follows. You should pass this
array as-is to OBS_GetData
. If you modify any values the function will
fail.
Metadata Output Key | Description |
---|---|
suggested_name | A suggested column name for adding this to an existing table |
numer_id | Identifier for desired measurement |
numer_timespan | Timespan that will be used of the desired measurement |
numer_name | Human-readable name of desired measure |
numer_description | Long human-readable description of the desired measure |
numer_t_description | Further information about the source table |
numer_type | PostgreSQL/PostGIS type of desired measure |
numer_colname | Internal identifier for column name |
numer_tablename | Internal identifier for table |
numer_geomref_colname | Internal identifier for geomref column name |
denom_id | Identifier for desired normalization |
denom_timespan | Timespan that will be used of the desired normalization |
denom_name | Human-readable name of desired measure’s normalization |
denom_description | Long human-readable description of the desired measure’s normalization |
denom_t_description | Further information about the source table |
denom_type | PostgreSQL/PostGIS type of desired measure’s normalization |
denom_colname | Internal identifier for normalization column name |
denom_tablename | Internal identifier for normalization table |
denom_geomref_colname | Internal identifier for normalization geomref column name |
geom_id | Identifier for desired boundary geometry |
geom_timespan | Timespan that will be used of the desired boundary geometry |
geom_name | Human-readable name of desired boundary geometry |
geom_description | Long human-readable description of the desired boundary geometry |
geom_t_description | Further information about the source table |
geom_type | PostgreSQL/PostGIS type of desired boundary geometry |
geom_colname | Internal identifier for boundary geometry column name |
geom_tablename | Internal identifier for boundary geometry table |
geom_geomref_colname | Internal identifier for boundary geometry ref column name |
timespan_rank | Ranking of this measurement by time, most recent is 1, second most recent 2, etc. |
score | The score of this measurement’s boundary compared to the extent and target_geoms passed in. Between 0 and 100. |
score_rank | The ranking of this measurement’s boundary, highest ranked is 1, second is 2, etc. |
numer_aggregate | The aggregate type of the numerator, either sum , average , median , or blank |
denom_aggregate | The aggregate type of the denominator, either sum , average , median , or blank |
normalization | The sort of normalization that will be used for this measure, either area , predenominated , or denominated |
Obtain metadata that can augment with one additional column of US population
data, using a boundary relevant for the geometry provided and latest timespan.
Limit to only the most recent column most relevant to the extent & density of
input geometries in tablename
.
1
2
3
4
5
6
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001"}]',
1, 1,
COUNT(*)
) FROM tablename
Obtain metadata that can augment with one additional column of US population data, using census tract boundaries.
1
2
3
4
5
6
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001", "geom_id": "us.census.tiger.census_tract"}]',
1, 1,
COUNT(*)
) FROM tablename
Obtain metadata that can augment with two additional columns, one for total population and one for male population.
1
2
3
4
5
6
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001"}, {"numer_id": "us.census.acs.B01001002"}]',
1, 1,
COUNT(*)
) FROM tablename
The OBS_MetadataValidation
function performs a validation check over the known issues using the extent, type of geometry, and metadata that is being used in the OBS_GetMeta
function.
Name | Description |
---|---|
extent | A geometry of the extent of the input geometries |
geometry_type | The geometry type of the source data |
metadata | A JSON array composed of metadata input objects. Each indicates one desired measure for an output column, and optional additional parameters about that column |
target_geoms | Target number of geometries. Boundaries with close to this many objects within extent will be ranked highest |
The schema of the metadata input objects are as follows:
Metadata Input Key | Description |
---|---|
numer_id | The identifier for the desired measurement. If left blank, a geom_id is specified and the column returns a geometry, instead of a measurement |
geom_id | Identifier for a desired geographic boundary level used to calculate measures. If undefined, this is automatically assigned. If defined, numer_id is blank and the column returns a geometry, instead of a measurement |
normalization | The desired normalization. One of ‘area’, ‘prenormalized’, or ‘denominated’. ‘Area’ will normalize the measure per square kilometer, ‘prenormalized’ will return the original value, and ‘denominated’ will normalize by a denominator. If the metadata object specifies a geometry, this is ignored |
denom_id | When normalization is ‘denominated’, this is the identifier for a desired normalization column. This is automatically assigned. If the metadata object specifies a geometry, this is ignored |
numer_timespan | The desired timespan for the measurement. If left unspecified, it defaults to the most recent timespan available |
geom_timespan | The desired timespan for the geometry. If left unspecified, it defaults to the timespan matching numer_timespan |
target_area | Instead of aiming to have target_geoms in the area of the geometry passed as extent , fill this area. Unit is square degrees WGS84. Set this to 0 if you want to use the smallest source geometry for this element of metadata. For example, if you are passing in points |
target_geoms | Override global target_geoms for this element of metadata |
max_timespan_rank | Only include timespans of this recency (For example, 1 is only the most recent timespan). There is no limit by default |
max_score_rank | Only include boundaries of this relevance (for example, 1 is the most relevant boundary). The default is 1 |
Key | Description |
---|---|
valid | A boolean field that represents if the validation was successful or not |
errors | A text array with all possible errors |
Validate metadata with two additional columns of US census data; using a boundary relevant for the geometry provided and the latest timespan. Limited to the most recent column, and the most relevant, based on the extent and density of input geometries in tablename
.
1
2
3
4
5
6
7
SELECT OBS_MetadataValidation(
ST_SetSRID(ST_Extent(the_geom), 4326),
ST_GeometryType(the_geom),
'[{"numer_id": "us.census.acs.B01003001"}, {"numer_id": "us.census.acs.B01001002"}]',
COUNT(*)::INTEGER
) FROM tablename
GROUP BY ST_GeometryType(the_geom)
The OBS_GetData(geomvals, metadata)
function returns a measure and/or
geometry corresponding to the metadata
JSON array for each every Geometry of
the geomval
element in the geomvals
array. The metadata argument must be
obtained from OBS_GetMeta(extent, metadata)
.
Name | Description |
---|---|
geomvals | An array of geomval elements, which are obtained by casting together a Geometry and a Numeric . This should be obtained by using ARRAY_AGG((the_geom, cartodb_id)::geomval) from the CARTO table one wishes to obtain data for. |
metadata | A JSON array composed of metadata output objects from OBS_GetMeta(extent, metadata) . The schema of the elements of the metadata JSON array corresponds to that of the output of OBS_GetMeta(extent, metadata) , and this argument must be obtained from that function in order for the call to be valid. |
A TABLE with the following schema, where each element of the input geomvals
array corresponds to one row:
Column | Type | Description |
---|---|---|
id | Numeric | ID corresponding to the val component of an element of the input geomvals array |
data | JSON | A JSON array with elements corresponding to the input metadata JSON array |
Each data
object has the following keys:
Key | Description |
---|---|
value | The value of the measurement or geometry for the geometry corresponding to this row and measurement corresponding to this position in the metadata JSON array |
To determine the appropriate cast for value
, one can use the numer_type
or geom_type
key corresponding to that value in the input metadata
JSON
array.
Obtain population densities for every geometry in a table, keyed by cartodb_id:
1
2
3
4
5
6
7
8
9
WITH meta AS (
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001"}]',
1, 1, COUNT(*)
) meta FROM tablename)
SELECT id AS cartodb_id, (data->0->>'value')::Numeric AS pop_density
FROM OBS_GetData((SELECT ARRAY_AGG((the_geom, cartodb_id)::geomval) FROM tablename),
(SELECT meta FROM meta))
Update a table with a blank numeric column called pop_density
with population
densities:
1
2
3
4
5
6
7
8
9
10
11
12
13
14
WITH meta AS (
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001"}]',
1, 1, COUNT(*)
) meta FROM tablename),
data AS (
SELECT id AS cartodb_id, (data->0->>'value')::Numeric AS pop_density
FROM OBS_GetData((SELECT ARRAY_AGG((the_geom, cartodb_id)::geomval) FROM tablename),
(SELECT meta FROM meta)))
UPDATE tablename
SET pop_density = data.pop_density
FROM data
WHERE cartodb_id = data.id
Update a table with two measurements at once, population density and household
density. The table should already have a Numeric column pop_density
and
household_density
.
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
WITH meta AS (
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom),4326),
'[{"numer_id": "us.census.acs.B01003001"},{"numer_id": "us.census.acs.B11001001"}]',
1, 1, COUNT(*)
) meta from tablename),
data AS (
SELECT id,
data->0->>'value' AS pop_density,
data->1->>'value' AS household_density
FROM OBS_GetData((SELECT ARRAY_AGG((the_geom, cartodb_id)::geomval) FROM tablename),
(SELECT meta FROM meta)))
UPDATE tablename
SET pop_density = data.pop_density,
household_density = data.household_density
FROM data
WHERE cartodb_id = data.id
The OBS_GetData(ids, metadata)
function returns a measure and/or
geometry corresponding to the metadata
JSON array for each every id of
the ids
array. The metadata argument must be obtained from
OBS_GetMeta(extent, metadata)
. When obtaining metadata, one must include
the geom_id
corresponding to the boundary that the ids
refer to.
Name | Description |
---|---|
ids | An array of TEXT elements. This should be obtained by using ARRAY_AGG(col_of_geom_refs) from the CARTO table one wishes to obtain data for. |
metadata | A JSON array composed of metadata output objects from OBS_GetMeta(extent, metadata) . The schema of the elements of the metadata JSON array corresponds to that of the output of OBS_GetMeta(extent, metadata) , and this argument must be obtained from that function in order for the call to be valid. |
For this function to work, the metadata
argument must include a geom_id
that corresponds to the ids found in col_of_geom_refs
.
A TABLE with the following schema, where each element of the input ids
array
corresponds to one row:
Column | Type | Description |
---|---|---|
id | Text | ID corresponding to an element of the input ids array |
data | JSON | A JSON array with elements corresponding to the input metadata JSON array |
Each data
object has the following keys:
Key | Description |
---|---|
value | The value of the measurement or geometry for the geometry corresponding to this row and measurement corresponding to this position in the metadata JSON array |
To determine the appropriate cast for value
, one can use the numer_type
or geom_type
key corresponding to that value in the input metadata
JSON
array.
Obtain population densities for every row of a table with FIPS code county IDs (USA).
1
2
3
4
5
6
7
8
WITH meta AS (
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001", "geom_id": "us.census.tiger.county"}]'
) meta FROM tablename)
SELECT id AS fips, (data->0->>'value')::Numeric AS pop_density
FROM OBS_GetData((SELECT ARRAY_AGG(fips) FROM tablename),
(SELECT meta FROM meta))
Update a table with population densities for every FIPS code county ID (USA).
This table has a blank column called pop_density
and fips codes stored in a
column fips
.
1
2
3
4
5
6
7
8
9
10
11
12
13
WITH meta AS (
SELECT OBS_GetMeta(
ST_SetSRID(ST_Extent(the_geom), 4326),
'[{"numer_id": "us.census.acs.B01003001", "geom_id": "us.census.tiger.county"}]'
) meta FROM tablename),
data as (
SELECT id AS fips, (data->0->>'value') AS pop_density
FROM OBS_GetData((SELECT ARRAY_AGG(fips) FROM tablename),
(SELECT meta FROM meta)))
UPDATE tablename
SET pop_density = data.pop_density
FROM data
WHERE fips = data.id
Use the following functions to retrieve Boundary data. Data ranges from small areas (e.g. US Census Block Groups) to large areas (e.g. Countries). You can access boundaries by point location lookup, bounding box lookup, direct ID access and several other methods described below.
You can access boundaries through CARTO Builder. The same methods will work if you are using the CARTO Engine to develop your application. We encourage you to use table modifying methods (UPDATE and INSERT) over dynamic methods (SELECT).
The OBS_GetBoundariesByGeometry(geometry, geometry_id)
method returns a set of boundary geometries that intersect a supplied geometry. This can be used to find all boundaries that are within or overlap a bounding box. You have the ability to choose whether to retrieve all boundaries that intersect your supplied bounding box or only those that fall entirely inside of your bounding box.
Name | Description |
---|---|
geom | a WGS84 geometry |
geometry_id | a string identifier for a boundary geometry |
timespan (optional) | year(s) to request from (‘NULL’ (default) gives most recent) |
overlap_type (optional) | one of ‘intersects’ (default), ‘contains’, or ‘within’. |
A table with the following columns:
Column Name | Description |
---|---|
the_geom | a boundary geometry (e.g., US Census tract boundaries) |
geom_refs | a string identifier for the geometry (e.g., geoids of US Census tracts) |
If geometries are not found for the requested geom
, geometry_id
, timespan
, or overlap_type
, then null values are returned.
Insert all Census Tracts from Lower Manhattan and nearby areas within the supplied bounding box to a table named manhattan_census_tracts
which has columns the_geom
(geometry) and geom_refs
(text).
1
2
3
4
5
6
7
INSERT INTO manhattan_census_tracts(the_geom, geom_refs)
SELECT *
FROM OBS_GetBoundariesByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342,
4326),
'us.census.tiger.census_tract')
overlap_type
other than the valid ones listed above is entered, then an error is thrownThe OBS_GetPointsByGeometry(polygon, geometry_id)
method returns point geometries and their geographical identifiers that intersect (or are contained by) a bounding box polygon and lie on the surface of a boundary corresponding to the boundary with same geographical identifiers (e.g., a point that is on a census tract with the same geoid). This is a useful alternative to OBS_GetBoundariesByGeometry
listed above because it returns much less data for each location.
Name | Description |
---|---|
polygon | a bounding box or other geometry |
geometry_id | a string identifier for a boundary geometry |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
overlap_type (optional) | one of ‘intersects’ (default), ‘contains’, or ‘within’. |
A table with the following columns:
Column Name | Description |
---|---|
the_geom | a point geometry on a boundary (e.g., a point that lies on a US Census tract) |
geom_refs | a string identifier for the geometry (e.g., the geoid of a US Census tract) |
If geometries are not found for the requested geometry, geometry_id
, timespan
, or overlap_type
, then NULL values are returned.
Insert points that lie on Census Tracts from Lower Manhattan and nearby areas within the supplied bounding box to a table named manhattan_tract_points
which has columns the_geom
(geometry) and geom_refs
(text).
1
2
3
4
5
6
7
INSERT INTO manhattan_tract_points (the_geom, geom_refs)
SELECT *
FROM OBS_GetPointsByGeometry(
ST_MakeEnvelope(-74.0251922607,40.6945658517,
-73.9651107788,40.7377626342,
4326),
'us.census.tiger.census_tract')
Invalid geometry type (ST_Point), expecting 'ST_MultiPolygon' or 'ST_Polygon'
The OBS_GetBoundary(point_geometry, boundary_id)
method returns a boundary geometry defined as overlapping the point geometry and from the desired boundary set (e.g. Census Tracts). See the Boundary ID Glossary. This is a useful method for performing aggregations of points.
Name | Description |
---|---|
point_geometry | a WGS84 polygon geometry (the_geom) |
boundary_id | a boundary identifier from the Boundary ID Glossary |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
A boundary geometry. If no value is found at the requested boundary_id
or timespan
, a null value is returned.
Value | Description |
---|---|
geom | WKB geometry |
Overwrite a point geometry with a boundary geometry that contains it in your table
1
2
UPDATE tablename
SET the_geom = OBS_GetBoundary(the_geom, 'us.census.tiger.block_group')
Invalid geometry type (ST_Line), expecting 'ST_Point'
The OBS_GetBoundaryId(point_geometry, boundary_id)
returns a unique geometry_id for the boundary geometry that contains a given point geometry. See the Boundary ID Glossary. The method can be combined with OBS_GetBoundaryById(geometry_id)
to create a point aggregation workflow.
Name | Description |
---|---|
point_geometry | a WGS84 point geometry (the_geom) |
boundary_id | a boundary identifier from the Boundary ID Glossary |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
A TEXT boundary geometry id. If no value is found at the requested boundary_id
or timespan
, a null value is returned.
Value | Description |
---|---|
geometry_id | a string identifier of a geometry in the Boundaries |
Write the US Census block group geoid that contains the point geometry for every row as a new column in your table.
1
2
UPDATE tablename
SET geometry_id = OBS_GetBoundaryId(the_geom, 'us.census.tiger.block_group')
Invalid geometry type (ST_Line), expecting 'ST_Point'
The OBS_GetBoundaryById(geometry_id, boundary_id)
returns the boundary geometry for a unique geometry_id. A geometry_id can be found using the OBS_GetBoundaryId(point_geometry, boundary_id)
method described above.
Name | Description |
---|---|
geometry_id | a string identifier for a Boundary geometry |
boundary_id | a boundary identifier from the Boundary ID Glossary |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
A boundary geometry. If a geometry is not found for the requested geometry_id
, boundary_id
, or timespan
, then a null value is returned.
Key | Description |
---|---|
geom | a WGS84 polygon geometry |
Use a table of geometry_id
s (e.g., geoid from the U.S. Census) to select the unique boundaries that they correspond to and insert into a table called, overlapping_polygons
. This is a useful method for creating new choropleths of aggregate data.
1
2
3
4
5
6
7
INSERT INTO overlapping_polygons (the_geom, geometry_id, point_count)
SELECT
OBS_GetBoundaryById(geometry_id, 'us.census.tiger.county') As the_geom,
geometry_id,
count(*)
FROM tablename
GROUP BY geometry_id
The OBS_GetBoundariesByPointAndRadius(point, radius, boundary_id)
method returns boundary geometries and their geographical identifiers that intersect (or are contained by) a circle centered on a point with a radius.
Name | Description |
---|---|
point | a WGS84 point geometry |
radius | a radius (in meters) from the center point |
geometry_id | a string identifier for a boundary geometry |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
overlap_type (optional) | one of ‘intersects’ (default), ‘contains’, or ‘within’. |
A table with the following columns:
Column Name | Description |
---|---|
the_geom | a boundary geometry (e.g., a US Census tract) |
geom_refs | a string identifier for the geometry (e.g., the geoid of a US Census tract) |
If geometries are not found for the requested point and radius, geometry_id
, timespan
, or overlap_type
, then null values are returned.
Insert into table denver_census_tracts
the census tract boundaries and geom_refs of census tracts which intersect within 10 miles of downtown Denver, Colorado.
1
2
3
4
5
6
INSERT INTO denver_census_tracts(the_geom, geom_refs)
SELECT *
FROM OBS_GetBoundariesByPointAndRadius(
CDB_LatLng(39.7392, -104.9903), -- Denver, Colorado
10000 * 1.609, -- 10 miles (10km * conversion to miles)
'us.census.tiger.census_tract')
Invalid geometry type (ST_Line), expecting 'ST_Point'
The OBS_GetPointsByPointAndRadius(point, radius, boundary_id)
method returns point geometries on boundaries (e.g., a point that lies on a Census tract) and their geographical identifiers that intersect (or are contained by) a circle centered on a point with a radius.
Name | Description |
---|---|
point | a WGS84 point geometry |
radius | radius (in meters) |
geometry_id | a string identifier for a boundary geometry |
timespan (optional) | year(s) to request from (NULL (default) gives most recent) |
overlap_type (optional) | one of ‘intersects’ (default), ‘contains’, or ‘within’. |
A table with the following columns:
Column Name | Description |
---|---|
the_geom | a point geometry (e.g., a point on a US Census tract) |
geom_refs | a string identifier for the geometry (e.g., the geoid of a US Census tract) |
If geometries are not found for the requested point and radius, geometry_id
, timespan
, or overlap_type
, then null values are returned.
Insert into table denver_tract_points
points on US census tracts and their corresponding geoids for census tracts which intersect within 10 miles of downtown Denver, Colorado, USA.
1
2
3
4
5
6
INSERT INTO denver_tract_points(the_geom, geom_refs)
SELECT *
FROM OBS_GetPointsByPointAndRadius(
CDB_LatLng(39.7392, -104.9903), -- Denver, Colorado
10000 * 1.609, -- 10 miles (10km * conversion to miles)
'us.census.tiger.census_tract')
Invalid geometry type (ST_Line), expecting 'ST_Point'
If you are using the discovery methods from the Data Observatory, use the following functions to retrieve boundary and measures data.
Use arbitrary text to search all available measures
Name | Description |
---|---|
search_term | a string to search for available measures |
boundary_id | a string identifier for a boundary geometry (optional) |
A TABLE containing the following properties
Key | Description |
---|---|
id | the unique id of the measure for use with the OBS_GetMeasure function |
name | the human readable name of the measure |
description | a brief description of the measure |
aggregate | sum are raw count values, median are statistical medians, average are statistical averages, undefined other (e.g. an index value) |
source | where the data came from (e.g. US Census Bureau) |
1
SELECT * FROM OBS_Search('home value')
Returns available boundary_id
s at a given point geometry.
Name | Description |
---|---|
point_geometry | a WGS84 point geometry (e.g. the_geom) |
A TABLE containing the following properties
Key | Description |
---|---|
boundary_id | a boundary identifier from the Boundary ID Glossary |
description | a brief description of the boundary dataset |
time_span | the timespan attached the boundary. this does not mean that the boundary is invalid outside of the timespan, but is the explicit timespan published with the geometry. |
1
SELECT * FROM OBS_GetAvailableBoundaries(CDB_LatLng(40.7, -73.9))
Return available numerators within a boundary and with the specified
filter_tags
.
Name | Type | Description |
---|---|---|
bounds | Geometry(Geometry, 4326) | a geometry which some of the numerator’s data must intersect with |
filter_tags | Text[] | a list of filters. Only numerators for which all of these apply are returned NULL to ignore (optional) |
denom_id | Text | the ID of a denominator to check whether the numerator is valid against. Will not reduce length of returned table, but will change values for valid_denom (optional) |
geom_id | Text | the ID of a geometry to check whether the numerator is valid against. Will not reduce length of returned table, but will change values for valid_geom (optional) |
timespan | Text | the ID of a timespan to check whether the numerator is valid against. Will not reduce length of returned table, but will change values for valid_timespan (optional) |
A TABLE containing the following properties
Key | Type | Description |
---|---|---|
numer_id | Text | The ID of the numerator |
numer_name | Text | A human readable name for the numerator |
numer_description | Text | Description of the numerator. Is sometimes NULL |
numer_weight | Numeric | Numeric “weight” of the numerator. Ignored. |
numer_license | Text | ID of the license for the numerator |
numer_source | Text | ID of the source for the numerator |
numer_type | Text | Postgres type of the numerator |
numer_aggregate | Text | Aggregate type of the numerator. If 'SUM' , this can be normalized by area |
numer_extra | JSONB | Extra information about the numerator column. Ignored. |
numer_tags | Text[] | Array of all tags applying to this numerator |
valid_denom | Boolean | True if the denom_id argument is a valid denominator for this numerator, False otherwise |
valid_geom | Boolean | True if the geom_id argument is a valid geometry for this numerator, False otherwise |
valid_timespan | Boolean | True if the timespan argument is a valid timespan for this numerator, False otherwise |
Obtain all numerators that are available within a small rectangle.
1
2
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326))
Obtain all numerators that are available within a small rectangle and are for the United States only.
1
2
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), '{section/tags.united_states}');
Obtain all numerators that are available within a small rectangle and are employment related for the United States only.
1
2
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), '{section/tags.united_states, subsection/tags.employment}');
Obtain all numerators that are available within a small rectangle and are related to both employment and age & gender for the United States only.
1
2
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), '{section/tags.united_states, subsection/tags.employment, subsection/tags.age_gender}');
Obtain all numerators that work with US population (us.census.acs.B01003001
)
as a denominator.
1
2
3
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, 'us.census.acs.B01003001')
WHERE valid_denom IS True;
Obtain all numerators that work with US states (us.census.tiger.state
)
as a geometry.
1
2
3
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, 'us.census.tiger.state')
WHERE valid_geom IS True;
Obtain all numerators available in the timespan 2011 - 2015
.
1
2
3
SELECT * FROM OBS_GetAvailableNumerators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, NULL, '2011 - 2015')
WHERE valid_timespan IS True;
Return available denominators within a boundary and with the specified
filter_tags
.
Name | Type | Description |
---|---|---|
bounds | Geometry(Geometry, 4326) | a geometry which some of the denominator’s data must intersect with |
filter_tags | Text[] | a list of filters. Only denominators for which all of these apply are returned NULL to ignore (optional) |
numer_id | Text | the ID of a numerator to check whether the denominator is valid against. Will not reduce length of returned table, but will change values for valid_numer (optional) |
geom_id | Text | the ID of a geometry to check whether the denominator is valid against. Will not reduce length of returned table, but will change values for valid_geom (optional) |
timespan | Text | the ID of a timespan to check whether the denominator is valid against. Will not reduce length of returned table, but will change values for valid_timespan (optional) |
A TABLE containing the following properties
Key | Type | Description |
---|---|---|
denom_id | Text | The ID of the denominator |
denom_name | Text | A human readable name for the denominator |
denom_description | Text | Description of the denominator. Is sometimes NULL |
denom_weight | Numeric | Numeric “weight” of the denominator. Ignored. |
denom_license | Text | ID of the license for the denominator |
denom_source | Text | ID of the source for the denominator |
denom_type | Text | Postgres type of the denominator |
denom_aggregate | Text | Aggregate type of the denominator. If 'SUM' , this can be normalized by area |
denom_extra | JSONB | Extra information about the denominator column. Ignored. |
denom_tags | Text[] | Array of all tags applying to this denominator |
valid_numer | Boolean | True if the numer_id argument is a valid numerator for this denominator, False otherwise |
valid_geom | Boolean | True if the geom_id argument is a valid geometry for this denominator, False otherwise |
valid_timespan | Boolean | True if the timespan argument is a valid timespan for this denominator, False otherwise |
Obtain all denominators that are available within a small rectangle.
1
2
SELECT * FROM OBS_GetAvailableDenominators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326));
Obtain all denominators that are available within a small rectangle and are for the United States only.
1
2
SELECT * FROM OBS_GetAvailableDenominators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), '{section/tags.united_states}');
Obtain all denominators for male population (us.census.acs.B01001002
).
1
2
3
SELECT * FROM OBS_GetAvailableDenominators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, 'us.census.acs.B01001002')
WHERE valid_numer IS True;
Obtain all denominators that work with US states (us.census.tiger.state
)
as a geometry.
1
2
3
SELECT * FROM OBS_GetAvailableDenominators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, 'us.census.tiger.state')
WHERE valid_geom IS True;
Obtain all denominators available in the timespan 2011 - 2015
.
1
2
3
SELECT * FROM OBS_GetAvailableDenominators(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, NULL, '2011 - 2015')
WHERE valid_timespan IS True;
Return available geometries within a boundary and with the specified
filter_tags
.
Name | Type | Description |
---|---|---|
bounds | Geometry(Geometry, 4326) | a geometry which must intersect the geometry |
filter_tags | Text[] | a list of filters. Only geometries for which all of these apply are returned NULL to ignore (optional) |
numer_id | Text | the ID of a numerator to check whether the geometry is valid against. Will not reduce length of returned table, but will change values for valid_numer (optional) |
denom_id | Text | the ID of a denominator to check whether the geometry is valid against. Will not reduce length of returned table, but will change values for valid_denom (optional) |
timespan | Text | the ID of a timespan to check whether the geometry is valid against. Will not reduce length of returned table, but will change values for valid_timespan (optional) |
number_geometries | Integer | an additional variable that is used to adjust the calculation of the score (optional) |
A TABLE containing the following properties
Key | Type | Description |
---|---|---|
geom_id | Text | The ID of the geometry |
geom_name | Text | A human readable name for the geometry |
geom_description | Text | Description of the geometry. Is sometimes NULL |
geom_weight | Numeric | Numeric “weight” of the geometry. Ignored. |
geom_aggregate | Text | Aggregate type of the geometry. Ignored. |
geom_license | Text | ID of the license for the geometry |
geom_source | Text | ID of the source for the geometry |
geom_type | Text | Postgres type of the geometry |
geom_extra | JSONB | Extra information about the geometry column. Ignored. |
geom_tags | Text[] | Array of all tags applying to this geometry |
valid_numer | Boolean | True if the numer_id argument is a valid numerator for this geometry, False otherwise |
valid_denom | Boolean | True if the geom_id argument is a valid geometry for this geometry, False otherwise |
valid_timespan | Boolean | True if the timespan argument is a valid timespan for this geometry, False otherwise |
score | Numeric | Score between 0 and 100 for this geometry, higher numbers mean that this geometry is a better choice for the passed extent |
numtiles | Numeric | How many raster tiles were read for score, numgeoms, and percentfill estimates |
numgeoms | Numeric | About how many of these geometries fit inside the passed extent |
percentfill | Numeric | About what percentage of the passed extent is filled with these geometries |
estnumgeoms | Numeric | Ignored |
meanmediansize | Numeric | Ignored |
Obtain all geometries that are available within a small rectangle.
1
2
SELECT * FROM OBS_GetAvailableGeometries(
ST_MakeEnvelope(-74, 41, -73, 40, 4326));
Obtain all geometries that are available within a small rectangle and are for the United States only.
1
2
SELECT * FROM OBS_GetAvailableGeometries(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), '{section/tags.united_states}');
Obtain all geometries that work with total population (us.census.acs.B01003001
).
1
2
3
SELECT * FROM OBS_GetAvailableGeometries(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, 'us.census.acs.B01003001')
WHERE valid_numer IS True;
Obtain all geometries with timespan 2015
.
1
2
3
SELECT * FROM OBS_GetAvailableGeometries(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, NULL, '2015')
WHERE valid_timespan IS True;
Return available timespans within a boundary and with the specified
filter_tags
.
Name | Type | Description |
---|---|---|
bounds | Geometry(Geometry, 4326) | a geometry which some of the timespan’s data must intersect with |
filter_tags | Text[] | a list of filters. Ignore |
numer_id | Text | the ID of a numerator to check whether the timespans is valid against. Will not reduce length of returned table, but will change values for valid_numer (optional) |
denom_id | Text | the ID of a denominator to check whether the timespans is valid against. Will not reduce length of returned table, but will change values for valid_denom (optional) |
geom_id | Text | the ID of a geometry to check whether the timespans is valid against. Will not reduce length of returned table, but will change values for valid_geom (optional) |
A TABLE containing the following properties
Key | Type | Description |
---|---|---|
timespan_id | Text | The ID of the timespan |
timespan_name | Text | A human readable name for the timespan |
timespan_description | Text | Ignored |
timespan_weight | Numeric | Ignored |
timespan_aggregate | Text | Ignored |
timespan_license | Text | Ignored |
timespan_source | Text | Ignored |
timespan_type | Text | Ignored |
timespan_extra | JSONB | Ignored |
timespan_tags | JSONB | Ignored |
valid_numer | Boolean | True if the numer_id argument is a valid numerator for this timespan, False otherwise |
valid_denom | Boolean | True if the timespan argument is a valid timespan for this timespan, False otherwise |
valid_geom | Boolean | True if the geom_id argument is a valid geometry for this timespan, False otherwise |
Obtain all timespans that are available within a small rectangle.
1
2
SELECT * FROM OBS_GetAvailableTimespans(
ST_MakeEnvelope(-74, 41, -73, 40, 4326));
Obtain all timespans for total population (us.census.acs.B01003001
).
1
2
3
SELECT * FROM OBS_GetAvailableTimespans(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, 'us.census.acs.B01003001')
WHERE valid_numer IS True;
Obtain all timespans that work with US states (us.census.tiger.state
)
as a geometry.
1
2
3
SELECT * FROM OBS_GetAvailableTimespans(
ST_MakeEnvelope(-74, 41, -73, 40, 4326), NULL, NULL, NULL, 'us.census.tiger.state')
WHERE valid_geom IS True;