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; create OR REPLACE function last_update_column() RETURNS trigger AS $$ BEGIN NEW.last_update = now(); RETURN NEW; END; $$ language 'plpgsql'; CREATE or replace FUNCTION change_trigger() RETURNS trigger AS $$ BEGIN IF TG_OP = 'INSERT' THEN INSERT INTO logging.t_history (tabname, schemaname, operation, new_val) VALUES (TG_RELNAME, TG_TABLE_SCHEMA, TG_OP, row_to_json(NEW)); RETURN NEW; ELSIF TG_OP = 'UPDATE' THEN INSERT INTO logging.t_history (tabname, schemaname, operation, new_val, old_val) VALUES (TG_RELNAME, TG_TABLE_SCHEMA, TG_OP, row_to_json(NEW), row_to_json(OLD)); RETURN NEW; ELSIF TG_OP = 'DELETE' THEN INSERT INTO logging.t_history (tabname, schemaname, operation, old_val) VALUES (TG_RELNAME, TG_TABLE_SCHEMA, TG_OP, row_to_json(OLD)); RETURN OLD; END IF; END; $$ LANGUAGE 'plpgsql' SECURITY DEFINER; --create types DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'parameter_type') THEN create TYPE parameter_type AS ENUM ( 'stored','pointed'); END IF; -- IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'privilege_role') THEN -- create TYPE privilege_role AS ENUM -- (); -- END IF; -- IF NOT EXISTS (SELECT 1 FROM pg_type WHERE typname = 'privilege_type') THEN -- create TYPE privilege_type AS ENUM -- (); -- END IF; --more types here... END$$; drop table if exists "user" cascade; drop table if exists "auth_info" cascade; drop table if exists "auth_token" cascade; drop table if exists "user_action" cascade; drop table if exists "user_history" cascade; drop table if exists stat cascade; drop table if exists action cascade; drop table if exists metric_systems cascade; drop table if exists measurands cascade; drop table if exists privilege cascade; drop table if exists pointed_values cascade; drop table if exists "auth_identity" cascade; drop table if exists category_files; drop table if exists units_conversions; drop table if exists in_stock; drop table if exists implemented_action; drop table if exists inventory_history; drop table if exists user_history; drop table if exists item_files; drop table if exists packages_files; drop table if exists system_info; drop table if exists user_inventory; create table "system_info"( "id" serial not null, "name" text, "value" jsonb, "creation_time" 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 "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 "stat"( "uid" serial not null, "owner" int not null default 1, "group" int not null default 2, -- 1 is a root usergroup, 2 is 'users' set as default "unixperms" int not null default unix_to_numeric('764'), "status" int not null default 0, "name" text NOT NULL check( length(name) < 4096 ), "creation_date" timestamp DEFAULT now() NOT NULL, "last_update" timestamp, constraint "pk_stat" primary key ("uid") ); 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"."uid" is 'unique uid 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)'; 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") ); 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 in future 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 "user" ( "address" text, "config" json DEFAULT ('{}'), "avatar" text, "email" varchar(256) not null, "status" integer not null, constraint "pk_user_uid" primary key ("uid"), constraint "ux_user_name" unique ("name"), constraint "ux_user_email" unique ("email") ) INHERITS (stat); create trigger update_user_last_update before update on "user" FOR EACH ROW EXECUTE PROCEDURE last_update_column(); create table "user_action" ( "id" serial not null, "name" text, constraint "pk_user_action" primary key ("id"), constraint "ux_user_action_name" unique ("name" ) ); comment on table "user_action" is 'action that user can take (like login/logout/config change?)'; comment on column "user_action"."name" is 'action name'; create table "user_history" ( "id" serial not null, "user_id" int not null, "action_id" int not null, "data" jsonb, "when" timestamp DEFAULT(now()), constraint "pk_user_history_id" primary key ("id"), constraint "fk_user_history_user_uid" foreign key ("user_id") references "user"("uid") on delete cascade deferrable initially deferred, constraint "fk_user_history_user_action" foreign key ("action_id") references "user_action"("id") on delete cascade deferrable initially deferred ); create index "ix_user_history_data" ON "user_history" ((("data" ->> 'status')::text)) WHERE ("data" ->> 'status') IS NOT NULL; comment on table "user_history" IS 'saves user actions like login/logout'; comment on column "user_history"."data" is 'data column contains information about taken action (if login was successful? if not, from what ip this action was taken?)'; /* get last login select t.id from user_history t where t.action_id = 1 and t.user_id = 2 and t.data->>'status' = 'success' order by t.id desc limit 1 get faild attempts select count(*) from user_history t inner join user_action on t.action_id = user_action.id where t.user_id = 2 and user_action.name = 'login' and t.data->>'status'= 'failed' and t.id > (select t.id from user_history t where t.action_id = 1 and t.user_id = 2 and t.data->>'status' = 'success' order by t.id desc limit 1) */ create table "auth_info" ( "id" serial not null, "user_uid" bigint, "password_hash" varchar(100) not null, "password_method" varchar(20) not null, "password_salt" varchar(20) not null, "unverified_email" varchar(256) not null, "email_token" varchar(64) not null, "email_token_expires" timestamp, "email_token_role" integer not null, constraint "pk_auth_into_id" primary key("id"), constraint "fk_auth_info_user_uid" foreign key ("user_uid") references "user" ("uid") on delete cascade deferrable initially deferred ); 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" foreign key ("auth_info_id") references "auth_info" ("id") on delete cascade deferrable initially deferred ); create table "auth_token" ( "id" serial not null, "version" integer not null, "auth_info_id" bigint, "value" varchar(64) not null, "expires" timestamp, 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 deferred ); 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 || uid::text FROM categories WHERE uid = 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; create table "category"( "parent_id" int, "description" text check(length(description) < 100000 ), "parent_path" ltree, constraint "pk_category_uid" primary key ("uid"), constraint "fk_category_parent_id" foreign key ("parent_id") references "category"("uid") on delete cascade deferrable initially deferred, constraint "fk_category_stat_owner" foreign key ("owner") references "user"("uid") 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" ); create unique index "ux_category_parent" on "category" ( "parent_id", "uid" ); 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"."description" is ''; comment on column "category"."parent_path" is ''; /* create table "measurands"( "id" serial not null unique primary key, "name" text not null unique, "description" text, "dimension_symbol" text ); create table "metric_systems"( "id" serial not null primary key, "name" VARCHAR(32) not null unique, "description" text ); comment on table measurands IS 'Information about measured quantity length, time etc.'; create table units( symbol VARCHAR (20) NOT NULL, description TEXT check(length(description) < 100000), measurand_id int REFERENCES measurands(id), base_unit int REFERENCES units(uid), metric_system int REFERENCES metric_systems(id), constraint units_pkey primary key (uid), constraint unitowner_fk foreign key (owner) REFERENCES users (uid) deferrable initially IMMEDIATE, constraint units_unique UNIQUE(name, symbol) ) inherits(stat); comment on table units IS 'Table holds information about units used in application'; comment on column units.name IS 'Parameter name e.g. Ampere'; comment on column units.symbol IS 'Parameter symbol e.g. A'; comment on column units.description IS 'Simple description'; create table units_conversions( from_unit INTEGER NOT NULL REFERENCES units(uid), to_unit INTEGER NOT NULL REFERENCES units(uid), equation TEXT NOT NULL, constraint unit_conversions_unique primary key (from_unit, to_unit) ); comment on table units_conversions IS 'This table contains a mathematical equation for converting one unitl to other, more info available at http://www.partow.net/programming/exprtk/index.html'; comment on column units_conversions.equation IS 'this equation should be a proper exprtk equation'; create table pointed_values( id serial primary key, data jsonb default('{}') ); create INDEX items_pointed_values_idx on pointed_values USING GIN (data); create table parameters ( symbol VARCHAR(20), unit INTEGER REFERENCES units(uid), description TEXT check(length(description) < 100000), ptype parameter_type default('stored'), constraint parameters_pkey primary key (uid), constraint parametereowner_fk foreign key (owner) REFERENCES users (uid) deferrable initially IMMEDIATE, constraint parameters_unique UNIQUE(name, symbol) ) INHERITS (stat); comment on column parameters.name IS 'Parameter name e.g. "Load current max." '; comment on column parameters.symbol IS 'Parameter symbol e.g. "IR'; comment on column parameters.unit IS 'Parameter unit e.g. id od Amper unit from unit table'; comment on column parameters.ptype IS '''stored'' parameter is a parameter which value is stored directly in items table, ''pointed'' means that the value of parameter is an ID of value stored in parameter_values table'; */ create table "item"( "category_id" int NOT NULL, "symbol" text NOT NULL, "original_symbol" text, "producer" text, -- name_scope VARCHAR(64) DEFAULT 'std' NOT NULL, "attributes" jsonb NOT NULL DEFAULT('{}'), description TEXT, constraint "pk_items" primary key ("uid"), constraint "fk_item_category" foreign key ("category_id") references "category"("uid") on delete cascade deferrable initially deferred, constraint "fk_item_user" foreign key ("owner") REFERENCES "user"("uid") deferrable initially IMMEDIATE ) INHERITS (stat); create index "ix_item_attributes" on "item" USING GIN ("attributes"); create unique index "ux_item" on "item"("name", "symbol"); create trigger update_item_last_update before update on item FOR EACH ROW EXECUTE PROCEDURE last_update_column(); create table "inventory"( "description" TEXT check(length(description)< 100000), constraint "pk_inventory" primary key ("uid"), constraint "fk_inventory_owner" foreign key ("owner") REFERENCES "user" ("uid") 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"( "user_id" INTEGER NOT NULL REFERENCES "user" on DELETE CASCADE, "inventory_id" INTEGER NOT NULL REFERENCES "inventory" on DELETE CASCADE, constraint user_inventory_pk primary key ("inventory_id", "user_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() ); */ -- create INDEX users_stat_index on users (uid, owner, group, unixperms, status) with ( FILLFACTOR=100 ); -- create INDEX categories_stat_index on categories (uid, owner, group, unixperms, status) with ( FILLFACTOR=100 ); -- create INDEX storages_stat_index on storages (uid, owner, group, unixperms, status) with ( FILLFACTOR=100 ); -- create INDEX files_stat_index on files (uid, owner, group, unixperms, status) with ( FILLFACTOR=100 ); -- create INDEX items_stat_index on items (uid, owner, group, unixperms, status) with ( FILLFACTOR=100 ); -- create trigger update_parameters_last_update before update on parameters FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_files_last_update before update on files FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_packages_last_update before update on packages FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_units_last_update before update on units FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_items_last_update before update on items FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_shelfs_last_update before update on shelfs FOR EACH ROW EXECUTE PROCEDURE last_update_column(); -- create trigger update_inventory_operations_lats_update before update on inventory_operations FOR EACH ROW EXECUTE PROCEDURE last_update_column(); create OR REPLACE function objects_with_action (m_tab VARCHAR, m_action varchar, userid int) RETURNS setof int AS $$ DECLARE r int; DECLARE usergroups INT; DECLARE groupsroot INT; DECLARE tablename VARCHAR(255); BEGIN SELECT "group" FROM "user" WHERE uid = userid INTO usergroups; groupsroot := 1; FOR r IN execute 'select distinct obj.uid from ' || m_tab ||' as obj inner join implemented_action as ia on ia.table_name ='''|| m_tab || ''' and ia.action = '''|| m_action ||''' and ((ia.status = 0) or (ia.status & obj.status <> 0)) inner join action as ac on ac.title = '''|| m_action ||''' left outer join privilege as pr on pr.related_table_name = '''|| m_tab || ''' and pr.action = '''|| m_action ||''' and ( (pr.type = ''object'' and pr.related_object_uid = obj.uid) or pr.type = ''global'' or (pr.role = ''self'' and ' || userid || ' = obj.uid and '''|| m_tab || ''' = ''users'')) WHERE ac.apply_object AND ( (' || usergroups || ' & ' || groupsroot || ' <> 0) OR ( ac.title = ''read'' AND ( (obj.unixperms & 4 <> 0) OR ( (obj.unixperms & 256 <> 0) AND obj.owner = ' || userid || ' ) OR ( (obj.unixperms & 32 <> 0) AND (' || usergroups || ' & obj.group <> 0) ) ) ) OR ( ac.title = ''write'' AND ( (obj.unixperms & 2 <> 0) OR ( (obj.unixperms & 128 <> 0) AND obj.owner = ' || userid || ' ) OR ( (obj.unixperms & 16 <> 0) AND (' || usergroups || ' & obj.group <> 0) ) ) ) OR ( ac.title = ''delete'' AND ( (obj.unixperms & 1 <> 0) OR ((obj.unixperms & 64 <> 0) AND obj.owner = ' || userid || ') OR ((obj.unixperms & 8 <> 0) AND (' || usergroups || ' & obj.group <> 0)) ) ) OR ( pr.role = ''user'' AND pr.who = ' || userid || ' ) OR ( pr.role = ''owner'' AND obj.owner = ' || userid || ' ) OR ( pr.role = ''owner_group'' AND (obj.group & ' || usergroups || ' <> 0) ) OR ( pr.role = ''group'' AND (pr.who & ' || usergroups || ' <> 0) ) ) OR pr.role = ''self'' ' LOOP RETURN NEXT r; end loop; END $$ LANGUAGE plpgsql ; -- insert needed data into dataase DO $$ DECLARE lastid int; BEGIN END $$;