Browse Source

- use gearbox setup-app in order to setup database instead of raw sql files

Damien ACCORSI 10 years ago
parent
commit
5462988448
3 changed files with 297 additions and 31 deletions
  1. 1 2
      tracim/tracim/model/data.py
  2. 26 28
      tracim/tracim/websetup/bootstrap.py
  3. 270 1
      tracim/tracim/websetup/schema.py

+ 1 - 2
tracim/tracim/model/data.py View File

@@ -295,14 +295,13 @@ class ContentType(object):
295 295
         return allowed_types
296 296
 
297 297
 class Content(DeclarativeBase):
298
+
298 299
     __tablename__ = 'contents'
299 300
 
300 301
     revision_to_serialize = -0  # This flag allow to serialize a given revision if required by the user
301 302
 
302 303
     content_id = Column(Integer, autoincrement=True, primary_key=True)
303 304
     parent_id = Column(Integer, ForeignKey('contents.content_id'), nullable=True, default=None)
304
-    node_depth = Column(Integer, unique=False, nullable=False, default=0)
305
-    parent_tree_path = Column(Unicode(255), unique=False, nullable=False, default='')
306 305
     owner_id = Column(Integer, ForeignKey('users.user_id'), nullable=True, default=None)
307 306
 
308 307
     type = Column(Unicode(32), unique=False, nullable=False)

+ 26 - 28
tracim/tracim/websetup/bootstrap.py View File

@@ -14,37 +14,35 @@ def bootstrap(command, conf, vars):
14 14
     from sqlalchemy.exc import IntegrityError
15 15
     try:
16 16
         u = model.User()
17
-        u.user_name = 'manager'
18
-        u.display_name = 'Example manager'
19
-        u.email = 'manager@somedomain.com'
20
-        u.password = 'managepass'
21
-    
17
+        u.display_name = 'Global manager'
18
+        u.email = 'admin@admin.admin'
19
+        u.password = 'admin@admin.admin'
22 20
         model.DBSession.add(u)
23
-    
24
-        g = model.Group()
25
-        g.group_name = 'managers'
26
-        g.display_name = 'Managers Group'
27
-    
28
-        g.users.append(u)
29
-    
30
-        model.DBSession.add(g)
31
-    
32
-        p = model.Permission()
33
-        p.permission_name = 'manage'
34
-        p.description = 'This permission give an administrative right to the bearer'
35
-        p.groups.append(g)
36
-    
37
-        model.DBSession.add(p)
38
-    
39
-        u1 = model.User()
40
-        u1.user_name = 'editor'
41
-        u1.display_name = 'Example editor'
42
-        u1.email = 'editor@somedomain.com'
43
-        u1.password = 'editpass'
44
-    
45
-        model.DBSession.add(u1)
21
+
22
+        g1 = model.Group()
23
+        g1.group_id = 1
24
+        g1.group_name = 'users'
25
+        g1.display_name = 'Users'
26
+        g1.users.append(u)
27
+        model.DBSession.add(g1)
28
+
29
+        g2 = model.Group()
30
+        g2.group_id = 2
31
+        g2.group_name = 'managers'
32
+        g2.display_name = 'Global Managers'
33
+        g2.users.append(u)
34
+        model.DBSession.add(g2)
35
+
36
+        g3 = model.Group()
37
+        g3.group_id = 3
38
+        g3.group_name = 'administrators'
39
+        g3.display_name = 'Administrators'
40
+        g3.users.append(u)
41
+        model.DBSession.add(g3)
42
+
46 43
         model.DBSession.flush()
47 44
         transaction.commit()
45
+
48 46
     except IntegrityError:
49 47
         print('Warning, there was a problem adding your auth data, it may have already been added:')
50 48
         import traceback

+ 270 - 1
tracim/tracim/websetup/schema.py View File

@@ -17,7 +17,15 @@ def setup_schema(command, conf, vars):
17 17
     
18 18
     # <websetup.websetup.schema.before.metadata.create_all>
19 19
     print("Creating tables")
20
-    model.metadata.create_all(bind=config['tg.app_globals'].sa_engine)
20
+    # model.metadata.create_all(bind=config['tg.app_globals'].sa_engine)
21
+
22
+    # result = config['tg.app_globals'].sa_engine.execute(get_initial_schema())
23
+    from sqlalchemy import DDL
24
+    result = model.DBSession.execute(DDL(get_initial_schema()))
25
+    print("Initial schema created.")
26
+
27
+    #ALTER TABLE bibi ADD COLUMN popo integer;
28
+
21 29
     # <websetup.websetup.schema.after.metadata.create_all>
22 30
     transaction.commit()
23 31
     print('Initializing Migrations')
@@ -26,3 +34,264 @@ def setup_schema(command, conf, vars):
26 34
     alembic_cfg.set_main_option("script_location", "migration")
27 35
     alembic_cfg.set_main_option("sqlalchemy.url", config['sqlalchemy.url'])
28 36
     alembic.command.stamp(alembic_cfg, "head")
37
+
38
+
39
+def get_initial_schema():
40
+    return """
41
+SET statement_timeout = 0;
42
+SET client_encoding = 'UTF8';
43
+SET standard_conforming_strings = on;
44
+SET check_function_bodies = false;
45
+SET client_min_messages = warning;
46
+
47
+-- CREATE EXTENSION IF NOT EXISTS plpgsql WITH SCHEMA pg_catalog;
48
+-- COMMENT ON EXTENSION plpgsql IS 'PL/pgSQL procedural language';
49
+SET search_path = public, pg_catalog;
50
+
51
+CREATE FUNCTION update_node() RETURNS trigger
52
+    LANGUAGE plpgsql
53
+    AS $$
54
+BEGIN
55
+INSERT INTO content_revisions (content_id, parent_id, type, created, updated,
56
+       label, description, status,
57
+       file_name, file_content, file_mimetype,
58
+       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.owner_id, nextval('seq__content_revisions__revision_id'), NEW.workspace_id, NEW.is_deleted, NEW.is_archived, NEW.properties, NEW.revision_type);
59
+return new;
60
+END;
61
+$$;
62
+
63
+CREATE FUNCTION set_created() RETURNS trigger
64
+    LANGUAGE plpgsql
65
+    AS $$
66
+BEGIN
67
+    NEW.created = CURRENT_TIMESTAMP;
68
+    NEW.updated = CURRENT_TIMESTAMP;
69
+    RETURN NEW;
70
+END;
71
+$$;
72
+
73
+CREATE FUNCTION set_updated() RETURNS trigger
74
+    LANGUAGE plpgsql
75
+    AS $$
76
+BEGIN
77
+    NEW.updated = CURRENT_TIMESTAMP;
78
+    RETURN NEW;
79
+END;
80
+$$;
81
+
82
+SET default_tablespace = '';
83
+SET default_with_oids = false;
84
+
85
+-- CREATE TABLE migrate_version (
86
+--    version_num character varying(32) NOT NULL
87
+-- );
88
+
89
+CREATE TABLE groups (
90
+    group_id integer NOT NULL,
91
+    group_name character varying(16) NOT NULL,
92
+    display_name character varying(255),
93
+    created timestamp without time zone
94
+);
95
+
96
+CREATE SEQUENCE seq__groups__group_id
97
+    START WITH 1
98
+    INCREMENT BY 1
99
+    NO MINVALUE
100
+    NO MAXVALUE
101
+    CACHE 1;
102
+
103
+ALTER SEQUENCE seq__groups__group_id OWNED BY groups.group_id;
104
+
105
+CREATE TABLE group_permission (
106
+    group_id integer NOT NULL,
107
+    permission_id integer NOT NULL
108
+);
109
+
110
+CREATE SEQUENCE seq__content_revisions__revision_id
111
+    START WITH 1
112
+    INCREMENT BY 1
113
+    NO MINVALUE
114
+    NO MAXVALUE
115
+    CACHE 1;
116
+
117
+CREATE TABLE content_revisions (
118
+    content_id integer NOT NULL,
119
+    parent_id integer,
120
+    type character varying(16) DEFAULT 'data'::character varying NOT NULL,
121
+    created timestamp without time zone,
122
+    updated timestamp without time zone,
123
+    label character varying(1024),
124
+    description text DEFAULT ''::text NOT NULL,
125
+    status character varying(32) DEFAULT 'new'::character varying,
126
+    file_name character varying(255),
127
+    file_content bytea,
128
+    file_mimetype character varying(255),
129
+    owner_id integer,
130
+    revision_id integer DEFAULT nextval('seq__content_revisions__revision_id'::regclass) NOT NULL,
131
+    workspace_id integer,
132
+    is_deleted boolean DEFAULT false NOT NULL,
133
+    is_archived boolean DEFAULT false NOT NULL,
134
+    properties text,
135
+    revision_type character varying(32)
136
+);
137
+
138
+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")';
139
+
140
+CREATE VIEW contents AS
141
+    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.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;
142
+
143
+CREATE SEQUENCE seq__contents__content_id
144
+    START WITH 1
145
+    INCREMENT BY 1
146
+    NO MINVALUE
147
+    NO MAXVALUE
148
+    CACHE 1;
149
+
150
+ALTER SEQUENCE seq__contents__content_id OWNED BY content_revisions.content_id;
151
+
152
+CREATE TABLE permissions (
153
+    permission_id integer NOT NULL,
154
+    permission_name character varying(63) NOT NULL,
155
+    description character varying(255)
156
+);
157
+
158
+CREATE SEQUENCE seq__permissions__permission_id
159
+    START WITH 1
160
+    INCREMENT BY 1
161
+    NO MINVALUE
162
+    NO MAXVALUE
163
+    CACHE 1;
164
+
165
+ALTER SEQUENCE seq__permissions__permission_id OWNED BY permissions.permission_id;
166
+
167
+CREATE TABLE users (
168
+    user_id integer NOT NULL,
169
+    email character varying(255) NOT NULL,
170
+    display_name character varying(255),
171
+    password character varying(128),
172
+    created timestamp without time zone,
173
+    is_active boolean DEFAULT true NOT NULL
174
+);
175
+
176
+CREATE TABLE user_group (
177
+    user_id integer NOT NULL,
178
+    group_id integer NOT NULL
179
+);
180
+
181
+CREATE SEQUENCE seq__users__user_id
182
+    START WITH 1
183
+    INCREMENT BY 1
184
+    NO MINVALUE
185
+    NO MAXVALUE
186
+    CACHE 1;
187
+
188
+ALTER SEQUENCE seq__users__user_id OWNED BY users.user_id;
189
+
190
+CREATE TABLE user_workspace (
191
+    user_id integer NOT NULL,
192
+    workspace_id integer NOT NULL,
193
+    role integer,
194
+    do_notify boolean DEFAULT FALSE NOT NULL
195
+);
196
+
197
+CREATE TABLE workspaces (
198
+    workspace_id integer NOT NULL,
199
+    label character varying(1024),
200
+    description text,
201
+    created timestamp without time zone,
202
+    updated timestamp without time zone,
203
+    is_deleted boolean DEFAULT false NOT NULL
204
+);
205
+
206
+CREATE SEQUENCE seq__workspaces__workspace_id
207
+    START WITH 11
208
+    INCREMENT BY 1
209
+    NO MINVALUE
210
+    NO MAXVALUE
211
+    CACHE 1;
212
+
213
+ALTER TABLE ONLY groups ALTER COLUMN group_id SET DEFAULT nextval('seq__groups__group_id'::regclass);
214
+ALTER TABLE ONLY content_revisions ALTER COLUMN content_id SET DEFAULT nextval('seq__contents__content_id'::regclass);
215
+ALTER TABLE ONLY permissions ALTER COLUMN permission_id SET DEFAULT nextval('seq__permissions__permission_id'::regclass);
216
+ALTER TABLE ONLY users ALTER COLUMN user_id SET DEFAULT nextval('seq__users__user_id'::regclass);
217
+ALTER TABLE ONLY workspaces ALTER COLUMN workspace_id SET DEFAULT nextval('seq__workspaces__workspace_id'::regclass);
218
+
219
+-- COPY migrate_version (version_num) FROM stdin;
220
+
221
+SELECT pg_catalog.setval('seq__groups__group_id', 4, true);
222
+SELECT pg_catalog.setval('seq__contents__content_id', 1, true);
223
+SELECT pg_catalog.setval('seq__content_revisions__revision_id', 2568, true);
224
+SELECT pg_catalog.setval('seq__permissions__permission_id', 1, true);
225
+SELECT pg_catalog.setval('seq__users__user_id', 2, true);
226
+
227
+SELECT pg_catalog.setval('seq__workspaces__workspace_id', 1, true);
228
+
229
+ALTER TABLE ONLY user_workspace
230
+    ADD CONSTRAINT pk__user_workspace__user_id__workspace_id PRIMARY KEY (user_id, workspace_id);
231
+
232
+ALTER TABLE ONLY workspaces
233
+    ADD CONSTRAINT pk__workspace__workspace_id PRIMARY KEY (workspace_id);
234
+
235
+ALTER TABLE ONLY groups
236
+    ADD CONSTRAINT uk__groups__group_name UNIQUE (group_name);
237
+
238
+ALTER TABLE ONLY group_permission
239
+    ADD CONSTRAINT pk__group_permission__group_id__permission_id PRIMARY KEY (group_id, permission_id);
240
+
241
+ALTER TABLE ONLY groups
242
+    ADD CONSTRAINT pk__groups__group_id PRIMARY KEY (group_id);
243
+
244
+ALTER TABLE ONLY content_revisions
245
+    ADD CONSTRAINT pk__content_revisions__revision_id PRIMARY KEY (revision_id);
246
+
247
+ALTER TABLE ONLY permissions
248
+    ADD CONSTRAINT uk__permissions__permission_name UNIQUE (permission_name);
249
+
250
+ALTER TABLE ONLY permissions
251
+    ADD CONSTRAINT pk__permissions__permission_id PRIMARY KEY (permission_id);
252
+
253
+ALTER TABLE ONLY users
254
+    ADD CONSTRAINT uk__users__email UNIQUE (email);
255
+
256
+ALTER TABLE ONLY user_group
257
+    ADD CONSTRAINT pk__user_group__user_id__group_id PRIMARY KEY (user_id, group_id);
258
+
259
+ALTER TABLE ONLY users
260
+    ADD CONSTRAINT pk__users__user_id PRIMARY KEY (user_id);
261
+
262
+CREATE INDEX idx__content_revisions__owner_id ON content_revisions USING btree (owner_id);
263
+
264
+CREATE INDEX idx__content_revisions__parent_id ON content_revisions USING btree (parent_id);
265
+
266
+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, 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.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.owner_id, content_revisions.workspace_id, content_revisions.is_deleted, content_revisions.is_archived, content_revisions.properties, content_revisions.revision_type;
267
+
268
+CREATE TRIGGER trg__contents__on_insert__set_created BEFORE INSERT ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_created();
269
+CREATE TRIGGER trg__contents__on_update__set_updated BEFORE UPDATE ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_updated();
270
+
271
+CREATE TRIGGER trg__contents__on_update INSTEAD OF UPDATE ON contents FOR EACH ROW EXECUTE PROCEDURE update_node();
272
+CREATE TRIGGER trg__workspaces__on_insert__set_created BEFORE INSERT ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_created();
273
+CREATE TRIGGER trg__workspaces__on_update__set_updated BEFORE UPDATE ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_updated();
274
+
275
+ALTER TABLE ONLY user_workspace
276
+    ADD CONSTRAINT fk__user_workspace__user_id FOREIGN KEY (user_id) REFERENCES users(user_id) ON UPDATE CASCADE ON DELETE CASCADE;
277
+
278
+ALTER TABLE ONLY user_workspace
279
+    ADD CONSTRAINT fk__user_workspace__workspace_id FOREIGN KEY (workspace_id) REFERENCES workspaces(workspace_id) ON UPDATE CASCADE ON DELETE CASCADE;
280
+
281
+ALTER TABLE ONLY group_permission
282
+    ADD CONSTRAINT fk__group_permission__group_id FOREIGN KEY (group_id) REFERENCES groups(group_id) ON UPDATE CASCADE ON DELETE CASCADE;
283
+
284
+ALTER TABLE ONLY group_permission
285
+    ADD CONSTRAINT fk__group_permission__permission_id FOREIGN KEY (permission_id) REFERENCES permissions(permission_id) ON UPDATE CASCADE ON DELETE CASCADE;
286
+
287
+ALTER TABLE ONLY content_revisions
288
+    ADD CONSTRAINT fk__content_revisions__owner_id FOREIGN KEY (owner_id) REFERENCES users(user_id);
289
+
290
+ALTER TABLE ONLY user_group
291
+    ADD CONSTRAINT fk__user_group__group_id FOREIGN KEY (group_id) REFERENCES groups(group_id) ON UPDATE CASCADE ON DELETE CASCADE;
292
+
293
+ALTER TABLE ONLY user_group
294
+    ADD CONSTRAINT fk__user_group__user_id FOREIGN KEY (user_id) REFERENCES users(user_id) ON UPDATE CASCADE ON DELETE CASCADE;
295
+
296
+COMMIT;
297
+"""