Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

temporal: use UPDATE-FROM syntax for updating metadata tables #3359

Merged
merged 9 commits into from
Feb 3, 2024
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
101 changes: 57 additions & 44 deletions lib/temporal/SQL/update_stds_spatial_temporal_extent_template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -5,6 +5,7 @@
--
--
-- Author: Soeren Gebbert soerengebbert <at> googlemail <dot> com
-- UPDATE FROM syntax: Stefan Blumentrath stefan <dot> blumentrath <at> gmx <dot> de
--#############################################################################

-- SPACETIME_REGISTER_TABLE is a placeholder for specific stds map register table name (SQL compliant)
Expand All @@ -14,53 +15,65 @@

-- UPDATE STDS_base SET modification_time = datetime("NOW") WHERE id = 'SPACETIME_ID';
-- UPDATE STDS_base SET revision = (revision + 1) WHERE id = 'SPACETIME_ID';

-- Number of registered maps
UPDATE STDS_metadata SET number_of_maps =
(SELECT count(id) FROM SPACETIME_REGISTER_TABLE)
WHERE id = 'SPACETIME_ID';

-- Update the temporal extent
UPDATE STDS_absolute_time SET start_time =
(SELECT min(start_time) FROM GRASS_MAP_absolute_time WHERE GRASS_MAP_absolute_time.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_absolute_time SET end_time =
(SELECT max(end_time) FROM GRASS_MAP_absolute_time WHERE GRASS_MAP_absolute_time.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_relative_time SET start_time =
(SELECT min(start_time) FROM GRASS_MAP_relative_time WHERE GRASS_MAP_relative_time.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_relative_time SET end_time =
(SELECT max(end_time) FROM GRASS_MAP_relative_time WHERE GRASS_MAP_relative_time.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_absolute_time
SET
start_time = new_stats.start_time_new,
end_time = new_stats.end_time_new
FROM
(SELECT
min(start_time) AS start_time_new,
max(end_time) AS end_time_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
GRASS_MAP_absolute_time ON
SPACETIME_REGISTER_TABLE.id = GRASS_MAP_absolute_time.id
) AS new_stats
WHERE STDS_absolute_time.id = 'SPACETIME_ID';

UPDATE STDS_relative_time
SET
start_time = new_stats.start_time_new,
end_time = new_stats.end_time_new
FROM
(SELECT
min(start_time) AS start_time_new,
max(end_time) AS end_time_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
GRASS_MAP_relative_time ON
SPACETIME_REGISTER_TABLE.id = GRASS_MAP_relative_time.id
) AS new_stats
WHERE STDS_relative_time.id = 'SPACETIME_ID';

-- Update the spatial extent
UPDATE STDS_spatial_extent SET north =
(SELECT max(north) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET south =
(SELECT min(south) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET east =
(SELECT max(east) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET west =
(SELECT min(west) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET top =
(SELECT max(top) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET bottom =
(SELECT min(bottom) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent SET proj =
(SELECT min(proj) FROM GRASS_MAP_spatial_extent WHERE GRASS_MAP_spatial_extent.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE STDS_spatial_extent
SET
north = new_stats.north_new,
south = new_stats.south_new,
east = new_stats.east_new,
west = new_stats.west_new,
top = new_stats.top_new,
bottom = new_stats.bottom_new,
proj = new_stats.proj_new
FROM
(SELECT
max(north) AS north_new,
min(south) AS south_new,
max(east) AS east_new,
min(west) AS west_new,
max(top) AS top_new,
min(bottom) AS bottom_new,
min(proj) AS proj_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
GRASS_MAP_spatial_extent ON
SPACETIME_REGISTER_TABLE.id = GRASS_MAP_spatial_extent.id
) AS new_stats
WHERE STDS_spatial_extent.id = 'SPACETIME_ID';
75 changes: 33 additions & 42 deletions lib/temporal/SQL/update_str3ds_metadata_template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,50 +2,41 @@
-- This SQL script is to update a space-time raster3d dataset metadata
--
-- Author: Soeren Gebbert soerengebbert <at> googlemail <dot> com
-- UPDATE FROM syntax: Stefan Blumentrath stefan <dot> blumentrath <at> gmx <dot> de
--#############################################################################

-- SPACETIME_REGISTER_TABLE is a placeholder for specific stds map register table name (SQL compliant)
-- SPACETIME_ID is a placeholder for specific stds id: name@mapset

-- Update the min and max values
UPDATE str3ds_metadata SET min_min =
(SELECT min(min) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET min_max =
(SELECT max(min) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET max_min =
(SELECT min(max) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET max_max =
(SELECT max(max) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
-- Update the resolution
UPDATE str3ds_metadata SET nsres_min =
(SELECT min(nsres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET nsres_max =
(SELECT max(nsres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET ewres_min =
(SELECT min(ewres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET ewres_max =
(SELECT max(ewres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET tbres_min =
(SELECT min(tbres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata SET tbres_max =
(SELECT max(tbres) FROM raster3d_metadata WHERE raster3d_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE str3ds_metadata
SET
-- Update the min and max values
min_min = new_stats.min_min_new,
min_max = new_stats.min_max_new,
max_min = new_stats.max_min_new,
max_max = new_stats.max_max_new,
-- Update the resolution
nsres_min = new_stats.nsres_min_new,
nsres_max = new_stats.nsres_max_new,
ewres_min = new_stats.ewres_min_new,
ewres_max = new_stats.ewres_max_new,
tbres_min = new_stats.tbres_min_new,
tbres_max = new_stats.tbres_max_new
FROM
(SELECT
min(min) AS min_min_new,
max(min) AS min_max_new,
min(max) AS max_min_new,
max(max) AS max_max_new,
min(nsres) AS nsres_min_new,
max(nsres) AS nsres_max_new,
min(ewres) AS ewres_min_new,
max(ewres) AS ewres_max_new,
min(tbres) AS tbres_min_new,
max(tbres) AS tbres_max_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
raster3d_metadata ON
SPACETIME_REGISTER_TABLE.id = raster3d_metadata.id
) AS new_stats
WHERE str3ds_metadata.id = 'SPACETIME_ID';
67 changes: 33 additions & 34 deletions lib/temporal/SQL/update_strds_metadata_template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -2,42 +2,41 @@
-- This SQL is to update a space-time raster dataset metadata
--
-- Author: Soeren Gebbert soerengebbert <at> googlemail <dot> com
-- UPDATE FROM syntax: Stefan Blumentrath stefan <dot> blumentrath <at> gmx <dot> de
--#############################################################################

-- SPACETIME_REGISTER_TABLE is a placeholder for specific stds map register table name (SQL compliant)
-- SPACETIME_ID is a placeholder for specific stds id: name@mapset
-- for TGIS < 3 the lines for semantic lables get replaced / commented out

-- Update the min and max values
UPDATE strds_metadata SET min_min =
(SELECT min(min) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET min_max =
(SELECT max(min) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET max_min =
(SELECT min(max) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET max_max =
(SELECT max(max) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
-- Update the resolution
UPDATE strds_metadata SET nsres_min =
(SELECT min(nsres) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET nsres_max =
(SELECT max(nsres) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET ewres_min =
(SELECT min(ewres) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata SET ewres_max =
(SELECT max(ewres) FROM raster_metadata WHERE raster_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE strds_metadata
SET
-- Update the min and max values
number_of_semantic_labels = number_of_semantic_labels_new,
-- Update the min and max values
min_min = new_stats.min_min_new,
min_max = new_stats.min_max_new,
max_min = new_stats.max_min_new,
max_max = new_stats.max_max_new,
-- Update the resolution
nsres_min = new_stats.nsres_min_new,
nsres_max = new_stats.nsres_max_new,
ewres_min = new_stats.ewres_min_new,
ewres_max = new_stats.ewres_max_new
FROM
(SELECT
count(distinct semantic_label) AS number_of_semantic_labels_new,
min(min) AS min_min_new,
max(min) AS min_max_new,
min(max) AS max_min_new,
max(max) AS max_max_new,
min(nsres) AS nsres_min_new,
max(nsres) AS nsres_max_new,
min(ewres) AS ewres_min_new,
max(ewres) AS ewres_max_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
raster_metadata ON
SPACETIME_REGISTER_TABLE.id = raster_metadata.id
) AS new_stats
WHERE strds_metadata.id = 'SPACETIME_ID';
15 changes: 0 additions & 15 deletions lib/temporal/SQL/update_strds_metadata_template_v3.sql

This file was deleted.

83 changes: 35 additions & 48 deletions lib/temporal/SQL/update_stvds_metadata_template.sql
Original file line number Diff line number Diff line change
Expand Up @@ -3,57 +3,44 @@
-- concept is clear
--
-- Author: Soeren Gebbert soerengebbert <at> googlemail <dot> com
-- UPDATE FROM syntax: Stefan Blumentrath stefan <dot> blumentrath <at> gmx <dot> de
--#############################################################################

-- SPACETIME_REGISTER_TABLE is a placeholder for specific stds map register table name (SQL compliant)
-- SPACETIME_ID is a placeholder for specific stds id: name@mapset

-- Update the vector features and topology
UPDATE stvds_metadata SET points =
(SELECT sum(points) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET lines =
(SELECT sum(lines) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET boundaries =
(SELECT sum(boundaries) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET centroids =
(SELECT sum(centroids) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET faces =
(SELECT sum(faces) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET kernels =
(SELECT sum(kernels) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET primitives =
(SELECT sum(primitives) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET nodes =
(SELECT sum(nodes) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET areas =
(SELECT sum(areas) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET islands =
(SELECT sum(islands) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET holes =
(SELECT sum(holes) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata SET volumes =
(SELECT sum(volumes) FROM vector_metadata WHERE vector_metadata.id IN
(SELECT id FROM SPACETIME_REGISTER_TABLE)
) WHERE id = 'SPACETIME_ID';
UPDATE stvds_metadata
SET
points = new_stats.points_new,
lines = new_stats.lines_new,
boundaries = new_stats.boundaries_new,
centroids = new_stats.centroids_new,
faces = new_stats.faces_new,
kernels = new_stats.kernels_new,
primitives = new_stats.primitives_new,
nodes = new_stats.nodes_new,
areas = new_stats.areas_new,
islands = new_stats.islands_new,
holes = new_stats.holes_new,
volumes = new_stats.volumes_new
FROM
(SELECT
sum(points) AS points_new,
sum(lines) AS lines_new,
sum(boundaries) AS boundaries_new,
sum(centroids) AS centroids_new,
sum(faces) AS faces_new,
sum(kernels) AS kernels_new,
sum(primitives) AS primitives_new,
sum(nodes) AS nodes_new,
sum(areas) AS areas_new,
sum(islands) AS islands_new,
sum(holes) AS holes_new,
sum(volumes) AS volumes_new
FROM
SPACETIME_REGISTER_TABLE INNER JOIN
vector_metadata ON
SPACETIME_REGISTER_TABLE.id = vector_metadata.id
) AS new_stats
WHERE stvds_metadata.id = 'SPACETIME_ID';
Loading
Loading