475 lines
19 KiB
PL/PgSQL
475 lines
19 KiB
PL/PgSQL
DROP SCHEMA public CASCADE;
|
||
CREATE SCHEMA public;
|
||
GRANT ALL ON SCHEMA public TO postgres;
|
||
GRANT ALL ON SCHEMA public TO public;
|
||
|
||
create extension IF NOT EXISTS "ltree";
|
||
|
||
create OR REPLACE function perm_to_numeric ( m_owner INT, m_group INT, m_other INT )
|
||
RETURNS INT AS $$
|
||
BEGIN RETURN cast((m_owner << 6) | (m_group << 3 | m_other << 0) AS INT); END $$
|
||
LANGUAGE plpgsql immutable COST 1;
|
||
|
||
|
||
create OR REPLACE function unix_to_numeric (unixperm VARCHAR)
|
||
RETURNS INT AS $$
|
||
DECLARE txt CHAR(3);
|
||
BEGIN
|
||
txt := right(unixperm, 3);
|
||
RETURN perm_to_numeric(cast(substring(txt, 1, 1) AS INT), cast(substring(txt, 2, 1) AS INT), cast(substring(txt, 3, 1) AS INT));
|
||
END $$
|
||
LANGUAGE plpgsql immutable cost 1;
|
||
|
||
|
||
-- set session "eedb.user.id" = '1234';
|
||
create or replace function app_current_user_id()
|
||
returns int as $$
|
||
begin
|
||
return current_setting('eedb.user.id', TRUE)::int;
|
||
end $$ --$$
|
||
language plpgsql stable cost 1;
|
||
|
||
|
||
create or replace function app_root_id()
|
||
returns int as $$
|
||
begin
|
||
-- return current_setting('eedb.root_user.id', TRUE)::int;
|
||
return 0;
|
||
end $$ --$$
|
||
language plpgsql stable cost 1;
|
||
|
||
|
||
create or replace function app_current_user_group()
|
||
returns int as $$
|
||
begin
|
||
return current_setting('eedb.user.id', TRUE)::int;
|
||
end $$ -- $$
|
||
language plpgsql stable;
|
||
|
||
|
||
create OR REPLACE function last_update_column()
|
||
RETURNS trigger AS $$
|
||
BEGIN
|
||
NEW.updated = now();
|
||
RETURN NEW;
|
||
END; $$ -- $$
|
||
language 'plpgsql';
|
||
|
||
create table "system_info"(
|
||
"id" serial not null,
|
||
"name" text,
|
||
"value" jsonb,
|
||
"when" timestamp,
|
||
constraint "pk_system_info" primary key ("id")
|
||
);
|
||
create index "ix_system_info_name"
|
||
on "system_info"("name")
|
||
with ( FILLFACTOR=100 );
|
||
comment on table "system_info"
|
||
is 'table introduced to save information about system e.g. actual db version / application version etc';
|
||
comment on column "system_info"."name"
|
||
is '';
|
||
comment on column "system_info"."value"
|
||
is '';
|
||
|
||
create table "group" (
|
||
"gid" serial not null,
|
||
"name" text not null,
|
||
constraint "pk_group_gid" primary key ("gid"),
|
||
constraint "ux_group_name" unique ("name")
|
||
);
|
||
create trigger "update_user_group_last_update"
|
||
before update on "group" for each row execute procedure last_update_column();
|
||
insert into "group"("name") values ('nogroup'), ('admins'), ('moderators'), ('users');
|
||
|
||
create or replace function default_group_id()
|
||
returns int as $$
|
||
declare id integer;
|
||
BEGIN
|
||
SELECT "group"."gid" FROM "group" WHERE "group"."name" = 'nogroup' limit 1 into id;
|
||
return id;
|
||
end $$ -- $$
|
||
language 'plpgsql';
|
||
|
||
create or replace function default_users_group_id()
|
||
returns int as $$
|
||
declare id integer;
|
||
BEGIN
|
||
SELECT "group"."gid" FROM "group" WHERE "group"."name" = 'users' limit 1 into id;
|
||
return id;
|
||
end $$ -- $$
|
||
language 'plpgsql';
|
||
|
||
create or replace function default_admins_group_id()
|
||
returns int as $$
|
||
declare id integer;
|
||
BEGIN
|
||
SELECT "group"."gid" FROM "group" WHERE "group"."name" = 'admins' limit 1 into id;
|
||
return id;
|
||
end $$ -- $$
|
||
language 'plpgsql'; -- $$
|
||
|
||
create table "auth_info" (
|
||
"id" serial not null,
|
||
"group" int not null default default_users_group_id(),
|
||
"created" timestamp DEFAULT now() not null,
|
||
"updated" timestamp,
|
||
"config" json not null DEFAULT ('{}'),
|
||
"password_hash" varchar(100) not null,
|
||
"password_method" varchar(20) not null,
|
||
"password_salt" varchar(20) not null,
|
||
"email" varchar(256) not null,
|
||
"status" integer DEFAULT 0 NOT NULL,
|
||
constraint "pk_auth_into_id" primary key("id"),
|
||
constraint "ux_auth_info_email" unique ("email")
|
||
);
|
||
create trigger "update_auth_info_updated"
|
||
before update on "auth_info" for each row execute procedure last_update_column();
|
||
comment on table "auth_info"
|
||
is '';
|
||
comment on column "auth_info"."id"
|
||
is '';
|
||
comment on column "auth_info"."group"
|
||
is 'default user group';
|
||
comment on column "auth_info"."created"
|
||
is 'time of created';
|
||
comment on column "auth_info"."config"
|
||
is 'user configuration';
|
||
|
||
|
||
create table "auth_identity" (
|
||
"id" serial not null,
|
||
"auth_info_id" bigint,
|
||
"provider" varchar(64) not null,
|
||
"identity" varchar(512) not null,
|
||
constraint "pk_auth_identity_id" primary key("id"),
|
||
constraint "fk_auth_identity_auth_info_id" foreign key ("auth_info_id") references "auth_info" ("id") on delete cascade deferrable initially immediate
|
||
);
|
||
comment on table "auth_identity"
|
||
is '';
|
||
comment on column "auth_identity"."id"
|
||
is '';
|
||
comment on column "auth_identity"."auth_info_id"
|
||
is '';
|
||
comment on column "auth_identity"."provider"
|
||
is '';
|
||
comment on column "auth_identity"."identity"
|
||
is '';
|
||
|
||
create table "auth_token" (
|
||
"id" serial not null,
|
||
"auth_info_id" bigint,
|
||
"value" varchar(64) not null,
|
||
"expires" timestamp not null,
|
||
"role" smallint not null,
|
||
constraint "pk_auth_token_id" primary key("id"),
|
||
constraint "fk_auth_token_auth_info_id" foreign key ("auth_info_id") references "auth_info" ("id") on delete cascade deferrable initially immediate
|
||
);
|
||
create index "ix_auth_token_value"
|
||
on "auth_token"("value");
|
||
comment on table "auth_token"
|
||
is '';
|
||
comment on column "auth_token"."id"
|
||
is '';
|
||
comment on column "auth_token"."auth_info_id"
|
||
is '';
|
||
comment on column "auth_token"."value"
|
||
is '';
|
||
comment on column "auth_token"."expires"
|
||
is '';
|
||
|
||
|
||
create UNLOGGED table "user_audit" (
|
||
"id" serial not null,
|
||
"auth_info_id" int not null,
|
||
"action" text not null,
|
||
"data" jsonb,
|
||
"when_happened" timestamp DEFAULT(now()),
|
||
constraint "pk_user_history_id" primary key ("id"),
|
||
constraint "fk_user_history_auth_info_id" foreign key ("auth_info_id") references "auth_info"("id") on delete cascade deferrable initially immediate
|
||
);
|
||
comment on table "user_audit" IS 'saves user actions like login/logout';
|
||
comment on column "user_audit"."id"
|
||
is '';
|
||
comment on column "user_audit"."auth_info_id"
|
||
is '';
|
||
comment on column "user_audit"."action"
|
||
is '';
|
||
comment on column "user_audit"."data"
|
||
is 'data column contains information about taken action (if login was successful? if not, from what ip this action was taken?)';
|
||
comment on column "user_audit"."when_happened"
|
||
is '';
|
||
|
||
|
||
--create table "user_groups"(
|
||
-- "uid" integer not null,
|
||
-- "gid" integer not null
|
||
--);
|
||
--comment on table "user_groups" is '';
|
||
--comment on column "user_groups"."uid" is '';
|
||
--comment on column "user_groups"."gid" is '';
|
||
|
||
create table "stat"(
|
||
"id" serial not null,
|
||
"owner" int not null default app_current_user_id(),
|
||
"group" int not null default default_group_id(),
|
||
"unixperms" int not null default unix_to_numeric('764'),
|
||
"status" int not null default 0,
|
||
"name" text not null,
|
||
"created" timestamp DEFAULT now() not null,
|
||
"updated" timestamp,
|
||
constraint "pk_stat" primary key ("id"),
|
||
constraint "fk_stat_user" foreign key ("owner") references "auth_info" ("id") on delete cascade deferrable initially immediate,
|
||
constraint "fk_stat_primary_group" foreign key ("group") references "group" ("gid") on delete cascade deferrable initially immediate
|
||
);
|
||
create trigger update_stat_last_update before update on stat for each row execute procedure last_update_column();
|
||
comment on table "stat"
|
||
is '';
|
||
comment on column "stat"."id"
|
||
is 'unique id for all objects in database';
|
||
comment on column "stat"."owner"
|
||
is 'uid of object''s owner';
|
||
comment on column "stat"."group"
|
||
is 'groups of object';
|
||
comment on column "stat"."unixperms"
|
||
is 'Unixpermissions';
|
||
comment on column "stat"."status"
|
||
is 'status in which object is in (login, logout, removed etc)';
|
||
comment on column "stat"."name"
|
||
is '';
|
||
comment on column "stat"."created"
|
||
is '';
|
||
comment on column "stat"."updated"
|
||
is '';
|
||
|
||
--create table "action"(
|
||
-- "title" text not null check( length(title) >= 3 AND length(title) < 100 ),
|
||
-- "apply_object" boolean not null,
|
||
-- constraint "pk_action" primary key ("title", "apply_object")
|
||
--);
|
||
--comment on table "action" is '';
|
||
--comment on column "action"."title" is 'column contains name of action';
|
||
--comment on column "action"."apply_object" is 'column specifies whether an action applies to objects or tables. Certain actions, like “create,” apply only to tables. I find the system is easier to manage if I choose my actions so they can only apply to one or the other, not both.';
|
||
|
||
|
||
--create table "implemented_action"(
|
||
-- "table_name" text not null,
|
||
-- "action" text not null,
|
||
-- "status" int not null,
|
||
-- constraint "pk_implemented_action" primary key ("table_name", "action", "status")
|
||
--);
|
||
--comment on table "implemented_action" is '';
|
||
--comment on column "implemented_action"."table_name" is '';
|
||
--comment on column "implemented_action"."action" is '';
|
||
--comment on column "implemented_action"."status" is '';
|
||
|
||
|
||
--create table "privilege" (
|
||
-- "role" varchar(30) not null, -- TODO change to enum
|
||
-- "who" int not null default 0,
|
||
-- "action" text not null,
|
||
-- "type" varchar(30) not null, -- TODO change to enum
|
||
-- "related_table_name" varchar(100) not null,
|
||
-- "related_object_uid" int not null default 0,
|
||
-- constraint "pk_privilege" primary key("role", "who", "action", "type", "related_table_name", "related_object_uid")
|
||
--);
|
||
--create index "ix_privilege_action_type" on "privilege" ( "action", "type") with ( FILLFACTOR=100 );
|
||
--create index "ix_privilege_related_table" on "privilege" ( "related_table_name" ) with ( FILLFACTOR=100 );
|
||
--create index "ix_privilege_action" on "privilege" ( "action" ) with ( FILLFACTOR=100 );
|
||
--create index "ix_privilege_type" on "privilege" ( "type" ) with ( FILLFACTOR=100 );
|
||
--comment on table "privilege" is '';
|
||
--comment on column "privilege"."role" is 'specifies whether the privilege is granted to a user, a group, or in the case of an “object” privilege, the object’s owner or owner_group. A further special case, in my system, is “self.”';
|
||
--comment on column "privilege"."who" is 'is needed if role is user or group, and holds the user or group ID to which the privilege is granted.';
|
||
--comment on column "privilege"."action" is 'is the action the privilege grants. This is always required.';
|
||
--comment on column "privilege"."type" is 'specifies whether the privilege is “object”, “table”, or “global.”';
|
||
--comment on column "privilege"."related_table_name" is 'holds the name of the table to which the privilege applies. This is always required, though in the case of a “self” privilege it’s redundant because a “self” privilege always applies to the t_user table.';
|
||
--comment on column "privilege"."related_object_uid" is 'stores the ID of the object to which the privilege applies, if it’s an object privilege. This has no meaning for table and global privileges, of course. The one applies to a table, not an object, and the second applies to all rows in a table, so an ID is immaterial. This is also not used for self privileges, because by definition a self privilege has to apply to the user requesting permission to do something.';
|
||
|
||
|
||
create table "file"(
|
||
"size" int,
|
||
"checksum" text,
|
||
"mimetype" text,
|
||
constraint "ix_file_id" primary key ("id"),
|
||
constraint "fk_category_stat_owner" foreign key ("owner") references "auth_info"("id") deferrable initially immediate
|
||
) inherits (stat);
|
||
create unique index "ux_file_data" on "file"("size", "checksum" );
|
||
comment on table "file"
|
||
is '';
|
||
comment on column "file"."size"
|
||
is 'size of file in bytes';
|
||
comment on column "file"."checksum"
|
||
is 'MD5 checksum of file';
|
||
comment on column "file"."mimetype"
|
||
is 'mime type of hold object';
|
||
|
||
---------------------------------------------
|
||
--- CATEGORIES
|
||
---------------------------------------------
|
||
|
||
create or replace function update_category_parent_path() returns trigger as $$
|
||
DECLARE
|
||
path ltree;
|
||
BEGIN
|
||
IF NEW.parent_id IS NULL THEN
|
||
NEW.parent_path = 'root'::ltree;
|
||
ELSEIF TG_OP = 'INSERT' OR OLD.parent_id IS NULL OR OLD.parent_id != NEW.parent_id THEN --
|
||
SELECT parent_path || "id"::text FROM "category" WHERE "id" = NEW.parent_id INTO path;
|
||
IF path IS NULL THEN
|
||
RAISE exception 'Invalid parent_uid %', NEW.parent_id;
|
||
END IF;
|
||
NEW.parent_path = path;
|
||
END IF;
|
||
RETURN NEW;
|
||
END;
|
||
$$ LANGUAGE plpgsql;
|
||
|
||
-- TODO thumbnail should be a link to file table
|
||
create table "category"(
|
||
"parent_id" int,
|
||
"parent_path" ltree,
|
||
"description" text check(length(description) < 100000),
|
||
"thumbnail" text,
|
||
constraint "pk_category_uid" primary key ("id"),
|
||
constraint "fk_category_parent_id" foreign key ("parent_id") references "category"("id") on delete cascade deferrable initially immediate,
|
||
constraint "fk_category_stat_owner" foreign key ("owner") references "auth_info"("id") deferrable initially immediate
|
||
) inherits (stat);
|
||
create index "ix_category_parent_path" on "category" using GIST ("parent_path");
|
||
create unique index "ux_category_name" on "category"("parent_id", "name" ) where ("parent_id" is not null);
|
||
create trigger "update_category_last_update" before update on "category" for each row execute procedure last_update_column();
|
||
create trigger "update_category_parent_path" before insert or update on "category" for each row execute procedure update_category_parent_path();
|
||
comment on table "category"
|
||
is 'categories of items';
|
||
comment on column "category"."parent_id"
|
||
is '';
|
||
comment on column "category"."parent_path"
|
||
is '';
|
||
comment on column "category"."description"
|
||
is '';
|
||
comment on column "category"."thumbnail"
|
||
is '';
|
||
|
||
|
||
create table "unit"(
|
||
"symbol" text not null,
|
||
"description" text,
|
||
"dimension_symbol" text,
|
||
-- "type" text
|
||
constraint "pk_unit" primary key ("id")
|
||
) inherits(stat);
|
||
create unique index "uk_unit_name" on "unit"("name", "symbol");
|
||
create trigger update_unit_last_update before update on "unit" for each row execute procedure last_update_column();
|
||
comment on table "unit"
|
||
is 'categories of items';
|
||
comment on column "unit"."symbol"
|
||
is '';
|
||
comment on column "unit"."description"
|
||
is '';
|
||
comment on column "unit"."dimension_symbol"
|
||
is '';
|
||
|
||
|
||
create table "parameter"(
|
||
"unit_id" int,
|
||
"type" text,
|
||
"description" text,
|
||
constraint "pk_parameter" primary key ("id"),
|
||
constraint "fk_parameter_unit" foreign key ("unit_id") references "unit"("id") on delete cascade deferrable initially immediate
|
||
) inherits(stat);
|
||
create unique index "uk_parameter_name" on "parameter"("name");
|
||
create trigger update_parameter_last_update before update on "parameter" for each row execute procedure last_update_column();
|
||
comment on table "parameter"
|
||
is 'Parameter data';
|
||
comment on column "parameter"."name"
|
||
is 'name of parameter e.g. Max power';
|
||
comment on column "parameter"."unit_id"
|
||
is 'id of assigned unit (for range types, unit/list types indicated type of single value)';
|
||
comment on column "parameter"."type"
|
||
is 'Type ot the parameter numeric/text or some variations e.g. list->"numeric[]", range->"numeric..."';
|
||
comment on column "parameter"."description"
|
||
is '';
|
||
|
||
|
||
-- TODO create fulltext search on short_desc column
|
||
-- TODO create "producer" table to save producers there insted in items table
|
||
create table "item"(
|
||
"producer_symbol" text,
|
||
"producer" text,
|
||
"attributes" jsonb not null DEFAULT('{}'),
|
||
"short_desc" text,
|
||
"description" text,
|
||
constraint "pk_items" primary key ("id"),
|
||
constraint "fk_item_auth_info" foreign key ("owner") references "auth_info"("id") deferrable initially immediate
|
||
) inherits ("stat");
|
||
create index "ix_item_attributes" on "item" USING GIN ("attributes");
|
||
create index "ix_item_producer" on "item"("producer");
|
||
create index "ix_item_producer_symbol" on "item"("producer_symbol");
|
||
create unique index "ux_item_symbol" on "item"("name");
|
||
create trigger update_item_last_update before update on item for each row execute procedure last_update_column();
|
||
comment on table "item"
|
||
is '';
|
||
comment on column "item"."name"
|
||
is 'Item symbol saved in database';
|
||
comment on column "item"."producer_symbol"
|
||
is 'symbol of the producent';
|
||
comment on column "item"."producer"
|
||
is 'producent';
|
||
comment on column "item"."attributes"
|
||
is 'JSON list of values';
|
||
comment on column "item"."short_desc"
|
||
is '';
|
||
comment on column "item"."description"
|
||
is '';
|
||
|
||
|
||
create table "category_items"(
|
||
"category_id" integer not null,
|
||
"item_id" integer not null,
|
||
constraint "pk_category_items" primary key ("category_id", "item_id"),
|
||
constraint "fk_category_id" foreign key ("category_id") references "category"("id") on delete cascade deferrable initially immediate,
|
||
constraint "fk_item_id" foreign key ("item_id") references "item"("id") on delete cascade deferrable initially immediate
|
||
);
|
||
comment on table "category_items"
|
||
is '';
|
||
|
||
|
||
--create table "inventory"(
|
||
-- "description" TEXT check(length(description)< 100000),
|
||
-- constraint "pk_inventory" primary key ("id"),
|
||
-- constraint "fk_inventory_owner" foreign key ("owner") references "auth_info" ("id") deferrable initially immediate,
|
||
-- constraint "chk_inventory_name_length" check (length(name) < 100)
|
||
--) inherits (stat);
|
||
--create trigger update_inventory_last_update before update on inventory for each row execute procedure last_update_column();
|
||
|
||
|
||
--create table "user_inventory"(
|
||
-- "auth_info_id" INTEGER not null references "auth_info" on DELETE CASCADE,
|
||
-- "inventory_id" INTEGER not null references "inventory" on DELETE CASCADE,
|
||
-- constraint user_inventory_pk primary key ("inventory_id", "auth_info_id")
|
||
--);
|
||
|
||
|
||
--create table in_stock(
|
||
-- item_id INTEGER not null references items,
|
||
-- inventory_id INTEGER not null references inventory,
|
||
-- amount numeric(10,10) not null DEFAULT 0
|
||
--);
|
||
--comment on table in_stock IS 'Table contains information about items being available in storage';
|
||
|
||
|
||
--create table inventory_operations(
|
||
-- constraint inventory_operations_pkey primary key (uid),
|
||
-- constraint OperationOwner_fk foreign key (owner) references users (uid) deferrable initially IMMEDIATE,
|
||
-- constraint inventory_operation_unique UNIQUE (name)
|
||
--) inherits(stat);
|
||
|
||
|
||
--create table inventory_history(
|
||
-- inventory_from_id INTEGER not null references inventory on DELETE CASCADE,
|
||
-- inventory_to_id INTEGER not null references inventory on DELETE CASCADE,
|
||
-- operation_id INTEGER not null references inventory_Operations on DELETE CASCADE ,
|
||
-- amount NUMERIC(10,10),
|
||
|
||
-- date timestamp not null default now()
|
||
--);
|