Skip to content

Commit 055d50b

Browse files
committed
fix #6429 Migration of HTML content to Content Workflow does not work for some sites
1 parent 1bd102c commit 055d50b

File tree

1 file changed

+279
-31
lines changed

1 file changed

+279
-31
lines changed

DNN Platform/Modules/HTML/Providers/DataProviders/SqlDataProvider/10.00.00.SqlDataProvider

+279-31
Original file line numberDiff line numberDiff line change
@@ -13,69 +13,317 @@
1313
/***** SqlDataProvider *****/
1414
/************************************************************/
1515

16-
-- Drop Foreign Key FK_HtmlText_WorkflowStates if it exists
16+
-- Drop Foreign Keys if they exist
1717
IF EXISTS (SELECT * FROM sys.foreign_keys WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}FK_HtmlText_WorkflowStates') AND parent_object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}HtmlText'))
1818
BEGIN
1919
ALTER TABLE {databaseOwner}{objectQualifier}HtmlText DROP CONSTRAINT FK_HtmlText_WorkflowStates;
2020
END
2121
GO
2222

23-
-- Drop Foreign Key FK_HtmlTextLog_WorkflowStates if it exists
2423
IF EXISTS (SELECT * FROM sys.foreign_keys WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}FK_HtmlTextLog_WorkflowStates') AND parent_object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}HtmlTextLog'))
2524
BEGIN
2625
ALTER TABLE {databaseOwner}{objectQualifier}HtmlTextLog DROP CONSTRAINT FK_HtmlTextLog_WorkflowStates;
2726
END
2827
GO
2928

30-
-- Drop Foreign Key FK_WorkflowStates_Workflow if it exists
3129
IF EXISTS (SELECT * FROM sys.foreign_keys WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}FK_WorkflowStates_Workflow') AND parent_object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}WorkflowStates'))
3230
BEGIN
3331
ALTER TABLE {databaseOwner}{objectQualifier}WorkflowStates DROP CONSTRAINT FK_WorkflowStates_Workflow;
3432
END
3533
GO
3634

37-
-- Update StateID in HtmlText when possible (only default workflows)
38-
DECLARE @CountResult INT;
35+
-- Create a robust workflow migration process
36+
-- Now create a procedure to ensure that missing content workflows and states are populated before running the migration
37+
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}CreateMissingContentWorkflows') AND type in (N'P', N'PC'))
38+
BEGIN
39+
DROP PROCEDURE {databaseOwner}{objectQualifier}CreateMissingContentWorkflows;
40+
END
41+
GO
42+
43+
CREATE PROCEDURE {databaseOwner}{objectQualifier}CreateMissingContentWorkflows
44+
AS
45+
BEGIN
46+
SET NOCOUNT ON;
47+
48+
-- Create all workflows for all portals in a set-based operation
49+
-- Direct Publish workflows
50+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflows
51+
(PortalID, WorkflowName, WorkflowKey, Description, IsSystem, IsDeleted)
52+
SELECT
53+
p.PortalID,
54+
N'Direct Publish',
55+
N'DirectPublish',
56+
N'Allows an author to directly publish content to the site.',
57+
1,
58+
0
59+
FROM {databaseOwner}{objectQualifier}Portals p
60+
WHERE NOT EXISTS (
61+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
62+
WHERE cw.PortalID = p.PortalID
63+
AND cw.WorkflowName = N'Direct Publish'
64+
AND cw.IsDeleted = 0
65+
);
66+
67+
-- Save Draft workflows
68+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflows
69+
(PortalID, WorkflowName, WorkflowKey, Description, IsSystem, IsDeleted)
70+
SELECT
71+
p.PortalID,
72+
N'Save Draft',
73+
N'SaveDraft',
74+
N'Allows author to save a draft copy before the content is published.',
75+
1,
76+
0
77+
FROM {databaseOwner}{objectQualifier}Portals p
78+
WHERE NOT EXISTS (
79+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
80+
WHERE cw.PortalID = p.PortalID
81+
AND cw.WorkflowName = N'Save Draft'
82+
AND cw.IsDeleted = 0
83+
);
84+
85+
-- Content Approval workflows
86+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflows
87+
(PortalID, WorkflowName, WorkflowKey, Description, IsSystem, IsDeleted)
88+
SELECT
89+
p.PortalID,
90+
N'Content Approval',
91+
N'ContentApproval',
92+
N'Allows an author to manage content and then have it reviewed by other users before it is published.',
93+
1,
94+
0
95+
FROM {databaseOwner}{objectQualifier}Portals p
96+
WHERE NOT EXISTS (
97+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
98+
WHERE cw.PortalID = p.PortalID
99+
AND cw.WorkflowName = N'Content Approval'
100+
AND cw.IsDeleted = 0
101+
);
102+
103+
-- Now create all states for Direct Publish workflows
104+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
105+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
106+
SELECT
107+
cw.WorkflowID,
108+
N'Published',
109+
1,
110+
1,
111+
1,
112+
0
113+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
114+
WHERE cw.WorkflowName = N'Direct Publish'
115+
AND NOT EXISTS (
116+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
117+
WHERE cws.WorkflowID = cw.WorkflowID
118+
AND cws.StateName = N'Published'
119+
);
120+
121+
-- Create states for Save Draft workflows
122+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
123+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
124+
SELECT
125+
cw.WorkflowID,
126+
N'Draft',
127+
1,
128+
1,
129+
1,
130+
0
131+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
132+
WHERE cw.WorkflowName = N'Save Draft'
133+
AND NOT EXISTS (
134+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
135+
WHERE cws.WorkflowID = cw.WorkflowID
136+
AND cws.StateName = N'Draft'
137+
);
138+
139+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
140+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
141+
SELECT
142+
cw.WorkflowID,
143+
N'Published',
144+
2,
145+
1,
146+
1,
147+
0
148+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
149+
WHERE cw.WorkflowName = N'Save Draft'
150+
AND NOT EXISTS (
151+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
152+
WHERE cws.WorkflowID = cw.WorkflowID
153+
AND cws.StateName = N'Published'
154+
);
155+
156+
-- Create states for Content Approval workflows
157+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
158+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
159+
SELECT
160+
cw.WorkflowID,
161+
N'Draft',
162+
1,
163+
1,
164+
1,
165+
0
166+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
167+
WHERE cw.WorkflowName = N'Content Approval'
168+
AND NOT EXISTS (
169+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
170+
WHERE cws.WorkflowID = cw.WorkflowID
171+
AND cws.StateName = N'Draft'
172+
);
173+
174+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
175+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
176+
SELECT
177+
cw.WorkflowID,
178+
N'Ready For Review',
179+
2,
180+
1,
181+
1,
182+
1
183+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
184+
WHERE cw.WorkflowName = N'Content Approval'
185+
AND NOT EXISTS (
186+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
187+
WHERE cws.WorkflowID = cw.WorkflowID
188+
AND cws.StateName = N'Ready For Review'
189+
);
190+
191+
INSERT INTO {databaseOwner}{objectQualifier}ContentWorkflowStates
192+
(WorkflowID, StateName, [Order], IsSystem, SendNotification, SendNotificationToAdministrators)
193+
SELECT
194+
cw.WorkflowID,
195+
N'Published',
196+
3,
197+
1,
198+
1,
199+
0
200+
FROM {databaseOwner}{objectQualifier}ContentWorkflows cw
201+
WHERE cw.WorkflowName = N'Content Approval'
202+
AND NOT EXISTS (
203+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates cws
204+
WHERE cws.WorkflowID = cw.WorkflowID
205+
AND cws.StateName = N'Published'
206+
);
207+
END
208+
GO
209+
210+
-- Execute the procedure to ensure that missing content workflows and states are populated
211+
EXEC {databaseOwner}{objectQualifier}CreateMissingContentWorkflows;
212+
GO
213+
214+
-- Clean up by dropping procedure (optional)
215+
-- IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}CreateMissingContentWorkflows') AND type in (N'P', N'PC'))
216+
-- BEGIN
217+
-- DROP PROCEDURE {databaseOwner}{objectQualifier}CreateMissingContentWorkflows;
218+
-- END
219+
-- GO
220+
221+
-- Now create a procedure to migrate HTML module content from old workflows to new
222+
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}MigrateHtmlWorkflows') AND type in (N'P', N'PC'))
223+
BEGIN
224+
DROP PROCEDURE {databaseOwner}{objectQualifier}MigrateHtmlWorkflows;
225+
END
226+
GO
39227

40-
SELECT @CountResult = COUNT(*)
41-
FROM {databaseOwner}{objectQualifier}WorkflowStates AS s1
42-
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates AS s2
43-
ON s1.StateID = s2.StateID
44-
AND s1.WorkflowID = s2.WorkflowID
45-
AND s1.StateName = s2.StateName;
46228

47-
IF @CountResult = 3 -- The count should be 3 for the default workflows
229+
CREATE PROCEDURE {databaseOwner}{objectQualifier}MigrateHtmlWorkflows
230+
AS
48231
BEGIN
49-
BEGIN TRANSACTION;
232+
SET NOCOUNT ON;
233+
234+
-- Create mapping table for old and new workflow states
235+
DECLARE @StateMapping TABLE (
236+
OldStateID INT,
237+
NewStateID INT
238+
);
50239

240+
-- Map old workflow states to new ones in one operation
241+
INSERT INTO @StateMapping (OldStateID, NewStateID)
242+
SELECT DISTINCT ws.StateID, cws.StateID
243+
FROM {databaseOwner}{objectQualifier}WorkflowStates ws
244+
INNER JOIN {databaseOwner}{objectQualifier}Workflow w ON ws.WorkflowID = w.WorkflowID
245+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows cw ON
246+
(w.PortalID = cw.PortalID OR (w.PortalID IS NULL AND cw.PortalID IS NOT NULL))
247+
AND (w.WorkflowName = cw.WorkflowName OR (w.WorkflowName = 'Content Staging' AND cw.WorkflowName ='Save Draft'))
248+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates cws ON
249+
cw.WorkflowID = cws.WorkflowID AND ws.StateName = cws.StateName;
250+
251+
-- Update HtmlText table with new StateIDs
51252
BEGIN TRY
52-
-- Perform the update
253+
BEGIN TRANSACTION;
254+
255+
-- First try to map using the state mapping table
256+
UPDATE {databaseOwner}{objectQualifier}HtmlText
257+
SET StateID = sm.NewStateID
258+
FROM {databaseOwner}{objectQualifier}HtmlText ht
259+
INNER JOIN @StateMapping sm ON ht.StateID = sm.OldStateID
260+
WHERE sm.NewStateID IS NOT NULL;
261+
262+
-- For any remaining records, use portal and state name to find a match
53263
UPDATE {databaseOwner}{objectQualifier}HtmlText
54-
SET StateID = s2.StateID
55-
FROM {databaseOwner}{objectQualifier}HtmlText AS h
56-
INNER JOIN {databaseOwner}{objectQualifier}Modules AS m ON h.ModuleID = m.ModuleID
57-
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates AS s1 ON h.StateID = s1.StateID
58-
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows AS w1 ON s1.WorkflowID = w1.WorkflowID
59-
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows AS w2 ON w1.WorkflowKey = w2.WorkflowKey AND m.PortalID = w2.PortalID
60-
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates AS s2 ON s1.StateName = s2.StateName AND w2.WorkflowID = s2.WorkflowID;
61-
62-
-- Commit the transaction
264+
SET StateID = cws.StateID
265+
FROM {databaseOwner}{objectQualifier}HtmlText ht
266+
INNER JOIN {databaseOwner}{objectQualifier}Modules m ON ht.ModuleID = m.ModuleID
267+
INNER JOIN {databaseOwner}{objectQualifier}WorkflowStates ws ON ht.StateID = ws.StateID
268+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows cw ON m.PortalID = cw.PortalID
269+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates cws ON
270+
cw.WorkflowID = cws.WorkflowID AND ws.StateName = cws.StateName
271+
WHERE NOT EXISTS (
272+
SELECT 1 FROM @StateMapping sm WHERE ht.StateID = sm.OldStateID
273+
);
274+
275+
-- As a fallback, set any unmapped states to Published state
276+
UPDATE {databaseOwner}{objectQualifier}HtmlText
277+
SET StateID = cws.StateID
278+
FROM {databaseOwner}{objectQualifier}HtmlText ht
279+
INNER JOIN {databaseOwner}{objectQualifier}Modules m ON ht.ModuleID = m.ModuleID
280+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows cw ON m.PortalID = cw.PortalID AND cw.WorkflowName = 'Direct Publish'
281+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates cws ON cw.WorkflowID = cws.WorkflowID AND cws.StateName = 'Published'
282+
WHERE NOT EXISTS (
283+
SELECT 1 FROM {databaseOwner}{objectQualifier}ContentWorkflowStates WHERE StateID = ht.StateID
284+
);
285+
286+
-- Update HtmlTextLog table
287+
UPDATE {databaseOwner}{objectQualifier}HtmlTextLog
288+
SET StateID = sm.NewStateID
289+
FROM {databaseOwner}{objectQualifier}HtmlTextLog htl
290+
INNER JOIN @StateMapping sm ON htl.StateID = sm.OldStateID;
291+
292+
-- For any remaining HtmlTextLog records, use the item's module info to find proper state
293+
UPDATE {databaseOwner}{objectQualifier}HtmlTextLog
294+
SET StateID = cws.StateID
295+
FROM {databaseOwner}{objectQualifier}HtmlTextLog htl
296+
INNER JOIN {databaseOwner}{objectQualifier}HtmlText ht ON htl.ItemID = ht.ItemID
297+
INNER JOIN {databaseOwner}{objectQualifier}Modules m ON ht.ModuleID = m.ModuleID
298+
INNER JOIN {databaseOwner}{objectQualifier}WorkflowStates ws ON htl.StateID = ws.StateID
299+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflows cw ON m.PortalID = cw.PortalID
300+
INNER JOIN {databaseOwner}{objectQualifier}ContentWorkflowStates cws ON
301+
cw.WorkflowID = cws.WorkflowID AND ws.StateName = cws.StateName
302+
WHERE NOT EXISTS (
303+
SELECT 1 FROM @StateMapping sm WHERE htl.StateID = sm.OldStateID
304+
);
305+
63306
COMMIT TRANSACTION;
64-
PRINT 'Transaction committed successfully.';
307+
PRINT 'HTML module workflow migration completed successfully.';
65308
END TRY
66309
BEGIN CATCH
67-
-- Rollback the transaction in case of an error
68310
ROLLBACK TRANSACTION;
69-
PRINT 'Transaction rolled back due to an error.';
70-
PRINT ERROR_MESSAGE();
311+
PRINT 'Error updating HTML module workflow references: ' + ERROR_MESSAGE();
71312
END CATCH
72313
END
73-
ELSE
74-
BEGIN
75-
PRINT 'The count is not equal to 3. No action was taken.';
76-
END
77314
GO
78315

316+
-- Execute the migration procedure
317+
EXEC {databaseOwner}{objectQualifier}MigrateHtmlWorkflows;
318+
GO
319+
320+
-- Clean up by dropping the migration procedure (optional)
321+
-- IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}MigrateHtmlWorkflows') AND type in (N'P', N'PC'))
322+
-- BEGIN
323+
-- DROP PROCEDURE {databaseOwner}{objectQualifier}MigrateHtmlWorkflows;
324+
-- END
325+
-- GO
326+
79327
-- Drop Table Workflow if it exists
80328
IF EXISTS (SELECT * FROM sys.objects WHERE object_id = OBJECT_ID(N'{databaseOwner}{objectQualifier}Workflow') AND type in (N'U'))
81329
BEGIN

0 commit comments

Comments
 (0)