123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293 |
- --
- -- Name: luticate_settings; Type: TABLE; Schema: public; Owner: dev; Tablespace:
- --
-
- CREATE TABLE luticate_settings (
- name character varying(128) NOT NULL,
- type character varying(128) NOT NULL,
- value text NOT NULL,
- is_blocked boolean NOT NULL,
- is_admin boolean NOT NULL
- );
-
-
- --
- -- Name: luticate_settings_users; Type: TABLE; Schema: public; Owner: dev; Tablespace:
- --
-
- CREATE TABLE luticate_settings_users (
- name character varying(128) NOT NULL,
- value text NOT NULL,
- user_id integer NOT NULL,
- is_blocked boolean NOT NULL
- );
-
- --
- -- Name: luticate_settings_pkey; Type: CONSTRAINT; Schema: public; Owner: dev; Tablespace:
- --
-
- ALTER TABLE ONLY luticate_settings
- ADD CONSTRAINT luticate_settings_pkey PRIMARY KEY (name);
-
-
- --
- -- Name: luticate_settings_users_pkey; Type: CONSTRAINT; Schema: public; Owner: dev; Tablespace:
- --
-
- ALTER TABLE ONLY luticate_settings_users
- ADD CONSTRAINT luticate_settings_users_pkey PRIMARY KEY (name, user_id);
-
- --
- -- Name: luticate_settings_users_name_fkey; Type: FK CONSTRAINT; Schema: public; Owner: dev
- --
-
- ALTER TABLE ONLY luticate_settings_users
- ADD CONSTRAINT luticate_settings_users_name_fkey FOREIGN KEY (name) REFERENCES luticate_settings(name) ON DELETE CASCADE;
-
-
- --
- -- Name: luticate_settings_users_user_id_fkey; Type: FK CONSTRAINT; Schema: public; Owner: dev
- --
-
- ALTER TABLE ONLY luticate_settings_users
- ADD CONSTRAINT luticate_settings_users_user_id_fkey FOREIGN KEY (user_id) REFERENCES luticate_users(id) ON DELETE CASCADE;
-
- --
- -- Name: sp_lu_get_user_setting(integer, character varying); Type: FUNCTION; Schema: public; Owner: dev
- --
-
- CREATE FUNCTION sp_lu_get_user_setting(_user_id integer, _setting_name character varying, OUT setting json) RETURNS json
- LANGUAGE plpgsql IMMUTABLE SECURITY DEFINER COST 10
- AS $$
- DECLARE
- _setting luticate_settings;
- _setting_user luticate_settings_users;
- BEGIN
- SELECT * INTO _setting FROM luticate_settings WHERE "name" = _setting_name AND NOT "is_admin";
- IF _setting IS NULL THEN
- setting := NULL;
- ELSE
- IF NOT _setting.is_blocked THEN
- SELECT * INTO _setting_user FROM luticate_settings_users WHERE "user_id" = _user_id AND "name" = _setting_name;
- IF _setting_user IS NOT NULL THEN
- _setting.value := _setting_user.value;
- END IF;
- END IF;
- setting := to_json(_setting);
- END IF;
- END;
- $$;
-
-
- --
- -- Name: sp_lu_get_all_user_settings(integer); Type: FUNCTION; Schema: public; Owner: dev
- --
-
- CREATE FUNCTION sp_lu_get_all_user_settings(_user_id integer, OUT _settings json) RETURNS SETOF json
- LANGUAGE sql IMMUTABLE SECURITY DEFINER COST 10
- AS $$
- SELECT sp_lu_get_user_setting(_user_id, s.name)
- FROM luticate_settings s
- WHERE NOT s.is_admin
- ORDER BY s.name
- $$;
|