add geostore project

This commit is contained in:
Helmut Merz 2020-12-28 10:19:52 +01:00
parent 6497e84e4a
commit 8e1be09060
2 changed files with 113 additions and 0 deletions

93
pgsql/geostore/tables.sql Normal file
View file

@ -0,0 +1,93 @@
-- steg/sql/tgeo.sql
set search_path to generic, public;
-- *** common tables ***
-- datatypes
create table datatypes (
id smallint not null primary key,
name text not null unique
);
insert into datatypes (id, name) values (10, 'text');
insert into datatypes (id, name) values (16, 'date');
insert into datatypes (id, name) values (20, 'int');
insert into datatypes (id, name) values (21, 'bool');
insert into datatypes (id, name) values (25, 'valuelist');
insert into datatypes (id, name) values (30, 'decimal');
insert into datatypes (id, name) values (35, 'timestamp');
create index idx_datatype_name on datatypes using btree (name);
-- properties
create table properties (
id serial not null primary key,
name text,
label text,
description text,
datatype smallint not null references datatypes,
domain text,
pattern text
);
-- for data see properties.sql
create index idx_prop_label on properties using btree (label);
-- valuelists
create table valuelists (
id bigserial not null primary key,
property int not null references properties,
value text,
pattern text
);
-- *** GIS-specific tables ***
-- geotypes
create table geotypes (
id smallint not null primary key,
name text not null unique
);
insert into geotypes (id, name) values
(0, 'area'),
(1, 'realestate'),
(2, 'building'),
(10, 'line'),
(20, 'point');
-- geoitems
create table geoitems (
id bigserial not null primary key,
geom geometry(geometry, 25832) not null, -- unique?
type smallint not null references geotypes,
name text,
description text,
community int not null
);
create index fki_item_type on geoitems using btree (type);
create index idx_item_geom on geoitems using brin (geom);
create index idx_item_community on geoitems using btree (community);
-- geoattrs
create table geoattrs (
id bigserial not null primary key,
item bigint not null references geoitems,
property int not null references properties,
txtvalue text,
intvalue bigint
);
create index fki_attr_item on geoattrs using btree (item);
create index fki_attr_prop on geoattrs using btree (property);
create index idx_attr_txtv on geoattrs using btree (property, txtvalue);
create index idx_attr_intv on geoattrs using btree (property, intvalue);

20
pgsql/geostore/views.sql Normal file
View file

@ -0,0 +1,20 @@
-- steg/sql/vgeo.sql
set search_path to generic, public;
create or replace view vgeoattrs as
select i.id as item_id, i.geom, i.type, i.name as item_name,
i.description as item_description, i.community,
a.id as attr_id, p.id as prop_id,
p.name as prop_name, p.label as prop_label,
p.description as prop_description, p.datatype,
p.domain as prop_domain,
case when p.datatype = 25 then vl.value
else a.txtvalue
end as txtvalue,
a.intvalue
from geoitems i
left join geoattrs a on a.item = i.id
left join properties p on p.id = a.property
left join valuelists vl on
p.datatype = 25 and vl.property = p.id and vl.id = a.intvalue;