File: upgrade-5.0d1-5.0d2.sql

package info (click to toggle)
dotlrn 2.5.0%2Bdfsg-2
  • links: PTS, VCS
  • area: main
  • in suites: squeeze
  • size: 108,252 kB
  • ctags: 19,369
  • sloc: tcl: 219,601; sql: 202,152; xml: 127,658; java: 7,268; php: 4,780; sh: 2,428; perl: 1,207; makefile: 134
file content (571 lines) | stat: -rw-r--r-- 21,562 bytes parent folder | download | duplicates (3)
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
-- /packages/news/sql/news-create.sql
--
-- @author stefan@arsdigita.com
-- @created 2000-12-13
-- @cvs-id $Id: upgrade-5.0d1-5.0d2.sql,v 1.2 2006/08/08 21:27:04 donb Exp $


-- *** PACKAGE NEWS, plsql to create content_item ***
create or replace package news
as 
    function new (
        item_id                 in cr_items.item_id%TYPE 	  default null,
        --
        locale                  in cr_items.locale%TYPE 	  default null, 
        --
        publish_date            in cr_revisions.publish_date%TYPE default null,
        text                    in varchar2                       default null,
        nls_language            in cr_revisions.nls_language%TYPE default null,
        title                   in cr_revisions.title%TYPE 	  default null,
        mime_type               in cr_revisions.mime_type%TYPE    default 'text/plain',
        --
        package_id              in cr_news.package_id%TYPE 	  default null,        
        archive_date            in cr_news.archive_date%TYPE      default null,
        approval_user           in cr_news.approval_user%TYPE     default null,
        approval_date           in cr_news.approval_date%TYPE     default null,
        approval_ip             in cr_news.approval_ip%TYPE       default null,      
        --
        relation_tag            in cr_child_rels.relation_tag%TYPE 
                                                                  default null,
        --
        item_subtype            in acs_object_types.object_type%TYPE 
                                                                  default 'content_revision',
        content_type            in acs_object_types.object_type%TYPE 
                                                                  default 'news',
        creation_date           in acs_objects.creation_date%TYPE default sysdate,
        creation_ip             in acs_objects.creation_ip%TYPE   default null,
        creation_user           in acs_objects.creation_user%TYPE default null,
        --
        is_live_p               in varchar2                       default 'f' 
    ) return cr_news.news_id%TYPE;

    procedure del (
        item_id in cr_items.item_id%TYPE
    );  

    procedure archive (
        item_id in cr_items.item_id%TYPE,
        archive_date in cr_news.archive_date%TYPE default sysdate       
    );  

    procedure make_permanent (
           item_id in cr_items.item_id%TYPE
    );

   
    procedure set_approve (
        revision_id      in cr_revisions.revision_id%TYPE,       
	approve_p        in varchar2 default 't',  
        publish_date     in cr_revisions.publish_date%TYPE  	default null,
        archive_date     in cr_news.archive_date%TYPE 		default null,
        approval_user    in cr_news.approval_user%TYPE 		default null,
        approval_date    in cr_news.approval_date%TYPE 		default sysdate,
        approval_ip      in cr_news.approval_ip%TYPE 		default null, 
        live_revision_p  in varchar2 default 't'
    );



    function status (
        publish_date     in cr_revisions.publish_date%TYPE,
        archive_date     in cr_news.archive_date%TYPE
    ) return varchar2;


    function name (
	news_id in cr_news.news_id%TYPE
    ) return varchar2;   


    --  
    -- API for revisions: e.g. when the news admin wants to revise a news item
    --
    function revision_new (
        item_id                 in cr_items.item_id%TYPE,       
        --
        publish_date            in cr_revisions.publish_date%TYPE    default null,
        text                    in varchar2                   default null,
        title                   in cr_revisions.title%TYPE,
        --
        -- here goes the revision log
        description             in cr_revisions.description%TYPE,
        --
        mime_type               in cr_revisions.mime_type%TYPE 	     default 'text/plain',
        package_id              in cr_news.package_id%TYPE 	     default null,        
        archive_date            in cr_news.archive_date%TYPE         default null,
        approval_user           in cr_news.approval_user%TYPE        default null,
        approval_date           in cr_news.approval_date%TYPE        default null,
        approval_ip             in cr_news.approval_ip%TYPE          default null,      
        --
        creation_date           in acs_objects.creation_date%TYPE    default sysdate,
        creation_ip             in acs_objects.creation_ip%TYPE      default null,           
        creation_user           in acs_objects.creation_user%TYPE    default null,
        --
        make_active_revision_p  in varchar2 default 'f'
    ) return cr_revisions.revision_id%TYPE;


    procedure revision_delete (
       revision_id in cr_revisions.revision_id%TYPE
    );


    procedure revision_set_active (
       revision_id in cr_revisions.revision_id%TYPE
    );

    procedure clone (
        new_package_id          in cr_news.package_id%TYPE 	  default null,
        old_package_id          in cr_news.package_id%TYPE 	  default null
    );

end news;
/
show errors



create or replace package body news
    as
    function new (
        item_id                 in cr_items.item_id%TYPE             default null,
        --
        locale                  in cr_items.locale%TYPE              default null, 
        --
        publish_date            in cr_revisions.publish_date%TYPE    default null,
        text                    in varchar2                          default null,
        nls_language            in cr_revisions.nls_language%TYPE    default null,
        title                   in cr_revisions.title%TYPE           default null,
        mime_type               in cr_revisions.mime_type%TYPE       default 
	                					     'text/plain',
        --
        package_id              in cr_news.package_id%TYPE           default null,      
        archive_date            in cr_news.archive_date%TYPE         default null,
        approval_user           in cr_news.approval_user%TYPE        default null,
        approval_date           in cr_news.approval_date%TYPE        default null,
        approval_ip             in cr_news.approval_ip%TYPE          default null,      
        --
        relation_tag            in cr_child_rels.relation_tag%TYPE   default null,
        --
        item_subtype            in acs_object_types.object_type%TYPE default 
                                                                     'content_revision',
        content_type            in acs_object_types.object_type%TYPE default 'news',
        creation_date           in acs_objects.creation_date%TYPE    default sysdate,
        creation_ip             in acs_objects.creation_ip%TYPE      default null,
        creation_user           in acs_objects.creation_user%TYPE    default null,
        --
        is_live_p               in varchar2                          default 'f'
    ) return cr_news.news_id%TYPE
    is
        v_news_id         integer;
        v_item_id         integer;
        v_id              integer;
        v_revision_id     integer;
        v_parent_id       integer;
        v_name            varchar2(200);
        v_log_string      varchar2(400);
    begin
        select content_item.get_id('news') 
        into   v_parent_id 
        from   dual;    
        --
        -- this will be used for 2xClick protection
        if item_id is null then
            select acs_object_id_seq.nextval 
            into   v_id 
            from   dual;
        else 
            v_id := item_id;
        end if; 
        --
        select 'news' || to_char(sysdate,'YYYYMMDD') || v_id 
        into   v_name 
        from   dual;    
        -- 
        v_log_string := 'initial submission'; 
        -- 
        v_item_id := content_item.new(
            item_id       => v_id,
            name          => v_name,
            parent_id     => v_parent_id,
            context_id    => package_id,
            locale        => locale,
            item_subtype  => item_subtype,
            content_type  => content_type,
            mime_type     => mime_type,
            nls_language  => nls_language,
            relation_tag  => relation_tag,
            creation_date => creation_date,
            creation_ip   => creation_ip,        
            creation_user => creation_user
        );
        v_revision_id := content_revision.new(
            title         => title,
            description   => v_log_string,
            publish_date  => publish_date,
            mime_type     => mime_type,
            nls_language  => nls_language,
            text          => text,
            item_id       => v_item_id,
            creation_date => creation_date,
            creation_ip   => creation_ip,
            creation_user => creation_user
        );
        insert into cr_news 
            (news_id, 
             package_id, 
             archive_date,
             approval_user, 
             approval_date, 
             approval_ip)
        values
            (v_revision_id, 
             package_id, 
             archive_date,
             approval_user, 
             approval_date, 
             approval_ip);
        -- make this revision live when immediately approved
        if is_live_p = 't' then
	    update 
                cr_items
            set
                live_revision = v_revision_id,
                publish_status = 'ready'
            where 
                item_id = v_item_id;
        end if;
        v_news_id := v_revision_id;
        return v_news_id;
    end new;


    -- deletes a news item along with all its revisions and possibnle attachements
    procedure del (
        item_id in cr_items.item_id%TYPE
    ) is
    v_item_id   cr_items.item_id%TYPE;

    cursor comment_cursor IS
        select message_id 
        from   acs_messages am, acs_objects ao
	where  am.message_id = ao.object_id
        and    ao.context_id = v_item_id;

    begin
    v_item_id := news.del.item_id;
	dbms_output.put_line('Deleting associated comments...');
	-- delete acs_messages, images, comments to news item
	for v_cm in  comment_cursor loop
	    -- images
	    delete from images
        	where image_id in (select latest_revision
                                   from cr_items 
                                   where parent_id = v_cm.message_id);
	    acs_message.del(v_cm.message_id);
            delete from general_comments
		where comment_id = v_cm.message_id;	 
        end loop;
        delete from cr_news 
        where news_id in (select revision_id 
                          from   cr_revisions 
                          where  item_id = v_item_id);
        content_item.del(v_item_id);
    end del;


    -- (re)-publish a news item out of the archive by nulling the archive_date
    -- this only applies to the currently active revision
    procedure make_permanent (
        item_id in cr_items.item_id%TYPE
     )
    is
    begin
        update cr_news
        set    archive_date = null
        where  news_id = content_item.get_live_revision(news.make_permanent.item_id);
    end make_permanent;


    -- archive a news item
    -- this only applies to the currently active revision
    procedure archive (
        item_id in cr_items.item_id%TYPE,
        archive_date in cr_news.archive_date%TYPE default sysdate       
    )
    is
    begin
        update cr_news  
        set    archive_date = news.archive.archive_date
        where  news_id = content_item.get_live_revision(news.archive.item_id);
    end archive;

  
    -- approve/unapprove a specific revision
    -- approving a revision makes it also the active revision
    procedure set_approve(  
        revision_id      in cr_revisions.revision_id%TYPE,       
	approve_p        in varchar2 default 't',  
        publish_date     in cr_revisions.publish_date%TYPE default null,
        archive_date     in cr_news.archive_date%TYPE default null,
        approval_user    in cr_news.approval_user%TYPE default null,
        approval_date    in cr_news.approval_date%TYPE default sysdate,
        approval_ip      in cr_news.approval_ip%TYPE default null, 
        live_revision_p  in varchar2 default 't'
    )
    is
        v_item_id cr_items.item_id%TYPE;
    begin
        select item_id into v_item_id 
        from   cr_revisions 
        where  revision_id = news.set_approve.revision_id;
        -- unapprove an revision (does not mean to knock out active revision)
        if news.set_approve.approve_p = 'f' then
            update  cr_news 
            set     approval_date = null,
                    approval_user = null,
                    approval_ip   = null,
                    archive_date  = null
            where   news_id = news.set_approve.revision_id;
            --
            update  cr_revisions
            set     publish_date = null
            where   revision_id  = news.set_approve.revision_id;
        else
        -- approve a revision
            update  cr_revisions
            set     publish_date  = news.set_approve.publish_date
            where   revision_id   = news.set_approve.revision_id;
            --  
            update  cr_news 
            set archive_date  = news.set_approve.archive_date,
                approval_date = news.set_approve.approval_date,
                approval_user = news.set_approve.approval_user,
                approval_ip   = news.set_approve.approval_ip
            where news_id     = news.set_approve.revision_id;
            -- 
            -- cannot use content_item.set_live_revision because it sets publish_date to sysdate
            if news.set_approve.live_revision_p = 't' then
                update  cr_items
                set     live_revision = news.set_approve.revision_id,
                        publish_status = 'ready'
                where   item_id = v_item_id;
            end if;
            --
        end if;    
    end set_approve;



    -- the status function returns information on the puplish or archive status
    -- it does not make any checks on the order of publish_date and archive_date
    function status (
        publish_date     in cr_revisions.publish_date%TYPE,
        archive_date     in cr_news.archive_date%TYPE
    ) return varchar2
    is
    begin

        if publish_date is not null then
            if publish_date > sysdate  then
                -- to be published (2 cases)
                if archive_date is null then 
                    return 'going_live_no_archive';
                else 
                    return 'going_live_with_archive';
                end if;  
            else
                -- already released or even archived (3 cases)
                if archive_date is null then
                     return 'published_no_archive';
                else
                    if archive_date - sysdate > 0 then
                        return 'published_with_archive';
                    else 
                        return 'archived';
                    end if;
                 end if;
            end if;     
        else 
            return 'unapproved';
        end if;
    end status;


    function name (
	news_id in cr_news.news_id%TYPE
    ) return varchar2
    is
        news_title varchar2(1000);
    begin
        select title 
	into news_title
        from cr_revisions
        where revision_id = news.name.news_id;

        return news_title;
    end name;
    

    -- 
    -- API for Revision management
    -- 
    function revision_new (
        item_id                 in cr_items.item_id%TYPE,       
        --
        publish_date            in cr_revisions.publish_date%TYPE  	default null,
        text                    in varchar2                             default null,
        title                   in cr_revisions.title%TYPE,
        --
        -- here goes the revision log
        description             in cr_revisions.description%TYPE,
        --
        mime_type               in cr_revisions.mime_type%TYPE 		default 'text/plain',
        package_id              in cr_news.package_id%TYPE 		default null,        
        archive_date            in cr_news.archive_date%TYPE 		default null,
        approval_user           in cr_news.approval_user%TYPE 		default null,
        approval_date           in cr_news.approval_date%TYPE 		default null,
        approval_ip             in cr_news.approval_ip%TYPE   		default null,      
        --
        creation_date           in acs_objects.creation_date%TYPE 	default sysdate,
        creation_ip             in acs_objects.creation_ip%TYPE 	default null,           
        creation_user           in acs_objects.creation_user%TYPE 	default null,
        --
        make_active_revision_p  in varchar2 default 'f'
    ) return cr_revisions.revision_id%TYPE
    is  
        v_revision_id    integer;
    begin
        -- create revision
        v_revision_id := content_revision.new(
            title         => title,
            description   => description,
            publish_date  => publish_date,
            mime_type     => mime_type,
            text          => text,
            item_id       => item_id,
            creation_date => creation_date,
            creation_user => creation_user,
            creation_ip   => creation_ip
        );
        -- create new news entry with new revision
        insert into cr_news
            (news_id, 
             package_id,
             archive_date, 
             approval_user, 
             approval_date, 
             approval_ip)
        values
            (v_revision_id, 
             package_id,
             archive_date, 
             approval_user, 
             approval_date,
             approval_ip);
        -- make active revision if indicated
        if make_active_revision_p = 't' then
            news.revision_set_active(v_revision_id);
        end if;
        return v_revision_id;
    end revision_new;



    procedure revision_set_active   (
        revision_id in cr_revisions.revision_id%TYPE
    )
    is
        v_news_item_p char;
        -- could be used to check if really a 'news' item
    begin
        update	
            cr_items
        set
            live_revision = news.revision_set_active.revision_id,
            publish_status = 'ready'
        where
	    item_id = (select
                           item_id
                       from
                           cr_revisions
                       where
                           revision_id = news.revision_set_active.revision_id);
    end revision_set_active; 


    procedure clone   (
        new_package_id    in cr_news.package_id%TYPE    default null,
        old_package_id    in cr_news.package_id%TYPE    default null
    )
    is
      new_news_id integer;
    begin
        for one_news in (select
                            publish_date,
                            content.blob_to_string(cr.content) as text,
                            cr.nls_language,
                            cr.title as title,
                            cr.mime_type,
                            cn.package_id,
                            archive_date,
                            approval_user,
                            approval_date,
                            approval_ip,
                            ao.creation_date,
                            ao.creation_ip,
                            ao.creation_user
                        from 
                            cr_items ci, 
                            cr_revisions cr,
                            cr_news cn,
                            acs_objects ao
                        where
                            (ci.item_id = cr.item_id
                            and ci.live_revision = cr.revision_id 
                            and cr.revision_id = cn.news_id 
                            and cr.revision_id = ao.object_id)
                        or (ci.live_revision is null 
                            and ci.item_id = cr.item_id
                            and cr.revision_id = content_item.get_latest_revision(ci.item_id)
                            and cr.revision_id = cn.news_id
                            and cr.revision_id = ao.object_id))
        loop

            new_news_id := news.new(
                publish_date      => one_news.publish_date,
                text              => one_news.text,
                nls_language      => one_news.nls_language,
                title             => one_news.title,
                mime_type         => one_news.mime_type,
                package_id        => news.clone.new_package_id,
                archive_date      => one_news.archive_date,
                approval_user     => one_news.approval_user,
                approval_date     => one_news.approval_date,
                approval_ip       => one_news.approval_ip,
                creation_date     => one_news.creation_date,
                creation_ip       => one_news.creation_ip,
                creation_user     => one_news.creation_user
            );

        end loop;
    end clone;

    -- currently not used, because we want to audit revisions
    procedure revision_delete (
        revision_id in cr_revisions.revision_id%TYPE
    )
    is
    begin
    -- delete from cr_news table
        delete from cr_news
        where  news_id = news.revision_delete.revision_id;
        -- delete revision
        content_revision.del(
            revision_id => news.revision_delete.revision_id
        );
    end revision_delete;

end news;
/
show errors