Skip to content

Commit

Permalink
* entities and versions are connected via id not entity name
Browse files Browse the repository at this point in the history
* stats are row based not column based
  • Loading branch information
benedeki committed Apr 20, 2022
1 parent 6f7bff6 commit ad463f8
Show file tree
Hide file tree
Showing 7 changed files with 88 additions and 76 deletions.
86 changes: 51 additions & 35 deletions database/src/main/dataset_schema/add.sql
Original file line number Diff line number Diff line change
Expand Up @@ -51,58 +51,74 @@ $$
--
-------------------------------------------------------------------------------
DECLARE
_entity_type CHAR := 'S';
_key_entity BIGINT;
_new_entity BOOLEAN;
_latest_version INTEGER;
_locked BOOLEAN;
_disabled BOOLEAN;
BEGIN
SELECT E.entity_latest_version, E.locked_at IS NOT NULL, E.disabled_at IS NOT NULL

IF i_entity_version = 1 THEN
-- lock on stats to prevent competing inserts of new entity
PERFORM 1
FROM entity_base.stats S
WHERE S.entity_type = _entity_type
FOR UPDATE;
END IF;

SELECT E.id_entity, E.entity_latest_version, E.locked_at IS NOT NULL, E.disabled_at IS NOT NULL
FROM dataset_schema.entities E
WHERE E.entity_name = i_entity_name
FOR UPDATE
INTO _latest_version, _locked, _disabled;
INTO _key_entity, _latest_version, _locked, _disabled;

IF NOT found THEN
-- new schema, lock on stats will prevent racing insert of the same schema
PERFORM
FROM entity_base.stats
FOR UPDATE;
_new_entity := NOT found;

_latest_version = 0;
ELSIF _disabled THEN
status := 31;
status_text := 'Schema has been disabled';
RETURN ;
ELSIF _locked THEN
status := 32;
status_text := 'Schema is locked';
RETURN;
END IF;
IF _new_entity THEN
IF i_entity_version != 1 THEN
status := 50;
status_text := 'Schema version wrong';
RETURN;
END IF;

UPDATE entity_base.stats
SET entity_count = stats.entity_count + 1
WHERE entity_type = _entity_type;

IF _latest_version >= i_entity_version THEN
status := 51;
status_text := 'Schema already exists';
RETURN;
ELSIF _latest_version + 1 < i_entity_version THEN
status := 50;
status_text := 'Schema version wrong';
RETURN;
INSERT INTO dataset_schema.entities (entity_name, entity_latest_version, created_by)
VALUES (i_entity_name, i_entity_version, i_user_name)
RETURNING id_entity
INTO _key_entity;
ELSE
IF _disabled THEN
status := 31;
status_text := 'Schema has been disabled';
RETURN ;
ELSIF _locked THEN
status := 32;
status_text := 'Schema is locked';
RETURN;
ELSEIF _latest_version >= i_entity_version THEN
status := 51;
status_text := 'Schema already exists';
RETURN;
ELSIF _latest_version + 1 < i_entity_version THEN
status := 50;
status_text := 'Schema version wrong';
RETURN;
END IF;
END IF;

INSERT INTO dataset_schema.versions (entity_name, entity_version, entity_description, fields, updated_by)
VALUES (i_entity_name, i_entity_version, i_entity_description, i_fields, i_user_name)
INSERT INTO dataset_schema.versions (key_entity, entity_version, entity_description, fields, updated_by)
VALUES (_key_entity, i_entity_version, i_entity_description, i_fields, i_user_name)
RETURNING dataset_schema.versions.id_entity_version
INTO id_entity_version;

IF _latest_version = 0 THEN
INSERT INTO dataset_schema.entities (entity_name, entity_latest_version, created_by)
VALUES (i_entity_name, i_entity_version, i_user_name);

UPDATE entity_base.stats
SET schema_count = stats.schema_count + 1;
ELSE
IF NOT _new_entity THEN
UPDATE dataset_schema.entities
SET entity_latest_version = i_entity_version
WHERE entity_name = i_entity_name;
WHERE id_entity = _key_entity;
END IF;

status := 11;
Expand Down
6 changes: 5 additions & 1 deletion database/src/main/dataset_schema/entities.ddl
Original file line number Diff line number Diff line change
Expand Up @@ -18,10 +18,14 @@
CREATE TABLE dataset_schema.entities
(
entity_type CHAR NOT NULL DEFAULT 'S',
CONSTRAINT entities_pk PRIMARY KEY (entity_name)
CONSTRAINT entities_pk PRIMARY KEY (id_entity)
)
INHERITS (entity_base.entities);

ALTER TABLE dataset_schema.entities
ADD CONSTRAINT entities_unq UNIQUE (entity_name);


ALTER TABLE IF EXISTS dataset_schema.entities
ADD CONSTRAINT check_dataset_schema_entity_type CHECK (entity_type = 'S')
NOT VALID;
Expand Down
52 changes: 22 additions & 30 deletions database/src/main/dataset_schema/get.sql
Original file line number Diff line number Diff line change
Expand Up @@ -46,7 +46,7 @@ $$
-- Returns:
-- status - Status code
-- status_text - Status text
-- id_schema - Id of the schema
-- id_entity_version - Id of the schema
-- entity_name - name of the schema
-- entity_version - the version of the schema
-- entity_description - description of the schema
Expand All @@ -67,38 +67,29 @@ $$
--
-------------------------------------------------------------------------------
DECLARE
_key_entity BIGINT;
_entity_version INTEGER;
_created_by TEXT;
_created_at TIMESTAMP WITH TIME ZONE;
_locked_by TEXT;
_locked_at TIMESTAMP WITH TIME ZONE;
_disabled_by TEXT;
_disabled_at TIMESTAMP WITH TIME ZONE;
BEGIN
SELECT coalesce(i_entity_version, E.entity_latest_version), E.created_by, E.created_at,
E.locked_by, E.locked_at, E.disabled_by, E.locked_at
SELECT E.id_entity, coalesce(i_entity_version, E.entity_latest_version), E.entity_name,
E.created_by, E.created_at, E.locked_by, E.locked_at, E.disabled_by, E.disabled_at
FROM dataset_schema.entities E
WHERE E.entity_name = i_entity_name
INTO _entity_version, _created_by, _created_at ,
_locked_by, _locked_at , _disabled_by, _disabled_at ;
INTO _key_entity, _entity_version, get.entity_name,
get.created_by, get.created_at, get.locked_by, get.locked_at, get.disabled_by, get.disabled_at;

IF NOT found THEN
status := 40;
status_text := 'Schema does not exist';
RETURN;
END IF;

SELECT 10, 'OK', dsv.id_entity_version, dsv.entity_name, dsv.entity_version,
dsv.entity_description, dsv.fields, _created_by, _created_at,
dsv.updated_by, dsv.updated_at , _locked_by, _locked_at,
_disabled_by, _disabled_at
FROM dataset_schema.versions dsv
WHERE dsv.entity_name = i_entity_name AND
dsv.entity_version = _entity_version
SELECT 10, 'OK', V.id_entity_version, V.entity_version, V.entity_description,
V.fields, V.updated_by, V.updated_at
FROM dataset_schema.versions V
WHERE V.key_entity = _key_entity AND
V.entity_version = _entity_version
INTO status, status_text, get.id_entity_version, get.entity_name, get.entity_version,
get.entity_description, get.fields, created_by, created_at,
get.updated_by, get.updated_at, locked_by, locked_at,
disabled_by, disabled_at;
get.entity_description, get.fields, get.updated_by, get.updated_at;

IF NOT found THEN
status := 43;
Expand Down Expand Up @@ -142,7 +133,7 @@ $$
-- Returns:
-- status - Status code
-- status_text - Status text
-- id_schema - Id of the schema
-- id_entity_version - Id of the schema
-- entity_name - name of the schema
-- entity_version - the version of the schema
-- entity_description - description of the schema
Expand All @@ -162,13 +153,14 @@ $$
--
-------------------------------------------------------------------------------
DECLARE
_key_entity BIGINT;
BEGIN

SELECT 10, 'OK', dsv.id_entity_version, dsv.entity_name, dsv.entity_version,
dsv.entity_description, dsv.fields, dsv.updated_by, dsv.updated_at
FROM dataset_schema.versions dsv
WHERE dsv.id_entity_version = i_key_entity_version
INTO status, status_text, get.id_entity_version, get.entity_name, get.entity_version,
SELECT 10, 'OK', V.id_entity_version, V.key_entity,V.entity_version,
V.entity_description, V.fields, V.updated_by, V.updated_at
FROM dataset_schema.versions V
WHERE V.id_entity_version = i_key_entity_version
INTO status, status_text, get.id_entity_version, _key_entity, get.entity_version,
get.entity_description, get.fields, get.updated_by, get.updated_at;

IF NOT found THEN
Expand All @@ -178,11 +170,11 @@ BEGIN
END IF;


SELECT E.created_by, E.created_at , E.locked_by, E.locked_at ,
SELECT E.entity_name, E.created_by, E.created_at, E.locked_by, E.locked_at,
E.disabled_by, E.locked_at
FROM dataset_schema.entities E
WHERE E.entity_name = get.entity_name
INTO get.created_by, get.created_at, get.locked_by, get.locked_at,
WHERE E.id_entity = _key_entity
INTO get.entity_name, get.created_by, get.created_at, get.locked_by, get.locked_at,
get.disabled_by, get.disabled_at;

RETURN;
Expand Down
2 changes: 1 addition & 1 deletion database/src/main/dataset_schema/versions.ddl
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,6 @@ CREATE TABLE dataset_schema.versions
INHERITS (entity_base.versions);

ALTER TABLE dataset_schema.versions
ADD CONSTRAINT versions_unq UNIQUE (entity_name, entity_version);
ADD CONSTRAINT versions_unq UNIQUE (key_entity, entity_version);

ALTER TABLE dataset_schema.versions OWNER to enceladus;
1 change: 1 addition & 0 deletions database/src/main/entity_base/entities.ddl
Original file line number Diff line number Diff line change
Expand Up @@ -17,6 +17,7 @@

CREATE TABLE entity_base.entities
(
id_entity BIGINT NOT NULL DEFAULT global_id(),
entity_name TEXT NOT NULL,
entity_latest_version INTEGER NOT NULL,
entity_type CHAR NOT NULL,
Expand Down
15 changes: 7 additions & 8 deletions database/src/main/entity_base/stats.ddl
Original file line number Diff line number Diff line change
Expand Up @@ -17,16 +17,15 @@

CREATE TABLE entity_base.stats
(
schema_count INTEGER NOT NULL,
mapping_table_count INTEGER NOT NULL,
dataset_count INTEGER NOT NULL
entity_type CHAR NOT NULL,
entity_count INTEGER NOT NULL DEFAULT 0,
CONSTRAINT stats_pk PRIMARY KEY (entity_type)
);

ALTER TABLE entity_base.stats
OWNER to enceladus;

INSERT INTO entity_base.stats(schema_count, mapping_table_count, dataset_count)
VALUES (0, 0, 0);

CREATE RULE entity_base_stats_del_protect AS ON DELETE TO entity_base.stats DO INSTEAD NOTHING;
CREATE RULE entity_base_stats_ins_protect AS ON INSERT TO entity_base.stats DO INSTEAD NOTHING;
INSERT INTO entity_base.stats(entity_type)
VALUES ('S'),
('M'),
('D');
2 changes: 1 addition & 1 deletion database/src/main/entity_base/versions.ddl
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@
CREATE TABLE entity_base.versions
(
id_entity_version BIGINT NOT NULL DEFAULT global_id(),
entity_name TEXT NOT NULL,
key_entity BIGINT NOT NULL,
entity_version INTEGER NOT NULL,
entity_description TEXT,
updated_by TEXT NOT NULL,
Expand Down

0 comments on commit ad463f8

Please sign in to comment.