|
@@ -0,0 +1,187 @@
|
|
1
|
+"""delete_content_view
|
|
2
|
+
|
|
3
|
+Revision ID: da12239d9da0
|
|
4
|
+Revises: b73e57760b36
|
|
5
|
+Create Date: 2016-03-04 15:59:05.828757
|
|
6
|
+
|
|
7
|
+"""
|
|
8
|
+
|
|
9
|
+# revision identifiers, used by Alembic.
|
|
10
|
+revision = 'da12239d9da0'
|
|
11
|
+down_revision = 'b73e57760b36'
|
|
12
|
+
|
|
13
|
+import sqlalchemy as sa
|
|
14
|
+from alembic import op
|
|
15
|
+from sqlalchemy.dialects import postgresql
|
|
16
|
+
|
|
17
|
+
|
|
18
|
+def set_field_where_null(field_name, value="''"):
|
|
19
|
+ op.execute("UPDATE content_revisions SET %s = %s WHERE %s IS NULL" % (field_name, value, field_name))
|
|
20
|
+
|
|
21
|
+
|
|
22
|
+def set_field_to_null_where_empty_string(field_name):
|
|
23
|
+ op.execute("UPDATE content_revisions SET %s = NULL WHERE %s = ''" % (field_name, field_name))
|
|
24
|
+
|
|
25
|
+fields_names_to_empty_string = ('file_mimetype', 'file_name', 'label', 'properties',
|
|
26
|
+ 'revision_type', 'status', 'description', 'label')
|
|
27
|
+
|
|
28
|
+
|
|
29
|
+def upgrade():
|
|
30
|
+ ### commands auto generated by Alembic - please adjust! ###
|
|
31
|
+
|
|
32
|
+ # Drop triggers
|
|
33
|
+ op.execute("DROP TRIGGER trg__contents__on_insert__set_created ON content_revisions")
|
|
34
|
+ op.execute("DROP TRIGGER trg__contents__on_update__set_updated ON content_revisions")
|
|
35
|
+ op.execute("DROP TRIGGER trg__contents__on_update On contents")
|
|
36
|
+ op.execute("DROP TRIGGER trg__workspaces__on_insert__set_created ON workspaces")
|
|
37
|
+ op.execute("DROP TRIGGER trg__workspaces__on_update__set_updated ON workspaces")
|
|
38
|
+ op.execute("DROP VIEW contents")
|
|
39
|
+
|
|
40
|
+ # Set empty string on future non null fields
|
|
41
|
+ for field_name in fields_names_to_empty_string:
|
|
42
|
+ set_field_where_null(field_name)
|
|
43
|
+
|
|
44
|
+ op.create_table('content',
|
|
45
|
+ sa.Column('id', sa.Integer(), nullable=False),
|
|
46
|
+ sa.PrimaryKeyConstraint('id', name=op.f('pk__content'))
|
|
47
|
+ )
|
|
48
|
+
|
|
49
|
+ # Create contents and reinit auto increment
|
|
50
|
+ op.execute("INSERT INTO content (id) SELECT DISTINCT(content_id) FROM content_revisions;")
|
|
51
|
+ op.execute("select setval('content_id_seq', (select max(id)+1 from content), false)")
|
|
52
|
+
|
|
53
|
+ op.alter_column('content_revisions', 'created',
|
|
54
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
55
|
+ nullable=False,
|
|
56
|
+ server_default=sa.func.now())
|
|
57
|
+ op.alter_column('content_revisions', 'file_mimetype',
|
|
58
|
+ existing_type=sa.VARCHAR(length=255),
|
|
59
|
+ nullable=False,
|
|
60
|
+ server_default='')
|
|
61
|
+ op.alter_column('content_revisions', 'file_name',
|
|
62
|
+ existing_type=sa.VARCHAR(length=255),
|
|
63
|
+ nullable=False,
|
|
64
|
+ server_default='')
|
|
65
|
+ op.alter_column('content_revisions', 'label',
|
|
66
|
+ existing_type=sa.VARCHAR(length=1024),
|
|
67
|
+ nullable=False,
|
|
68
|
+ server_default='')
|
|
69
|
+ op.alter_column('content_revisions', 'properties',
|
|
70
|
+ existing_type=sa.TEXT(),
|
|
71
|
+ nullable=False,
|
|
72
|
+ server_default='')
|
|
73
|
+ op.alter_column('content_revisions', 'revision_type',
|
|
74
|
+ existing_type=sa.VARCHAR(length=32),
|
|
75
|
+ nullable=False,
|
|
76
|
+ server_default='')
|
|
77
|
+ op.alter_column('content_revisions', 'status',
|
|
78
|
+ existing_type=sa.VARCHAR(length=32),
|
|
79
|
+ nullable=False,
|
|
80
|
+ existing_server_default=sa.text("'new'::character varying"),
|
|
81
|
+ server_default='')
|
|
82
|
+ op.alter_column('content_revisions', 'updated',
|
|
83
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
84
|
+ nullable=False,
|
|
85
|
+ server_default=sa.func.now())
|
|
86
|
+ op.create_foreign_key(op.f('fk__content_revisions__content_id__content'), 'content_revisions', 'content',
|
|
87
|
+ ['content_id'], ['id'])
|
|
88
|
+ op.create_foreign_key(op.f('fk__content_revisions__workspace_id__workspaces'), 'content_revisions', 'workspaces',
|
|
89
|
+ ['workspace_id'], ['workspace_id'])
|
|
90
|
+ op.create_foreign_key(op.f('fk__content_revisions__parent_id__content'), 'content_revisions', 'content',
|
|
91
|
+ ['parent_id'], ['id'])
|
|
92
|
+ op.alter_column('user_workspace', 'role',
|
|
93
|
+ existing_type=sa.INTEGER(),
|
|
94
|
+ nullable=False)
|
|
95
|
+ op.drop_constraint('fk__user_workspace__user_id', 'user_workspace', type_='foreignkey')
|
|
96
|
+ op.drop_constraint('fk__user_workspace__workspace_id', 'user_workspace', type_='foreignkey')
|
|
97
|
+ op.create_foreign_key(op.f('fk__user_workspace__user_id__users'), 'user_workspace', 'users', ['user_id'],
|
|
98
|
+ ['user_id'])
|
|
99
|
+ op.create_foreign_key(op.f('fk__user_workspace__workspace_id__workspaces'), 'user_workspace', 'workspaces',
|
|
100
|
+ ['workspace_id'], ['workspace_id'])
|
|
101
|
+ op.alter_column('workspaces', 'created',
|
|
102
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
103
|
+ nullable=False,
|
|
104
|
+ server_default=sa.func.now())
|
|
105
|
+ op.alter_column('workspaces', 'description',
|
|
106
|
+ existing_type=sa.TEXT(),
|
|
107
|
+ nullable=False,
|
|
108
|
+ server_default='')
|
|
109
|
+ op.alter_column('workspaces', 'label',
|
|
110
|
+ existing_type=sa.VARCHAR(length=1024),
|
|
111
|
+ nullable=False,
|
|
112
|
+ server_default='')
|
|
113
|
+ op.alter_column('workspaces', 'updated',
|
|
114
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
115
|
+ nullable=False,
|
|
116
|
+ server_default=sa.func.now())
|
|
117
|
+ ### end Alembic commands ###
|
|
118
|
+
|
|
119
|
+
|
|
120
|
+def downgrade():
|
|
121
|
+ ### commands auto generated by Alembic - please adjust! ###
|
|
122
|
+ op.alter_column('workspaces', 'updated',
|
|
123
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
124
|
+ nullable=True)
|
|
125
|
+ op.alter_column('workspaces', 'label',
|
|
126
|
+ existing_type=sa.VARCHAR(length=1024),
|
|
127
|
+ nullable=True)
|
|
128
|
+ op.alter_column('workspaces', 'description',
|
|
129
|
+ existing_type=sa.TEXT(),
|
|
130
|
+ nullable=True)
|
|
131
|
+ op.alter_column('workspaces', 'created',
|
|
132
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
133
|
+ nullable=True)
|
|
134
|
+ op.drop_constraint(op.f('fk__user_workspace__workspace_id__workspaces'), 'user_workspace', type_='foreignkey')
|
|
135
|
+ op.drop_constraint(op.f('fk__user_workspace__user_id__users'), 'user_workspace', type_='foreignkey')
|
|
136
|
+ op.create_foreign_key('fk__user_workspace__workspace_id', 'user_workspace', 'workspaces', ['workspace_id'],
|
|
137
|
+ ['workspace_id'], onupdate='CASCADE', ondelete='CASCADE')
|
|
138
|
+ op.create_foreign_key('fk__user_workspace__user_id', 'user_workspace', 'users', ['user_id'], ['user_id'],
|
|
139
|
+ onupdate='CASCADE', ondelete='CASCADE')
|
|
140
|
+ op.alter_column('user_workspace', 'role',
|
|
141
|
+ existing_type=sa.INTEGER(),
|
|
142
|
+ nullable=True)
|
|
143
|
+ op.drop_constraint(op.f('fk__content_revisions__parent_id__content'), 'content_revisions', type_='foreignkey')
|
|
144
|
+ op.drop_constraint(op.f('fk__content_revisions__workspace_id__workspaces'), 'content_revisions', type_='foreignkey')
|
|
145
|
+ op.drop_constraint(op.f('fk__content_revisions__content_id__content'), 'content_revisions', type_='foreignkey')
|
|
146
|
+ op.alter_column('content_revisions', 'updated',
|
|
147
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
148
|
+ nullable=True)
|
|
149
|
+ op.alter_column('content_revisions', 'status',
|
|
150
|
+ existing_type=sa.VARCHAR(length=32),
|
|
151
|
+ nullable=True,
|
|
152
|
+ existing_server_default=sa.text("'new'::character varying"))
|
|
153
|
+ op.alter_column('content_revisions', 'revision_type',
|
|
154
|
+ existing_type=sa.VARCHAR(length=32),
|
|
155
|
+ nullable=True)
|
|
156
|
+ op.alter_column('content_revisions', 'properties',
|
|
157
|
+ existing_type=sa.TEXT(),
|
|
158
|
+ nullable=True)
|
|
159
|
+ op.alter_column('content_revisions', 'label',
|
|
160
|
+ existing_type=sa.VARCHAR(length=1024),
|
|
161
|
+ nullable=True)
|
|
162
|
+ op.alter_column('content_revisions', 'file_name',
|
|
163
|
+ existing_type=sa.VARCHAR(length=255),
|
|
164
|
+ nullable=True)
|
|
165
|
+ op.alter_column('content_revisions', 'file_mimetype',
|
|
166
|
+ existing_type=sa.VARCHAR(length=255),
|
|
167
|
+ nullable=True)
|
|
168
|
+ op.alter_column('content_revisions', 'created',
|
|
169
|
+ existing_type=postgresql.TIMESTAMP(),
|
|
170
|
+ nullable=True)
|
|
171
|
+ op.drop_table('content')
|
|
172
|
+
|
|
173
|
+ for field_name in fields_names_to_empty_string:
|
|
174
|
+ set_field_to_null_where_empty_string(field_name)
|
|
175
|
+
|
|
176
|
+ op.execute("""
|
|
177
|
+CREATE VIEW contents AS
|
|
178
|
+ 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;
|
|
179
|
+
|
|
180
|
+
|
|
181
|
+CREATE TRIGGER trg__contents__on_insert__set_created BEFORE INSERT ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_created();
|
|
182
|
+CREATE TRIGGER trg__contents__on_update__set_updated BEFORE UPDATE ON content_revisions FOR EACH ROW EXECUTE PROCEDURE set_updated();
|
|
183
|
+CREATE TRIGGER trg__contents__on_update INSTEAD OF UPDATE ON contents FOR EACH ROW EXECUTE PROCEDURE update_node();
|
|
184
|
+CREATE TRIGGER trg__workspaces__on_insert__set_created BEFORE INSERT ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_created();
|
|
185
|
+CREATE TRIGGER trg__workspaces__on_update__set_updated BEFORE UPDATE ON workspaces FOR EACH ROW EXECUTE PROCEDURE set_updated();
|
|
186
|
+""")
|
|
187
|
+ ### end Alembic commands ###
|