data
This module contains functions and procedures that make use of data (user-provided data) for their computations.
ENRICH_GRID
ENRICH_GRID(grid_type, input_query, input_index_column, data_query data_geography_column, variables, output)Description
This procedure enriches a query containing grid cell indexes of one of the supported types (H3, Quadbin) with data from another enrichment query that contains geographies, thus effectively transferring geography-based data to an spatial grid.
As a result of this process, each input grid cell will be enriched with the data of the enrichment query that spatially intersects it. When the input cell intersects with more than one feature of the enrichment query, the data is aggregated using the aggregation methods specified.
Valid aggregation methods are:
SUM: It assumes the aggregated variable is an extensive property (e.g. population). Accordingly, the value corresponding to the enrichment feature intersected is weighted by the fraction of area or length intersected. If the enrichment features are points, then a simple sum is performed.MIN: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM.MAX: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM.AVG: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM. However, a weighted average is computed, using the intersection areas or lengths as the weight. When the enrichment features are points, a simple average is computed.COUNTIt computes the number of enrichment features that contain the enrichment variable and are intersected by the input geography.
For other types of aggregation, the ENRICH_GRID_RAW procedure can be used to obtain non-aggregated data that can be later applied to any desired custom aggregation.
Input parameters
grid_type: Type of grid: "h3" or "quadbin".input_query:VARCHARquery to be enriched; this query must produce valid grid indexes for the selected grid type in a column of the proper type (VARCHAR for H3 and INT for Quadbin). It can include additional columns with data associated with the grid cells that will be preserved. A qualified table name can be given as well.input_index_column:VARCHARname of a column in the query that contains the grid indexes.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the polygons provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYwith the columns that will be used to enrich the input polygons and their corresponding aggregation method (SUM,AVG,MAX,MIN,COUNT). Each element in this array should be anOBJECTwith fieldscolumnandaggregation.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Note that GeometryCollection/FeatureCollection geographies are not supported at the moment.
Output
The output table will contain all the input columns provided in the input_query and one extra column for each variable in variables, named after its corresponding enrichment column and including a suffix indicating the aggregation method used.
If a new output table is created, it will be clustered by the spatial index to optimize its performance when filtering data by it or using it to join to other grid tables. This is important to visualize the results in a map efficiently. If an SQL clause is included in the output parameter this optimization will not be performed.
Examples
CALL CARTO.CARTO.ENRICH_GRID(
'h3',
$
SELECT value AS index FROM TABLE(FLATTEN(ARRAY_CONSTRUCT(
'8718496d8ffffff','873974865ffffff','87397486cffffff','8718496daffffff','873974861ffffff','8718496dbffffff','87397494bffffff','8718496ddffffff','873974864ffffff'
)))
$,
'index',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: INDEX, VAR1_SUM, VAR2_SUM, VAR2_MAXCALL CARTO.CARTO.ENRICH_GRID(
'h3',
'mydb.myschema.mytable',
'index',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be augmented
-- with columns: VAR1_SUM, VAR2_SUM, VAR2_MAXENRICH_GRID_RAW
ENRICH_GRID_RAW(grid_type, input_query, input_index_column, data_query data_geography_column, variables, output)Description
This procedure enriches a query containing grid cell indexes of one of the supported types (H3, Quadbin) with data from another enrichment query that contains geographies, thus effectively transferring geography-based data to an spatial grid.
Input parameters
grid_type: Type of grid: "h3" or "quadbin".input_query:VARCHARquery to be enriched; this query must produce valid grid indexes for the selected grid type in a column of the proper type (VARCHAR for H3 and INT for Quadbin). It can include additional columns with data associated with the grid cells that will be preserved. A qualified table name can be given as well.input_index_column:VARCHARname of a column in the query that contains the grid indexes.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the polygons provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYofVARCHARelements with names of the columns in the enrichment query that will be added to the enriched results.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Note that GeometryCollection/FeatureCollection geographies are not supported at the moment.
Output
The output table will contain all the input columns provided in the input_query and one extra ARRAY column named __CARTO_ENRICHMENT. The array contains OBJECTs with one field for each variable. Additional fields will be included with information about the intersection of the geographies:
__carto_dimensiondimension of the enrichment geography: 2 for areas (polygons), 1 for lines and 0 for points.__carto_intersectionarea in square meters (for dimension = 2) or length in meters (for dimension = 1) of the intersection.__carto_totalarea in square meters (for dimension = 2) or length in meters (for dimension = 1) of the enrichment feature.
If a new output table is created, it will be clustered by the spatial index to optimize its performance when filtering data by it or using it to join to other grid tables. This is important to visualize the results in a map efficiently. If an SQL clause is included in the output parameter this optimization will not be performed.
Examples
CALL CARTO.CARTO.ENRICH_GRID_RAW(
'h3',
$
SELECT value AS index FROM TABLE(FLATTEN(ARRAY_CONSTRUCT(
'8718496d8ffffff','873974865ffffff','87397486cffffff','8718496daffffff','873974861ffffff','8718496dbffffff','87397494bffffff','8718496ddffffff','873974864ffffff'
)))
$,
'index',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: INDEX, __CARTO_ENRICHMENT. The latter will contain OBJECTSs with the fields VAR1, VAR2, __carto_intersection, __carto_total and __carto_dimension.CALL CARTO.CARTO.ENRICH_GRID_RAW(
'h3',
'mydb.myschema.mytable',
'index',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be augmented
-- with column __CARTO_ENRICHMENT which will contain OBJECTSs with the fields VAR1, VAR2, __carto_intersection, __carto_total and __carto_dimension.ENRICH_POINTS
ENRICH_POINTS(input_query, input_geography_column, data_query, data_geography_column, variables, output)Description
This procedure enriches a query containing geographic points with data from another query, spatially matching both and aggregating the result.
As a result of this process, each input point will be enriched with the data from the enrichment query that spatially intersects it. When the input point intersects with more than one enrichment polygon, point or line, the data is aggregated using the aggregation methods specified.
Valid aggregation methods are: SUM, MIN, MAX, AVG, and COUNT.
For special types of aggregation, the ENRICH_POINTS_RAW procedure can be used to obtain non-aggregated data that can be later applied to any desired custom aggregation.
Input parameters
input_query:VARCHARquery to be enriched. A qualified table name can be given as well.input_geography_column:VARCHARname of the GEOGRAPHY column in the query containing the points to be enriched.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the points provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYwith the columns that will be used to enrich the input polygons and their corresponding aggregation method (SUM,AVG,MAX,MIN,COUNT). Each element in this array should be anOBJECTwith fieldscolumnandaggregation.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Output
The output table will contain all the input columns provided in the input_query and one extra column for each variable in variables, named after its corresponding enrichment column and including a suffix indicating the aggregation method used.
If a new output table is created, it will be ordered by the x and y coordinates optimize the performance of spatial filters and joins. This is important to visualize the results in a map efficiently.
Examples
CALL CARTO.CARTO.ENRICH_POINTS(
'SELECT ID, GEOM FROM MYTABLE', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: ID, GEOM, VAR1_SUM, VAR2_SUM, VAR2_MAXCALL CARTO.CARTO.ENRICH_POINTS(
'mydb.myschema.mytable', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be created
-- with columns: VAR1_SUM, VAR2_SUM, VAR2_MAXENRICH_POINTS_RAW
ENRICH_POINTS_RAW(input_query, input_geography_column, data_query, data_geography_column, variables, output)Description
This procedure enriches a query containing geographic points with data from another query, spatially matching both.
As a result of this process, each input polygon will be enriched with the data from the enrichment query that spatially intersects it. The variable values corresponding to all intersecting enrichment features for a given input point will be returned in an ARRAY column named __CARTO_ENRICHMENT. Each array value in this column contains OBJECTSs with one field for each variable and additional measure fields __carto_total and __carto_dimension. See the output information for details.
Input parameters
input_query:VARCHARquery to be enriched. A qualified table name can be given as well.input_geography_column:VARCHARname of the GEOGRAPHY column in the query containing the points to be enriched.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the points provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYofVARCHARelements with names of the columns in the enrichment query that will be added to the enriched results.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Output
The output table will contain all the input columns provided in the input_query and one extra ARRAY column named __CARTO_ENRICHMENT. The array contains OBJECTs with one field for each variable. Additional fields will be included with information about the intersection of the geographies:
__carto_dimensiondimension of the enrichment geography: 2 for areas (polygons), 1 for lines, and 0 for points.__carto_totalarea in square meters (for dimension = 2) or length in meters (for dimension = 1) of the enrichment feature.
If a new output table is created, it will be ordered by the x and y coordinates optimize the performance of spatial filters and joins. This is important to visualize the results in a map efficiently.
Examples
CALL CARTO.CARTO.ENRICH_POINTS_RAW(
'SELECT ID, GEOM FROM MYTABLE', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: ID, GEOM, __CARTO_ENRICHMENT. The latter will contain OBJECTSs with the fields VAR1, VAR2, __carto_total and __carto_dimension.CALL CARTO.CARTO.ENRICH_POINTS_RAW(
'mydb.myschema.mytable', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be augmented
-- with column __CARTO_ENRICHMENT which will contain OBJECTSs with the fields VAR1, VAR2, __carto_total and __carto_dimension.ENRICH_POLYGONS
ENRICH_POLYGONS(input_query, input_geography_column, data_query, data_geography_column, variables, output)Description
This procedure enriches a query containing geographic polygons with data from another query, spatially matching both and aggregating the result.
As a result of this process, each input polygon will be enriched with the data from the enrichment query that spatially intersects it. When the input polygon intersects with more than one enrichment polygon, point or line, the data is aggregated using the aggregation methods specified.
Valid aggregation methods are:
SUM: It assumes the aggregated variable is an extensive property (e.g. population). Accordingly, the value corresponding to the enrichment feature intersected is weighted by the fraction of area or length intersected. If the enrichment features are points, then a simple sum is performed.MIN: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM.MAX: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM.AVG: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the intersected area/length as it's the case forSUM. However, a weighted average is computed, using the intersection areas or lengths as the weight. When the enrichment features are points, a simple average is computed.COUNTIt computes the number of enrichment features that contain the enrichment variable and are intersected by the input geography.
For other types of aggregation, the ENRICH_POLYGONS_RAW procedure can be used to obtain non-aggregated data that can be later applied to any desired custom aggregation.
Input parameters
input_query:VARCHARquery to be enriched. A qualified table name can be given as well.input_geography_column:VARCHARname of the GEOGRAPHY column in the query containing the polygons to be enriched.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the polygons provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYwith the columns that will be used to enrich the input polygons and their corresponding aggregation method (SUM,AVG,MAX,MIN,COUNT). Each element in this array should be anOBJECTwith fieldscolumnandaggregation.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Note that GeometryCollection/FeatureCollection geographies are not supported at the moment.
Output
The output table will contain all the input columns provided in the input_query and one extra column for each variable in variables, named after its corresponding enrichment column and including a suffix indicating the aggregation method used.
If a new output table is created, it will be ordered by the minimum x and y coordinates of each polygon to optimize the performance of spatial filters and joins. This is important to visualize the results in a map efficiently.
Examples
CALL CARTO.CARTO.ENRICH_POLYGONS(
'SELECT ID, GEOM FROM MYTABLE', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: ID, GEOM, VAR1_SUM, VAR2_SUM, VAR2_MAXCALL CARTO.CARTO.ENRICH_POLYGONS(
'mydb.myschema.mytable', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'VAR1', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'sum'),
OBJECT_CONSTRUCT('column', 'VAR2', 'aggregation', 'max')
),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be augmented
-- with columns: VAR1_SUM, VAR2_SUM, VAR2_MAXENRICH_POLYGONS_RAW
ENRICH_POLYGONS_RAW(input_query, input_geography_column, data_query, data_geography_column, variables, output)Description
This procedure enriches a query containing geographic polygons with data from another query, spatially matching both.
As a result of this process, each input polygon will be enriched with the data of the enrichment query that spatially intersects it. The variable values corresponding to all intersecting enrichment features for a given input polygon will be returned in an ARRAY column named __CARTO_ENRICHMENT. Each array value in this column contains OBJECTSs with one field for each variable and additional measure fields __carto_intersection, __carto_total and __carto_dimension. See the output information for details.
Input parameters
input_query:VARCHARquery to be enriched. A qualified table name can be given as well.input_geography_column:VARCHARname of the GEOGRAPHY column in the query containing the polygons to be enriched.data_query:VARCHARquery that contains both a geography column and the columns with the data that will be used to enrich the polygons provided in the input query. All rows in the table must contain the same kind of geometry (points/lines/polygons) in the geography column.data_geography_column:VARCHARname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYofVARCHARelements with names of the columns in the enrichment query that will be added to the enriched results.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Note that GeometryCollection/FeatureCollection geographies are not supported at the moment.
Output
The output table will contain all the input columns provided in the input_query and one extra ARRAY column named __CARTO_ENRICHMENT. The array contains OBJECTs with one field for each variable. Additional fields will be included with information about the intersection of the geographies:
__carto_dimensiondimension of the enrichment geography: 2 for areas (polygons), 1 for lines and 0 for points.__carto_intersectionarea in square meters (for dimension = 2) or length in meters (for dimension = 1) of the intersection.__carto_totalarea in square meters (for dimension = 2) or length in meters (for dimension = 1) of the enrichment feature.
Moreover, another field named __carto_input_area will be included in __CARTO_ENRICHMENT, containing the area of the input polygon in square meters.
If a new output table is created, it will be ordered by the minimum x and y coordinates of each polygon to optimize the performance of spatial filters and joins. This is important to visualize the results in a map efficiently.
Examples
CALL CARTO.CARTO.ENRICH_POLYGONS_RAW(
'SELECT ID, GEOM FROM MYTABLE', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('MYENRICHEDTABLE')
);
-- The table `MYENRICHEDTABLE` will be created
-- with columns: ID, GEOM, __CARTO_ENRICHMENT. The latter will contain OBJECTSs with the fields VAR1, VAR2, __carto_intersection, __carto_total, dimension and __carto_input_area.CALL CARTO.CARTO.ENRICH_POLYGONS_RAW(
'mydb.myschema.mytable', 'GEOM',
'SELECT GEOM, VAR1, VAR2 FROM MYDATATABLE', 'GEOM',
ARRAY_CONSTRUCT('VAR1', 'VAR2'),
TO_ARRAY('mydb.myschema.mytable')
);
-- The table `mydb.myschema.mytable` will be augmented
-- with columns __CARTO_ENRICHMENT which will contain OBJECTSs with the fields VAR1, VAR2, __carto_intersection, __carto_total, dimension and __carto_input_area.ENRICH_POLYGONS_WEIGHTED
ENRICH_POLYGONS_WEIGHTED(input_query, input_geography_column, data_query, data_geography_column, variables, weight_variable, custom_weight_query, output)Description
This procedure enriches a query containing geographic polygons with custom data provided by the user.
As a result of this process, each input polygon will be enriched with the custom data that spatially intersect it, weighted accordingly by the specified feature. When the input polygon intersects with more than one polygon, point, or line of the provided datasets, the data is aggregated using the aggregation methods specified. Using a speficied feature as weight for the enrichment, it weights appropiately the intersection segments with regard to the total original segment. For example the attribution of the feature to each intersected segment results from the value of the weighted feature in the intersection segment over the total original segment.
Valid aggregation methods are:
SUM: It assumes the aggregated variable is an extensive property (e.g. population). Accordingly, the value corresponding to the feature intersected is weighted by the fraction of the intersected weight variable.MIN: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the weight variable.MAX: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). Thus, the value is not altered by the weight variable.AVG: It assumes the aggregated variable is an intensive property (e.g. temperature, population density). A weighted average is computed, using the value of the intersected weight variable as weights.COUNTIt computes the number of features that contain the enrichment variable and are intersected by the input geography.
Input parameters
input_query:STRINGquery to be enriched (Standard SQL). A qualified table name can be given as well, e.g.'project-id.dataset-id.table-name'.input_geography_column:STRINGname of the GEOGRAPHY column in the query containing the polygons to be enriched.data_query:STRINGquery that contains both a geography column and the columns with the data that will be used to enrich the polygons provided in the input query.data_geography_column:STRINGname of the GEOGRAPHY column provided in thedata_query.variables:ARRAYwith the columns that will be used to enrich the input polygons and their corresponding aggregation method (SUM,AVG,MAX,MIN,COUNT). Each element in this array should be anOBJECTwith fieldscolumnandaggregation.weight_variable:OBJECTwith fieldsvariableandaggregation. Variable that will be used to weight the intersections of the input polygons with the Data Observatory datasets polygons, lines, points. Its slug and the aggregation method must be provided. Valid aggregation methods are:SUM,AVG,MAX,MIN,COUNT. This variable is mandatory. IfNULLthen an error is raised.custom_weight_query:STRINGquery that contains the custom variable to be used as weight together with a geography columngeom. If it is set toNULL, then thedata_queryis used for theweight_variable.output:ARRAYofVARCHARcontaining the name of an output table to store the results and optionally an SQL clause that can be used to partition it, e.g.'CLUSTER BY number'. When the output table is the same than then input, the input table will be enriched in place.
Output
The output table will contain all the input columns provided in the input_query and one extra column for each variable in variables, named after its corresponding name and including a suffix indicating the aggregation method used.
If a new output table is created, it will be clustered by the geography column to optimize the performance of spatial filters and joins. This is important to visualize the results in a map efficiently. If an SQL clause is included in the output parameter this optimization will not be performed.
Examples
CALL CARTO.CARTO.ENRICH_POLYGONS_WEIGHTED(
$
SELECT id, geom FROM mydb.myschema.myinputtable
$,
'geom',
$
SELECT id, v1, v2, geom FROM mydb.myschema.mytableenrich
$,
'geom',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'v1', 'aggregation', 'avg'),
OBJECT_CONSTRUCT('column', 'v2', 'aggregation', 'avg')
),
OBJECT_CONSTRUCT('column', 'v3', 'aggregation', 'sum'),
$
SELECT id, v3, geom FROM mydb.myschema.mytableweight
$,
TO_ARRAY('mydb.myschema.mytable')
);
-- The table mydb.myschema.mytable will be created
-- with columns: id, geom, v1_avg, v2_avgCALL CARTO.CARTO.ENRICH_POLYGONS_WEIGHTED(
$
SELECT id, geom FROM mydb.myschema.myinputtable
$,
'geom',
$
SELECT id, v1, v2, v3, geom FROM mydb.myschema.mytableenrich
$,
'geom',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'v1', 'aggregation', 'avg'),
OBJECT_CONSTRUCT('column', 'v2', 'aggregation', 'avg')
),
OBJECT_CONSTRUCT('column', 'v3', 'aggregation', 'sum'),
NULL,
TO_ARRAY('mydb.myschema.mytable')
);
-- The table mydb.myschema.mytable will be created
-- with columns: id, geom, v1_avg, v2_avgCALL CARTO.CARTO.ENRICH_POLYGONS_WEIGHTED(
$
SELECT id, geom FROM mydb.myschema.myinputtable
$,
'geom',
$
SELECT id, v1, v2, v3, geom FROM mydb.myschema.mytableenrich
$,
'geom',
ARRAY_CONSTRUCT(
OBJECT_CONSTRUCT('column', 'v1', 'aggregation', 'avg'),
OBJECT_CONSTRUCT('column', 'v2', 'aggregation', 'avg'),
OBJECT_CONSTRUCT('column', 'v2', 'aggregation', 'sum')
),
OBJECT_CONSTRUCT('column', 'v3', 'aggregation', 'sum'),
NULL,
TO_ARRAY('mydb.myschema.mytable')
);
-- The table mydb.myschema.mytable will be created
-- with columns: id, geom, v1_avg, v2_avg, v2_sumLast updated
Was this helpful?
