-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathtranscode_system_migration.sql
671 lines (585 loc) · 28.7 KB
/
transcode_system_migration.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
/*
This script migrates as much configuration as possible from the old transcode system to the new transcode system.
Assumptions:
- This script is run against a 5.10 environment
- No manual changes have been made to any formats after upgrading the targeted environment to 5.10.
Things to be aware of:
- Since this script changes the configuration of the targeted environment,
please ensure that you handle the changes in Configuration Management after having run this script.
If a format doesn't have any conditions specified on when it should be created in the old transcode system
it will be allowed to be created in all cases in the new system. To identify these formats you can use the
following script. The script can be run after the migration too to identify the "bad" formats for cleanup
should that be desired.
```
select mf.media_formatid, mfl.medianame, vf.foldername, vf.folderpath
from (select mf.media_formatid
from media_format mf
left join digizuite_assettype_configs_upload_quality uq on mf.media_formatid = uq.FormatId
where uq.FormatId is null
intersect
select mf.media_formatid
from media_format mf
left join dz_profileformat pf on mf.media_formatid = pf.media_formatid
left join dbo.Layoutfolder_Profile_Destination LPD on pf.dz_profileid = LPD.Dz_ProfileId
where LPD.Layoutfolder_Profile_DestinationId is null
except
select mft.identifyMediaFormatId from media_format_type mft
) as formats_with_path
join media_format mf on mf.media_formatid = formats_with_path.media_formatid
join media_format_language mfl on mf.media_formatid = mfl.media_formatid and mfl.languageid = 3
left join VirtualFolder vf
on mf.foldermedia_formatID = vf.folderid and vf.repositoryid = 16 and vf.languageid = 3
order by foldername asc
```
*/
-- Start transaction to ensure that the migration is atomic.
BEGIN TRANSACTION
BEGIN TRY
SET NOCOUNT ON;
DECLARE @mediaFormatId INT,
@mediaFormatTypeId INT,
@name NVARCHAR(255),
@downloadReplaceMask NVARCHAR(MAX),
@audioBitrate INT,
@videoBitrate INT,
@width INT,
@height INT,
@settings NVARCHAR(1024),
@extension NVARCHAR(10),
@details NVARCHAR(MAX),
@formatId INT,
@compressionLevel INT,
@immediatelyGeneratedFor NVARCHAR(MAX),
@no_security_folder NVARCHAR(MAX),
@pre_generate_folders NVARCHAR(MAX),
@assetFilter NVARCHAR(MAX),
@assetFilter_AssetType NVARCHAR(MAX),
@assetFilter_ChannelFolder NVARCHAR(MAX);
-- Create temp table with media formats to process.
CREATE TABLE #mediaFormatsToProcess(
mediaFormatId INT,
mediaFormatTypeId INT,
name NVARCHAR(255),
downloadReplaceMask NVARCHAR(MAX),
audioBitrate INT,
videoBitrate INT,
width INT,
height INT,
settings NVARCHAR(1024),
no_security_folder nvarchar(max),
pre_generate_folders nvarchar(max)
);
-- Create temp table for keeping track of the migrated formats.
CREATE TABLE #migratedFormats(
mediaFormatId INT,
formatId INT,
extension NVARCHAR(8),
details NVARCHAR(MAX)
);
SELECT @formatId=Id, @details=Details FROM [dbo].[Formats] WHERE [Name] = 'Thumbnail';
IF @formatId IS NOT NULL
BEGIN
SET @mediaFormatId = (SELECT imf.media_formatid
FROM item_media_format imf
JOIN item i on imf.itemid = i.itemid
WHERE i.ItemGuid = 'e579a06d-ea32-451f-a3d3-b937224c2ffa');
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
UPDATE [dbo].[Formats]
SET ImmediatelyGeneratedFor='[0]'
WHERE Id=@formatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, 'webp', @details);
END
SELECT @formatId=Id, @details=Details FROM [dbo].[Formats] WHERE [Name] = 'Large Thumbnail';
IF @formatId IS NOT NULL
BEGIN
SET @mediaFormatId = (SELECT imf.media_formatid
FROM item_media_format imf
JOIN item i on imf.itemid = i.itemid
WHERE i.ItemGuid = '7fb6d99b-9d25-4fb3-831f-b6c51ac08782');
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
UPDATE [dbo].[Formats]
SET ImmediatelyGeneratedFor='[0]'
WHERE Id=@formatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, 'webp', @details);
END
SELECT @formatId=Id, @details=Details FROM [dbo].[Formats] WHERE [Name] = 'PDF';
IF @formatId IS NOT NULL
BEGIN
SET @mediaFormatId = (SELECT imf.media_formatid
FROM item_media_format imf
JOIN item i on imf.itemid = i.itemid
WHERE i.ItemGuid = 'ad44feb1-7038-42a3-a56a-453c76eec8c0');
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
UPDATE [dbo].[Formats]
SET ImmediatelyGeneratedFor='[5,8,9,14,100,101,102,103,105,106,107,108,111,112]'
WHERE Id=@formatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, 'pdf', @details);
END
SELECT @formatId=Id, @details=Details FROM [dbo].[Formats] WHERE [Name] = 'Video Preview';
IF @formatId IS NOT NULL
BEGIN
SET @mediaFormatId = (SELECT imf.media_formatid
FROM item_media_format imf
JOIN item i on imf.itemid = i.itemid
WHERE i.ItemGuid = '8bbd835f-80de-460e-bd68-23ef8cc545b4');
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
UPDATE [dbo].[Formats]
SET ImmediatelyGeneratedFor='[1]'
WHERE Id=@formatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, 'mp4', @details);
END
SELECT @formatId=Id, @details=Details FROM [dbo].[Formats] WHERE [Name] = 'Audio Preview';
IF @formatId IS NOT NULL
BEGIN
SET @mediaFormatId = (SELECT imf.media_formatid
FROM item_media_format imf
JOIN item i on imf.itemid = i.itemid
WHERE i.ItemGuid = '75a39459-ba5f-46aa-897b-3cb915a91c70');
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
UPDATE [dbo].[Formats]
SET ImmediatelyGeneratedFor='[2]'
WHERE Id=@formatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, 'mp3', @details);
END
-- Try migrating each media format that isn't already migrated.
INSERT INTO #mediaFormatsToProcess
SELECT mf.media_formatid, mf.media_format_typeid, mfl.medianame, mf.download_replace_mask,
mf.audiobitrate, mf.videobitrate, mf.width, mf.height, mf.settings,
coalesce((select json_arrayagg(t.LayoutfolderId)
from (select distinct LPD.LayoutfolderId
from dz_profileformat pf
join dz_profile p on pf.dz_profileid = p.dz_profileid
join Layoutfolder_Profile_Destination LPD on p.dz_profileid = LPD.Dz_ProfileId
join digitranscode_destination maybe_storage_manager_destination
on LPD.DestinationId =
maybe_storage_manager_destination.digitranscode_destinationid
left join digitranscode_destination maybe_specific_destination
on maybe_specific_destination.StorageManagerId =
maybe_storage_manager_destination.digitranscode_destinationid
where mf.media_formatid = pf.media_formatid
and (maybe_storage_manager_destination.LaxSecurity = 1 or
maybe_specific_destination.LaxSecurity = 1)) as t), '[]') as no_security_folder,
coalesce(
(select json_arrayagg(t.LayoutfolderId)
from (select distinct LPD.LayoutfolderId
from dz_profileformat pf
join dz_profile p on pf.dz_profileid = p.dz_profileid
join Layoutfolder_Profile_Destination LPD on p.dz_profileid = LPD.Dz_ProfileId
where mf.media_formatid = pf.media_formatid) as t)
, '[]') as pre_generate_folders
FROM [dbo].[media_format] mf
JOIN [dbo].[media_format_language] mfl ON mf.media_formatid=mfl.media_formatid
WHERE mf.mapped_to_format_id IS NULL AND mfl.languageid=3;
WHILE(EXISTS(SELECT NULL FROM #mediaFormatsToProcess))
BEGIN
SELECT TOP 1
@mediaFormatId=mediaFormatId,
@mediaFormatTypeId=mediaFormatTypeId,
@name=name,
@downloadReplaceMask=downloadReplaceMask,
@audioBitrate=audioBitrate,
@videoBitrate=videoBitrate,
@width=width,
@height=height,
@settings=settings,
@pre_generate_folders=pre_generate_folders,
@no_security_folder=no_security_folder
FROM #mediaFormatsToProcess;
DELETE FROM #mediaFormatsToProcess WHERE mediaFormatId=@mediaFormatId;
IF EXISTS(SELECT NULL FROM [dbo].[Formats] WHERE [Name]=@name)
BEGIN
print 'Can not migrate the media format ' + CONVERT(NVARCHAR(10), @mediaFormatId) + ' since a format with the name "' + @name + '" already exists';
CONTINUE;
END
-- Get the extension of the media format.
SELECT TOP 1 @extension=extension FROM [dbo].[media_format_type_extension] WHERE media_format_typeid=@mediaFormatTypeId;
IF @extension IN ('jpg', 'jpeg', 'png', 'webp', 'avif', 'tif', 'tiff') AND (@settings IS NULL OR @settings='')
BEGIN
print 'No ImageMagick command is available for the image media format ' + CONVERT(NVARCHAR(10), @mediaFormatId) + '. ' +
'Can only migrate image media formats with ImageMagick commands.';
CONTINUE;
END
-- Escape backslashes and double-quotes to ensure that the corresponding string is a valid JSON string.
SET @settings = REPLACE(@settings, '\', '\\');
SET @settings = REPLACE(@settings, '"', '\u0022');
-- Get the new format details.
IF @extension='jpg' OR @extension='jpeg'
BEGIN
SET @extension='jpeg';
SET @details = '{"type":"JpegImageFormat",' +
'"BackgroundColor":"transparent",' +
'"ColorSpace":0,' +
'"Quality":0,' +
'"TargetMaxSize":null,' +
'"Interlace":true,' +
'"CropWidth":0,' +
'"CropHeight":0,' +
'"CropPosition":4,' +
'"Clip":false,' +
'"DotsPerInchX":72,' +
'"DotsPerInchY":72,' +
'"AutoOrient":true,' +
'"RemoveFileMetadata":false,' +
'"WatermarkAssetId":0,' +
'"WatermarkAssetExtension":"",' +
'"WatermarkPosition":4,' +
'"WatermarkCoveragePercentage":0,' +
'"WatermarkOffsetX":0,' +
'"WatermarkOffsetY":0,' +
'"WatermarkOpacityPercentage":0,' +
'"CustomConversionCommand":"' + @settings + '",' +
'"Height":0,' +
'"Width":0,' +
'"ResizeMode":2,' +
'"BackgroundWidth":0,' +
'"BackgroundHeight":0}';
END
ELSE IF @extension='png'
BEGIN
SET @details = '{"type":"PngImageFormat",' +
'"ColorSpace":0,' +
'"CompressionLevel":7,' +
'"Interlace":true,' +
'"BackgroundColor":"transparent",' +
'"CropWidth":0,' +
'"CropHeight":0,' +
'"CropPosition":4,' +
'"Clip":false,' +
'"DotsPerInchX":72,' +
'"DotsPerInchY":72,' +
'"AutoOrient":true,' +
'"RemoveFileMetadata":false,' +
'"WatermarkAssetId":0,' +
'"WatermarkAssetExtension":"",' +
'"WatermarkPosition":4,' +
'"WatermarkCoveragePercentage":0,' +
'"WatermarkOffsetX":0,' +
'"WatermarkOffsetY":0,' +
'"WatermarkOpacityPercentage":0,' +
'"CustomConversionCommand":"' + @settings + '",' +
'"Height":0,' +
'"Width":0,' +
'"ResizeMode":2,' +
'"BackgroundWidth":0,' +
'"BackgroundHeight":0}';
END
ELSE IF @extension='webp'
BEGIN
SET @details = '{"type":"WebPImageFormat",' +
'"ColorSpace":0,' +
'"Quality":0,' +
'"BackgroundColor":"transparent",' +
'"CropWidth":0,' +
'"CropHeight":0,' +
'"CropPosition":4,' +
'"Clip":false,' +
'"DotsPerInchX":72,' +
'"DotsPerInchY":72,' +
'"AutoOrient":true,' +
'"RemoveFileMetadata":false,' +
'"WatermarkAssetId":0,' +
'"WatermarkAssetExtension":"",' +
'"WatermarkPosition":4,' +
'"WatermarkCoveragePercentage":0,' +
'"WatermarkOffsetX":0,' +
'"WatermarkOffsetY":0,' +
'"WatermarkOpacityPercentage":0,' +
'"CustomConversionCommand":"' + @settings + '",' +
'"Height":0,' +
'"Width":0,' +
'"ResizeMode":2,' +
'"BackgroundWidth":0,' +
'"BackgroundHeight":0}';
END
ELSE IF @extension='avif'
BEGIN
SET @details = '{"type":"AvifImageFormat",' +
'"ColorSpace":0,' +
'"Quality":0,' +
'"BackgroundColor":"transparent",' +
'"CropWidth":0,' +
'"CropHeight":0,' +
'"CropPosition":4,' +
'"Clip":false,' +
'"DotsPerInchX":72,' +
'"DotsPerInchY":72,' +
'"AutoOrient":true,' +
'"RemoveFileMetadata":false,' +
'"WatermarkAssetId":0,' +
'"WatermarkAssetExtension":"",' +
'"WatermarkPosition":4,' +
'"WatermarkCoveragePercentage":0,' +
'"WatermarkOffsetX":0,' +
'"WatermarkOffsetY":0,' +
'"WatermarkOpacityPercentage":0,' +
'"CustomConversionCommand":"' + @settings + '",' +
'"Height":0,' +
'"Width":0,' +
'"ResizeMode":2,' +
'"BackgroundWidth":0,' +
'"BackgroundHeight":0}';
END
ELSE IF @extension='tif' OR @extension='tiff'
BEGIN
SET @extension='tiff';
SET @details = '{"type":"TiffImageFormat",' +
'"ColorSpace":0,' +
'"BackgroundColor":"transparent",' +
'"CropWidth":0,' +
'"CropHeight":0,' +
'"CropPosition":4,' +
'"Clip":false,' +
'"DotsPerInchX":72,' +
'"DotsPerInchY":72,' +
'"AutoOrient":true,' +
'"RemoveFileMetadata":false,' +
'"WatermarkAssetId":0,' +
'"WatermarkAssetExtension":"",' +
'"WatermarkPosition":4,' +
'"WatermarkCoveragePercentage":0,' +
'"WatermarkOffsetX":0,' +
'"WatermarkOffsetY":0,' +
'"WatermarkOpacityPercentage":0,' +
'"CustomConversionCommand":"' + @settings + '",' +
'"Height":0,' +
'"Width":0,' +
'"ResizeMode":2,' +
'"BackgroundWidth":0,' +
'"BackgroundHeight":0}';
END
ELSE IF @extension='mp3'
BEGIN
SET @compressionLevel = CASE
WHEN @audioBitrate = 0 THEN 4
WHEN @audioBitrate <= 128000 THEN 6
WHEN @audioBitrate < 192000 THEN 4
ELSE 2
END;
SET @details = '{"type":"Mp3AudioFormat",' +
'"CompressionLevel":' + CONVERT(NVARCHAR(10), @compressionLevel);
if @audioBitrate<>0
begin
set @details = @details + ',"Bitrate":' + CONVERT(NVARCHAR(10), @audioBitrate)
end
set @details = @details + '}';
END
ELSE IF @extension='avi'
BEGIN
SET @details = '{"type":"AviVideoFormat",' +
'"BackgroundColor":"#00000000",' +
'"CompressionLevel":23,';
IF @videoBitrate<>0
begin
set @details = @details +
'"VideoBitrate":' + CONVERT(NVARCHAR(10), @videoBitrate) + ',';
end;
IF @audioBitrate<>0
begin
set @details = @details +
'"AudioBitrate":' + CONVERT(NVARCHAR(10), @audioBitrate) + ',';
end;
set @details = @details +
'"Height":' + CONVERT(NVARCHAR(10), @height) + ',' +
'"Width":' + CONVERT(NVARCHAR(10), @width) + ',' +
'"ResizeMode":0,' + -- fixed size
'"BackgroundWidth":0,' +
'"BackgroundHeight":0' +
'}';
END
ELSE IF @extension='mov'
BEGIN
SET @details = '{"type":"MovVideoFormat",' +
'"BackgroundColor":"#00000000",' +
'"CompressionLevel":23,';
IF @videoBitrate<>0
begin
set @details = @details +
'"VideoBitrate":' + CONVERT(NVARCHAR(10), @videoBitrate) + ',';
end;
IF @audioBitrate<>0
begin
set @details = @details +
'"AudioBitrate":' + CONVERT(NVARCHAR(10), @audioBitrate) + ',';
end;
set @details = @details +
'"Height":' + CONVERT(NVARCHAR(10), @height) + ',' +
'"Width":' + CONVERT(NVARCHAR(10), @width) + ',' +
'"ResizeMode":0,' + -- fixed size
'"BackgroundWidth":0,' +
'"BackgroundHeight":0' +
'}';
END
ELSE IF @extension='mp4'
BEGIN
SET @details = '{"type":"Mp4VideoFormat",' +
'"BackgroundColor":"#00000000",' +
'"CompressionLevel":23,';
IF @videoBitrate<>0
begin
set @details = @details +
'"VideoBitrate":' + CONVERT(NVARCHAR(10), @videoBitrate) + ',';
end;
IF @audioBitrate<>0
begin
set @details = @details +
'"AudioBitrate":' + CONVERT(NVARCHAR(10), @audioBitrate) + ',';
end;
set @details = @details +
'"Height":' + CONVERT(NVARCHAR(10), @height) + ',' +
'"Width":' + CONVERT(NVARCHAR(10), @width) + ',' +
'"ResizeMode":0,' + -- fixed size
'"BackgroundWidth":0,' +
'"BackgroundHeight":0' +
'}';
END
ELSE IF @extension='pdf'
SET @details = '{"type":"PdfFormat"}'
ELSE
BEGIN
print 'The extension "' + @extension + '" is not supported in the new transcode system. ' +
'Can not migrate the media format ' + CONVERT(NVARCHAR(10), @mediaFormatId) + '.';
CONTINUE;
END
-- Find asset types to generate renditions of the format for immediately.
SET @immediatelyGeneratedFor = COALESCE(
'[' + (SELECT STRING_AGG(assetType, ',') FROM digizuite_assettype_configs_upload_quality WHERE FormatId = @mediaFormatId) + ']',
'[]'
);
-- Make the download replace mask prettier.
-- This is technically not needed but helps to avoid confusion.
SET @downloadReplaceMask = (SELECT REPLACE(@downloadReplaceMask, '[%MediaFormatId%]', '[%FormatId%]'));
SET @downloadReplaceMask = (SELECT REPLACE(@downloadReplaceMask, '[%MediaFormatName%]', '[%FormatName%]'));
set @assetFilter_AssetType = coalesce((select json_arrayagg(t.assetType)
from (select pat.assettypeid as assetType
from dz_profileformat pf
join dz_profile p on pf.dz_profileid = p.dz_profileid
join dz_profile_assettype pat on p.dz_profileid = pat.dz_profileid
where pf.media_formatid = @mediaFormatId
union
select assetType as assetType
from digizuite_assettype_configs_upload_quality
where FormatId = @mediaFormatId) as t)
, '[]');
set @assetFilter_ChannelFolder = @pre_generate_folders;
-- In case a format is setup to be generated immediately, always consider it available
if exists(select * from digizuite_assettype_configs_upload_quality where FormatId = @mediaFormatId)
begin
set @assetFilter_ChannelFolder = '[]'
end
set @assetFilter = '{"AssetTypes":' + @assetFilter_AssetType + ',"ChannelFolderIds":' + @assetFilter_ChannelFolder + '}';
-- Create new format.
INSERT INTO [dbo].[Formats]([Name],[Description],[Category],[ImmediatelyGeneratedFor],[DownloadReplaceMask],[Details],[CreatedAt],[LastModified],[PreGenerateForChannelFolderIds],[NoSecurityWhenInChannelFolderIds],[AssetFilter])
VALUES (@name, '', 0, @immediatelyGeneratedFor, NULLIF(@downloadReplaceMask, ''), @details, GETDATE(), GETDATE(), @pre_generate_folders, @no_security_folder, @assetFilter);
SELECT @formatId=Id FROM [dbo].[Formats] WHERE [Name]=@name;
-- Map the old format to the new format.
UPDATE [dbo].[media_format]
SET mapped_to_format_id=@formatId
WHERE media_formatid=@mediaFormatId;
INSERT INTO #migratedFormats(mediaFormatId, formatId, extension, details)
VALUES (@mediaFormatId, @formatId, @extension, @details);
END
DROP TABLE #mediaFormatsToProcess;
-- Create an index to make the next query operation faster.
CREATE NONCLUSTERED INDEX [asset_filetable_Media_formatid_index] ON [dbo].[asset_filetable]
(
[Media_formatid] ASC,
[Processing] ASC
)
INCLUDE([assetid],[hashsha1],[destinationid],[Size],[fileName]);
-- Create rendition entries for the migrated formats to avoid re-transcoding.
WHILE EXISTS(SELECT NULL FROM #migratedFormats)
BEGIN
SELECT TOP 1 @mediaFormatId=mediaFormatId, @formatId=formatId, @extension=extension, @details=details FROM #migratedFormats;
DELETE FROM #migratedFormats WHERE mediaFormatId=@mediaFormatId AND formatId=@formatId;
INSERT INTO [dbo].[Renditions]([FormatId],[AssetId],[FilePath],[FileSize],[Fingerprint],[State],[IgnoreSecurity],[ErrorMessage],[LastModified])
SELECT @formatId,
af.assetid,
'assets/' + MIN(af.fileName),
MAX(af.Size),
COALESCE(UPPER(a.hashsha1), '') + '-' + @extension + '-' + @details,
2,
0, -- rely on the migration of profiles to IgnoreSecurity instead of hard-coding it on the rendition.
NULL,
GETDATE()
FROM [dbo].[asset_filetable] af
JOIN [dbo].[asset] a on af.assetid = a.assetid
WHERE af.Media_formatid = @mediaFormatId
AND af.Processing = 0
AND NOT EXISTS(SELECT NULL FROM [dbo].[Renditions] r WHERE r.FormatId = @formatId AND r.AssetId = af.assetid)
GROUP BY af.assetid, af.Media_formatid, a.hashsha1
-- Migrate existing member group download qualities.
INSERT INTO [dbo].[LoginService_GroupDownloadQualities]([MemberGroupId], [FormatId])
SELECT q1.MemberGroupId, CONVERT(NVARCHAR(10), @formatId)
FROM [dbo].[LoginService_GroupDownloadQualities] q1
WHERE q1.FormatId=CONVERT(NVARCHAR(10), @mediaFormatId) AND
NOT EXISTS(SELECT NULL FROM [dbo].[LoginService_GroupDownloadQualities] q2
WHERE q1.MemberGroupId = q2.MemberGroupId AND q2.FormatId = CONVERT(NVARCHAR(10), @formatId));
DELETE FROM [dbo].[LoginService_GroupDownloadQualities] WHERE FormatId = CONVERT(NVARCHAR(10), @mediaFormatId);
END
DROP TABLE #migratedFormats;
-- Prepare special-case migration of source copy media formats.
declare @source_copy_media_format_ids table (media_format_id int primary key);
insert into @source_copy_media_format_ids (media_format_id)
SELECT distinct target_media_formatid
FROM dbo.media_transcode
WHERE source_media_formatid IS NULL
AND progid = 'DigiJobs.JobFileCopy';
-- Map the source copy media formats to the SourceFormat with the id -1.
UPDATE [dbo].[media_format]
SET mapped_to_format_id=-1
WHERE media_formatid IN (SELECT media_format_id FROM @source_copy_media_format_ids);
update Formats
set NoSecurityWhenInChannelFolderIds = coalesce((select json_arrayagg(t.LayoutfolderId)
from (select distinct LPD.LayoutfolderId
from dz_profileformat pf
join dz_profile p on pf.dz_profileid = p.dz_profileid
join Layoutfolder_Profile_Destination LPD
on p.dz_profileid = LPD.Dz_ProfileId
join digitranscode_destination maybe_storage_manager_destination
on LPD.DestinationId =
maybe_storage_manager_destination.digitranscode_destinationid
left join digitranscode_destination maybe_specific_destination
on maybe_specific_destination.StorageManagerId =
maybe_storage_manager_destination.digitranscode_destinationid
where pf.media_formatid in
(SELECT media_format_id FROM @source_copy_media_format_ids)
and (maybe_storage_manager_destination.LaxSecurity = 1 or
maybe_specific_destination.LaxSecurity = 1)) as t), '[]'),
PreGenerateForChannelFolderIds = coalesce(
(select json_arrayagg(t.LayoutfolderId)
from (select distinct LPD.LayoutfolderId
from dz_profileformat pf
join dz_profile p on pf.dz_profileid = p.dz_profileid
join Layoutfolder_Profile_Destination LPD on p.dz_profileid = LPD.Dz_ProfileId
where pf.media_formatid in (SELECT media_format_id FROM @source_copy_media_format_ids)) as t)
, '[]')
where Id = -1
drop index [asset_filetable_Media_formatid_index] ON [dbo].[asset_filetable];
SET NOCOUNT OFF;
-- Migration was successful, commit the changes.
COMMIT TRANSACTION;
END TRY
BEGIN CATCH
-- Migration was unsuccessful, rollback the changes.
IF @@TRANCOUNT > 0 ROLLBACK TRANSACTION;
DECLARE @msg NVARCHAR(MAX), @sev INT, @stt INT;
SET @msg = N'ERROR: Number: ' + CAST(ERROR_NUMBER() as nvarchar(max)) + N', Message: ' + ERROR_MESSAGE();
SET @sev = ERROR_SEVERITY();
SET @stt = ERROR_STATE();
RaisError(@msg, @sev, @stt);
END CATCH