tracim-init-database.new.sql.deprecated 11KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274
  1. SET statement_timeout = 0;
  2. SET client_encoding = 'UTF8';
  3. SET standard_conforming_strings = on;
  4. SET check_function_bodies = false;
  5. SET client_min_messages = warning;
  6. CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
  7. COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
  8. SET search_path = public, pg_catalog;
  9. CREATE FUNCTION update_node() RETURNS trigger
  10. LANGUAGE plpgsql
  11. AS $$
  12. BEGIN
  13. INSERT INTO content_revisions (content_id, parent_id, type, created, updated,
  14. label, description, status,
  15. file_name, file_content, file_mimetype, parent_tree_path,
  16. owner_id, revision_id, workspace_id, is_deleted, is_archived, properties, revision_type) VALUES (NEW.content_id, NEW.parent_id, NEW.type, NEW.created, NEW.updated, NEW.label, NEW.description, NEW.status, NEW.file_name, NEW.file_content, NEW.file_mimetype, NEW.parent_tree_path, NEW.owner_id, nextval('seq__content_revisions__revision_id'), NEW.workspace_id, NEW.is_deleted, NEW.is_archived, NEW.properties, NEW.revision_type);
  17. return new;
  18. END;
  19. $$;
  20. CREATE FUNCTION set_created() RETURNS trigger
  21. LANGUAGE plpgsql
  22. AS $$
  23. BEGIN
  24. NEW.created = CURRENT_TIMESTAMP;
  25. NEW.updated = CURRENT_TIMESTAMP;
  26. RETURN NEW;
  27. END;
  28. $$;
  29. CREATE FUNCTION set_updated() RETURNS trigger
  30. LANGUAGE plpgsql
  31. AS $$
  32. BEGIN
  33. NEW.updated = CURRENT_TIMESTAMP;
  34. RETURN NEW;
  35. END;
  36. $$;
  37. SET default_tablespace = '';
  38. SET default_with_oids = false;
  39. CREATE TABLE migrate_version (
  40. version_num character varying(32) NOT NULL
  41. );
  42. CREATE TABLE groups (
  43. group_id integer NOT NULL,
  44. group_name character varying(16) NOT NULL,
  45. display_name character varying(255),
  46. created timestamp without time zone
  47. );
  48. CREATE SEQUENCE seq__groups__group_id
  49. START WITH 1
  50. INCREMENT BY 1
  51. NO MINVALUE
  52. NO MAXVALUE
  53. CACHE 1;
  54. ALTER SEQUENCE seq__groups__group_id OWNED BY groups.group_id;
  55. CREATE TABLE group_permission (
  56. group_id integer NOT NULL,
  57. permission_id integer NOT NULL
  58. );
  59. CREATE SEQUENCE seq__content_revisions__revision_id
  60. START WITH 1
  61. INCREMENT BY 1
  62. NO MINVALUE
  63. NO MAXVALUE
  64. CACHE 1;
  65. CREATE TABLE content_revisions (
  66. content_id integer NOT NULL,
  67. parent_id integer,
  68. type character varying(16) DEFAULT 'data'::character varying NOT NULL,
  69. created timestamp without time zone,
  70. updated timestamp without time zone,
  71. label character varying(1024),
  72. description text DEFAULT ''::text NOT NULL,
  73. status character varying(32) DEFAULT 'new'::character varying,
  74. file_name character varying(255),
  75. file_content bytea,
  76. file_mimetype character varying(255),
  77. parent_tree_path character varying(255),
  78. owner_id integer,
  79. revision_id integer DEFAULT nextval('seq__content_revisions__revision_id'::regclass) NOT NULL,
  80. workspace_id integer,
  81. is_deleted boolean DEFAULT false NOT NULL,
  82. is_archived boolean DEFAULT false NOT NULL,
  83. properties text,
  84. revision_type character varying(32)
  85. );
  86. COMMENT ON COLUMN content_revisions.properties IS 'This column contain properties specific to a given type. these properties are json encoded (so there is no structure "a priori")';
  87. CREATE VIEW contents AS
  88. SELECT DISTINCT ON (content_revisions.content_id) content_revisions.content_id, content_revisions.parent_id, content_revisions.type, content_revisions.created, content_revisions.updated, content_revisions.label, content_revisions.description, content_revisions.status, content_revisions.file_name, content_revisions.file_content, content_revisions.file_mimetype, content_revisions.parent_tree_path, content_revisions.owner_id, content_revisions.workspace_id, content_revisions.is_deleted, content_revisions.is_archived, content_revisions.properties, content_revisions.revision_type FROM content_revisions ORDER BY content_revisions.content_id, content_revisions.updated DESC, content_revisions.created DESC;
  89. CREATE SEQUENCE seq__contents__content_id
  90. START WITH 1
  91. INCREMENT BY 1
  92. NO MINVALUE
  93. NO MAXVALUE
  94. CACHE 1;
  95. ALTER SEQUENCE seq__contents__content_id OWNED BY content_revisions.content_id;
  96. CREATE TABLE permissions (
  97. permission_id integer NOT NULL,
  98. permission_name character varying(63) NOT NULL,
  99. description character varying(255)
  100. );
  101. CREATE SEQUENCE seq__permissions__permission_id
  102. START WITH 1
  103. INCREMENT BY 1
  104. NO MINVALUE
  105. NO MAXVALUE
  106. CACHE 1;
  107. ALTER SEQUENCE seq__permissions__permission_id OWNED BY permissions.permission_id;
  108. CREATE TABLE users (
  109. user_id integer NOT NULL,
  110. email character varying(255) NOT NULL,
  111. display_name character varying(255),
  112. password character varying(128),
  113. created timestamp without time zone,
  114. is_active boolean DEFAULT true NOT NULL
  115. );
  116. CREATE TABLE user_group (
  117. user_id integer NOT NULL,
  118. group_id integer NOT NULL
  119. );
  120. CREATE SEQUENCE seq__users__user_id
  121. START WITH 1
  122. INCREMENT BY 1
  123. NO MINVALUE
  124. NO MAXVALUE
  125. CACHE 1;
  126. ALTER SEQUENCE seq__users__user_id OWNED BY users.user_id;
  127. CREATE TABLE user_workspace (
  128. user_id integer NOT NULL,
  129. workspace_id integer NOT NULL,
  130. role integer,
  131. do_notify boolean DEFAULT FALSE NOT NULL
  132. );
  133. CREATE TABLE workspaces (
  134. workspace_id integer NOT NULL,
  135. label character varying(1024),
  136. description text,
  137. created timestamp without time zone,
  138. updated timestamp without time zone,
  139. is_deleted boolean DEFAULT false NOT NULL
  140. );
  141. CREATE SEQUENCE seq__workspaces__workspace_id
  142. START WITH 11
  143. INCREMENT BY 1
  144. NO MINVALUE
  145. NO MAXVALUE
  146. CACHE 1;
  147. ALTER TABLE ONLY groups ALTER COLUMN group_id SET DEFAULT nextval('seq__groups__group_id'::regclass);
  148. ALTER TABLE ONLY content_revisions ALTER COLUMN content_id SET DEFAULT nextval('seq__contents__content_id'::regclass);
  149. ALTER TABLE ONLY permissions ALTER COLUMN permission_id SET DEFAULT nextval('seq__permissions__permission_id'::regclass);
  150. ALTER TABLE ONLY users ALTER COLUMN user_id SET DEFAULT nextval('seq__users__user_id'::regclass);
  151. ALTER TABLE ONLY workspaces ALTER COLUMN workspace_id SET DEFAULT nextval('seq__workspaces__workspace_id'::regclass);
  152. -- COPY migrate_version (version_num) FROM stdin;
  153. INSERT INTO groups (group_id, group_name, display_name, created) VALUES
  154. (1, 'users', 'Users', '2014-10-08 14:55:43.329136'),
  155. (2, 'managers', 'Global Managers', '2014-10-08 14:55:43.329136'),
  156. (3, 'administrators', 'Administrators', '2014-10-08 14:55:43.329136');
  157. SELECT pg_catalog.setval('seq__groups__group_id', 4, true);
  158. SELECT pg_catalog.setval('seq__contents__content_id', 1, true);
  159. SELECT pg_catalog.setval('seq__content_revisions__revision_id', 2568, true);
  160. SELECT pg_catalog.setval('seq__permissions__permission_id', 1, true);
  161. INSERT INTO users(user_id, email, display_name, password, created, is_active)
  162. VALUES(1, 'demo.michel@tracim.org', 'Michel', '1533a541f0f24746a21b622a88ee8a43ce0197fb73300f633f8860abdbd22e6b8ebb1542dc4bae072729f84b4f0020c37abc60dd769dec7951e4ab80d10ce39e', '2014-10-23 15:28:56.268502', 't');
  163. INSERT INTO user_group(user_id, group_id) VALUES (1,1), (1, 2), (1,3);
  164. SELECT pg_catalog.setval('seq__users__user_id', 2, true);
  165. SELECT pg_catalog.setval('seq__workspaces__workspace_id', 1, true);
  166. ALTER TABLE ONLY user_workspace
  167. ADD CONSTRAINT pk__user_workspace__user_id__workspace_id PRIMARY KEY (user_id, workspace_id);
  168. ALTER TABLE ONLY workspaces
  169. ADD CONSTRAINT pk__workspace__workspace_id PRIMARY KEY (workspace_id);
  170. ALTER TABLE ONLY groups
  171. ADD CONSTRAINT uk__groups__group_name UNIQUE (group_name);
  172. ALTER TABLE ONLY group_permission
  173. ADD CONSTRAINT pk__group_permission__group_id__permission_id PRIMARY KEY (group_id, permission_id);
  174. ALTER TABLE ONLY groups
  175. ADD CONSTRAINT pk__groups__group_id PRIMARY KEY (group_id);
  176. ALTER TABLE ONLY content_revisions
  177. ADD CONSTRAINT pk__content_revisions__revision_id PRIMARY KEY (revision_id);
  178. ALTER TABLE ONLY permissions
  179. ADD CONSTRAINT uk__permissions__permission_name UNIQUE (permission_name);
  180. ALTER TABLE ONLY permissions
  181. ADD CONSTRAINT pk__permissions__permission_id PRIMARY KEY (permission_id);
  182. ALTER TABLE ONLY users
  183. ADD CONSTRAINT uk__users__email UNIQUE (email);
  184. ALTER TABLE ONLY user_group
  185. ADD CONSTRAINT pk__user_group__user_id__group_id PRIMARY KEY (user_id, group_id);
  186. ALTER TABLE ONLY users
  187. ADD CONSTRAINT pk__users__user_id PRIMARY KEY (user_id);
  188. CREATE INDEX idx__content_revisions__owner_id ON content_revisions USING btree (owner_id);
  189. CREATE INDEX idx__content_revisions__parent_id ON content_revisions USING btree (parent_id);
  190. CREATE INDEX idx__content_revisions__parent_tree_path ON content_revisions USING btree (parent_tree_path);
  191. CREATE RULE rul__insert__new_node AS ON INSERT TO contents DO INSTEAD INSERT INTO content_revisions (content_id, parent_id, type, created, updated, label, description, status, file_name, file_content, file_mimetype, parent_tree_path, owner_id, revision_id, workspace_id, is_deleted, is_archived, properties, revision_type) VALUES (nextval('seq__contents__content_id'::regclass), new.parent_id, new.type, new.created, new.updated, new.label, new.description, new.status, new.file_name, new.file_content, new.file_mimetype, new.parent_tree_path, new.owner_id, nextval('seq__content_revisions__revision_id'::regclass), new.workspace_id, new.is_deleted, new.is_archived, new.properties, new.revision_type) RETURNING content_revisions.content_id, content_revisions.parent_id, content_revisions.type, content_revisions.created, content_revisions.updated, content_revisions.label, content_revisions.description, content_revisions.status, content_revisions.file_name, content_revisions.file_content, content_revisions.file_mimetype, content_revisions.parent_tree_path, content_revisions.owner_id, content_revisions.workspace_id, content_revisions.is_deleted, content_revisions.is_archived, content_revisions.properties, content_revisions.revision_type;
  192. CREATE TRIGGER trg__contents__on_insert__set_created BEFORE INSERT ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_created();
  193. CREATE TRIGGER trg__contents__on_update__set_updated BEFORE UPDATE ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_updated();
  194. CREATE TRIGGER trg__contents__on_update INSTEAD OF UPDATE ON contents FOR EACH ROW EXECUTE PROCEDURE update_node();
  195. CREATE TRIGGER trg__workspaces__on_insert__set_created BEFORE INSERT ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_created();
  196. CREATE TRIGGER trg__workspaces__on_update__set_updated BEFORE UPDATE ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_updated();
  197. ALTER TABLE ONLY user_workspace
  198. ADD CONSTRAINT fk__user_workspace__user_id FOREIGN KEY (user_id) REFERENCES users(user_id) ON UPDATE CASCADE ON DELETE CASCADE;
  199. ALTER TABLE ONLY user_workspace
  200. ADD CONSTRAINT fk__user_workspace__workspace_id FOREIGN KEY (workspace_id) REFERENCES workspaces(workspace_id) ON UPDATE CASCADE ON DELETE CASCADE;
  201. ALTER TABLE ONLY group_permission
  202. ADD CONSTRAINT fk__group_permission__group_id FOREIGN KEY (group_id) REFERENCES groups(group_id) ON UPDATE CASCADE ON DELETE CASCADE;
  203. ALTER TABLE ONLY group_permission
  204. ADD CONSTRAINT fk__group_permission__permission_id FOREIGN KEY (permission_id) REFERENCES permissions(permission_id) ON UPDATE CASCADE ON DELETE CASCADE;
  205. ALTER TABLE ONLY content_revisions
  206. ADD CONSTRAINT fk__content_revisions__owner_id FOREIGN KEY (owner_id) REFERENCES users(user_id);
  207. ALTER TABLE ONLY user_group
  208. ADD CONSTRAINT fk__user_group__group_id FOREIGN KEY (group_id) REFERENCES groups(group_id) ON UPDATE CASCADE ON DELETE CASCADE;
  209. ALTER TABLE ONLY user_group
  210. ADD CONSTRAINT fk__user_group__user_id FOREIGN KEY (user_id) REFERENCES users(user_id) ON UPDATE CASCADE ON DELETE CASCADE;
  211. COMMIT;