vector_metadata_table.sql 2.6 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263
  1. --#############################################################################
  2. -- This SQL script generates the vector table to store
  3. -- metadata for SQL queries and temporal GIS support.
  4. --
  5. -- Author: Soeren Gebbert soerengebbert <at> googlemail <dot> com
  6. --#############################################################################
  7. PRAGMA foreign_keys = ON;
  8. -- The metadata table
  9. CREATE TABLE vector_metadata (
  10. id VARCHAR NOT NULL, -- The id (PFK) is the unique identifier for all tables, it is based on name and mapset (name@mapset) and is used as primary foreign key
  11. stvds_register VARCHAR, -- The name of the table storing all space-time vector datasets in which this map is registered
  12. PRIMARY KEY (id),
  13. FOREIGN KEY (id) REFERENCES vector_base (id) ON DELETE CASCADE
  14. );
  15. -- Create the views to access all columns for the absolute and relative time
  16. CREATE VIEW vector_view_abs_time AS SELECT
  17. A1.id, A1.mapset,
  18. A1.name, A1.temporal_type,
  19. A1.creation_time, A1.modification_time,
  20. A1.revision, A1.creator,
  21. A2.start_time, A2.end_time,
  22. A3.north, A3.south, A3.east, A3.west, A3.proj,
  23. A4.stvds_register
  24. FROM vector_base A1, vector_absolute_time A2,
  25. vector_spatial_extent A3, vector_metadata A4
  26. WHERE A1.id = A2.id AND A1.id = A3.id AND A1.id = A4.id;
  27. CREATE VIEW vector_view_rel_time AS SELECT
  28. A1.id, A1.mapset,
  29. A1.name, A1.temporal_type,
  30. A1.creation_time, A1.modification_time,
  31. A1.revision, A1.creator,
  32. A2.interval,
  33. A3.north, A3.south, A3.east, A3.west, A3.proj,
  34. A4.stvds_register
  35. FROM vector_base A1, vector_relative_time A2,
  36. vector_spatial_extent A3, vector_metadata A4
  37. WHERE A1.id = A2.id AND A1.id = A3.id AND A1.id = A4.id;
  38. -- Create a trigger to update the modification time and revision number in case the metadata or timestanps have been updated
  39. CREATE TRIGGER update_vector_metadata AFTER UPDATE ON vector_metadata
  40. BEGIN
  41. UPDATE vector_base SET modification_time = datetime("NOW") WHERE id = old.id;
  42. UPDATE vector_base SET revision = (revision + 1) WHERE id = old.id;
  43. END;
  44. -- Create trigger for automated deletion of dependent rows, this should normally be done using foreign keys
  45. CREATE TRIGGER delete_vector_base AFTER DELETE ON vector_base
  46. BEGIN
  47. DELETE FROM vector_absolute_time WHERE id = old.id;
  48. DELETE FROM vector_relative_time WHERE id = old.id;
  49. DELETE FROM vector_spatial_extent WHERE id = old.id;
  50. DELETE FROM vector_metadata WHERE id = old.id;
  51. END;