Retrieve table/view comments as tilejson (#871)

This commit is contained in:
Lucas 2023-09-12 12:59:59 +08:00 committed by GitHub
parent da05f43048
commit fa1bf4bdbd
No known key found for this signature in database
GPG Key ID: 4AEE18F83AFDEB23
11 changed files with 165 additions and 46 deletions

View File

@ -1,3 +1,61 @@
# Table Sources
Table Source is a database table which can be used to query [vector tiles](https://github.com/mapbox/vector-tile-spec). If a [PostgreSQL connection string](pg-connections.md) is given, Martin will publish all tables as data sources if they have at least one geometry column. If geometry column SRID is 0, a default SRID must be set, or else that geo-column/table will be ignored. All non-geometry table columns will be published as vector tile feature tags (properties).
# Modifying Tilejson
Martin will automatically generate a `TileJSON` manifest for each table source. It will contain the `name`, `description`, `minzoom`, `maxzoom`, `bounds` and `vector_layer` information.
For example, if there is a table `public.table_source`:
the default `TileJSON` might look like this (note that URL will be automatically adjusted to match the request host):
The table:
```sql
CREATE TABLE "public"."table_source" ( "gid" int4 NOT NULL, "geom" "public"."geometry" );
```
The TileJSON:
```json
{
"tilejson": "3.0.0",
"tiles": [
"http://localhost:3000/table_source/{z}/{x}/{y}"
],
"vector_layers": [
{
"id": "table_source",
"fields": {
"gid": "int4"
}
}
],
"bounds": [
-2.0,
-1.0,
142.84131509869133,
45.0
],
"description": "public.table_source.geom",
"name": "table_source"
}
```
By default the `description` and `name` is database identifies about this table, and the bounds is queried from database. You can fine tune these by adjusting `auto_publish` section in [configuration file](https://maplibre.org/martin/config-file.html#config-example).
## TileJSON in SQL Comments
Other than adjusting `auto_publish` section in configuration file, you can fine tune the `TileJSON` on the database side directly: Add a valid JSON as an SQL comment on the table.
Martin will merge table comment into the generated TileJSON using JSON Merge patch. The following example update description and adds attribution, version, foo(even a nested DIY field) fields to the TileJSON.
```sql
DO $do$ BEGIN
EXECUTE 'COMMENT ON TABLE table_source IS $tj$' || $$
{
"version": "1.2.3",
"attribution": "osm",
"description": "a description from table comment",
"foo": {"bar": "foo"}
}
$$::json || '$tj$';
END $do$;
```

View File

@ -1,10 +1,9 @@
use log::error;
use serde::{Deserialize, Serialize};
use tilejson::{Bounds, TileJSON};
use crate::config::UnrecognizedValues;
use crate::pg::config::PgInfo;
use crate::pg::utils::InfoMap;
use crate::pg::utils::{patch_json, InfoMap};
pub type FuncInfoSources = InfoMap<FunctionInfo>;
@ -67,34 +66,6 @@ impl FunctionInfo {
..Default::default()
}
}
/// Merge the `self.tilejson` from the function comment into the generated tilejson (param)
fn merge_json(&self, tilejson: TileJSON) -> TileJSON {
let Some(tj) = &self.tilejson else {
// Nothing to merge in, keep the original
return tilejson;
};
// Not the most efficient, but this is only executed once per source:
// * Convert the TileJSON struct to a serde_json::Value
// * Merge the self.tilejson into the value
// * Convert the merged value back to a TileJSON struct
// * In case of errors, return the original tilejson
let mut tilejson2 = match serde_json::to_value(tilejson.clone()) {
Ok(v) => v,
Err(e) => {
error!("Failed to serialize tilejson, unable to merge function comment: {e}");
return tilejson;
}
};
json_patch::merge(&mut tilejson2, tj);
match serde_json::from_value(tilejson2.clone()) {
Ok(v) => v,
Err(e) => {
error!("Failed to deserialize merged function comment tilejson: {e}");
tilejson
}
}
}
}
impl PgInfo for FunctionInfo {
@ -111,6 +82,6 @@ impl PgInfo for FunctionInfo {
tilejson.minzoom = self.minzoom;
tilejson.maxzoom = self.maxzoom;
tilejson.bounds = self.bounds;
self.merge_json(tilejson)
patch_json(tilejson, &self.tilejson)
}
}

View File

@ -5,7 +5,7 @@ use tilejson::{Bounds, TileJSON, VectorLayer};
use crate::config::UnrecognizedValues;
use crate::pg::config::PgInfo;
use crate::pg::utils::InfoMap;
use crate::pg::utils::{patch_json, InfoMap};
use crate::utils::sorted_opt_map;
pub type TableInfoSources = InfoMap<TableInfo>;
@ -81,6 +81,10 @@ pub struct TableInfo {
#[serde(flatten, skip_serializing)]
pub unrecognized: UnrecognizedValues,
/// TileJSON provider by the SQL comment. Shouldn't be serialized
#[serde(skip)]
pub tilejson: Option<serde_json::Value>,
}
impl PgInfo for TableInfo {
@ -106,6 +110,6 @@ impl PgInfo for TableInfo {
other: HashMap::default(),
};
tilejson.vector_layers = Some(vec![layer]);
tilejson
patch_json(tilejson, &self.tilejson)
}
}

View File

@ -49,7 +49,17 @@ WITH
geometry_columns.f_table_schema = sic.table_schema AND
geometry_columns.f_table_name = sic.table_name AND
geometry_columns.f_geometry_column = sic.column_name
GROUP BY 1, 2, 3, 4, 5, 6)
GROUP BY 1, 2, 3, 4, 5, 6),
descriptions AS (
-- comments on table/views
SELECT
pg_namespace.nspname AS schema_name,
relname AS table_name,
CAST(obj_description(relfilenode, 'pg_class') AS VARCHAR) AS description
FROM pg_class
JOIN pg_namespace ON pg_class.relnamespace = pg_namespace.oid
WHERE relkind = 'r' OR relkind = 'v'
)
SELECT schema,
name,
geom,
@ -61,10 +71,14 @@ SELECT schema,
jsonb_object_agg(columns.column_name, columns.type_name)
FILTER (WHERE columns.column_name IS NOT NULL AND columns.type_name != 'geometry'),
'{}'::jsonb
) as properties
) as properties,
dc.description
FROM annotated_geometry_columns AS gc
LEFT JOIN columns ON
gc.schema = columns.table_schema AND
gc.name = columns.table_name AND
gc.geom != columns.column_name
GROUP BY gc.schema, gc.name, gc.geom, gc.srid, gc.type, gc.is_view, gc.geom_idx;
LEFT JOIN descriptions AS dc on
gc.schema = dc.schema_name AND
gc.name = dc.table_name
GROUP BY gc.schema, gc.name, gc.geom, gc.srid, gc.type, gc.is_view, gc.geom_idx,dc.description;

View File

@ -1,8 +1,9 @@
use std::collections::HashMap;
use log::{info, warn};
use log::{debug, info, warn};
use postgis::ewkb;
use postgres_protocol::escape::{escape_identifier, escape_literal};
use serde_json::Value;
use tilejson::Bounds;
use crate::pg::config::PgInfo;
@ -27,10 +28,25 @@ pub async fn query_available_tables(pool: &PgPool) -> Result<SqlTableInfoMapMapM
let mut res = SqlTableInfoMapMapMap::new();
for row in &rows {
let schema: String = row.get("schema");
let table: String = row.get("name");
let tilejson = if let Some(text) = row.get("description") {
match serde_json::from_str::<Value>(text) {
Ok(v) => Some(v),
Err(e) => {
warn!("Unable to deserialize SQL comment on {schema}.{table} as tilejson, the automatically generated tilejson would be used: {e}");
None
}
}
} else {
debug!("Unable to find a SQL comment on {schema}.{table}, the tilejson would be generated automatically");
None
};
let info = TableInfo {
layer_id: None,
schema: row.get("schema"),
table: row.get("name"),
schema,
table,
geometry_column: row.get("geom"),
geometry_index: row.get("geom_idx"),
is_view: row.get("is_view"),
@ -46,6 +62,7 @@ pub async fn query_available_tables(pool: &PgPool) -> Result<SqlTableInfoMapMapM
prop_mapping: HashMap::new(),
unrecognized: HashMap::new(),
bounds: None,
tilejson,
};
// Warn for missing geometry indices. Ignore views since those can't have indices

View File

@ -3,7 +3,7 @@ use std::collections::HashMap;
use deadpool_postgres::tokio_postgres::types::Json;
use log::{error, info, warn};
use postgis::{ewkb, LineString, Point, Polygon};
use tilejson::Bounds;
use tilejson::{Bounds, TileJSON};
use crate::source::UrlQuery;
@ -20,6 +20,34 @@ pub fn json_to_hashmap(value: &serde_json::Value) -> InfoMap<String> {
hashmap
}
#[must_use]
pub fn patch_json(target: TileJSON, patch: &Option<serde_json::Value>) -> TileJSON {
let Some(tj) = patch else {
// Nothing to merge in, keep the original
return target;
};
// Not the most efficient, but this is only executed once per source:
// * Convert the TileJSON struct to a serde_json::Value
// * Merge the self.tilejson into the value
// * Convert the merged value back to a TileJSON struct
// * In case of errors, return the original tilejson
let mut tilejson2 = match serde_json::to_value(target.clone()) {
Ok(v) => v,
Err(e) => {
error!("Failed to serialize tilejson, unable to merge function comment: {e}");
return target;
}
};
json_patch::merge(&mut tilejson2, tj);
match serde_json::from_value(tilejson2.clone()) {
Ok(v) => v,
Err(e) => {
error!("Failed to deserialize merged function comment tilejson: {e}");
target
}
}
}
#[must_use]
pub fn query_to_json(query: &UrlQuery) -> Json<InfoMap<serde_json::Value>> {
let mut query_as_json = HashMap::new();

View File

@ -2,7 +2,7 @@
"tiles": {
"MixPoints": {
"content_type": "application/x-protobuf",
"description": "MixedCase.MixPoints.Geom"
"description": "a description from comment on table"
},
"auto_table": {
"content_type": "application/x-protobuf",
@ -116,8 +116,7 @@
"content_type": "image/png"
},
"table_source": {
"content_type": "application/x-protobuf",
"description": "public.table_source.geom"
"content_type": "application/x-protobuf"
},
"table_source_multiple_geom": {
"content_type": "application/x-protobuf",

View File

@ -23,6 +23,6 @@
}
}
],
"description": "public.table_source.geom\npublic.points1.geom\npublic.points2.geom",
"description": "public.points1.geom\npublic.points2.geom",
"name": "table_source,points1,points2"
}

View File

@ -11,6 +11,8 @@
}
}
],
"description": "public.table_source.geom",
"name": "table_source"
"name": "table_source",
"foo": {
"bar": "foo"
}
}

View File

@ -54,3 +54,20 @@ values (1, '02daedc70702ec68753fde38351f5d9d', '0101000020E610000050C4D38CE9DA61
(30, '404175d17b08782edc9d316c378adc86', '0101000020E6100000F9B5A5ADB7265BC0EE07F81F2F284840');
CREATE INDEX ON "MixedCase"."MixPoints" USING GIST ("Geom");
DO $do$ BEGIN
EXECUTE 'COMMENT ON TABLE "MixedCase"."MixPoints" IS $tj$' || $$
{
"description": "a description from comment on table",
"vector_layers": [
{
"id":"MixPoints",
"fields":{
"Gid":"int4",
"TABLE":"text"
}
}
]
}
$$::json || '$tj$';
END $do$;

View File

@ -33,3 +33,12 @@ INSERT INTO table_source(geom) values (GeomFromEWKT('SRID=4326;POINT(142.8403402
INSERT INTO table_source(geom) values (GeomFromEWKT('SRID=4326;POINT(142.84131509869133 11.92781306544329)'));
-- DO NOT CREATE INDEX ON GEOMETRY COLUMN -- this table is used in a test case
DO $do$ BEGIN
EXECUTE 'COMMENT ON TABLE table_source IS $tj$' || $$
{
"description": null,
"foo": {"bar": "foo"}
}
$$::json || '$tj$';
END $do$;