Commit c7ee67b1 authored by Frank Bergmann's avatar Frank Bergmann

Initial Import

parents
Pipeline #86 failed with stages
<?xml version="1.0"?>
<!-- Generated by the OpenACS Package Manager -->
<package key="acs-messaging" url="http://openacs.org/repository/apm/packages/acs-messaging/" type="apm_service">
<package-name>Messaging</package-name>
<pretty-plural>Messaging Services</pretty-plural>
<initial-install-p>t</initial-install-p>
<singleton-p>t</singleton-p>
<version name="5.1.5" url="http://openacs.org/repository/download/apm/acs-messaging-5.1.5.apm">
<owner url="mailto:akk+@cs.cmu.edu">Anukul Kapoor</owner>
<owner url="mailto:prevost@maya.com">John Prevost</owner>
<owner url="mailto:vinod@kurup.com">Vinod Kurup</owner>
<summary>General messaging for bboard and general comments.</summary>
<release-date>2004-02-28</release-date>
<maturity>3</maturity>
<vendor url="http://openacs.org">OpenACS</vendor>
<description format="text/html">Provides generic message services, with email sending. acs-mail-lite and notifications are the
prefered packages for delivering this functionality and it is anticipated that this package will ultimately be deprecated.</description>
<provides url="acs-messaging" version="5.1.4"/>
<requires url="acs-content-repository" version="5.0.0"/>
<requires url="acs-kernel" version="5.0.0"/>
<callbacks>
</callbacks>
<parameters>
<!-- No version parameters -->
</parameters>
</version>
</package>
--
-- packages/acs-messaging/sql/acs-messaging-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2000-08-27
-- @cvs-id $Id$
--
set feedback off
-- Object System Metadata ----------------------------------------------
begin
acs_object_type.create_type (
supertype => 'content_item',
object_type => 'acs_message',
pretty_name => 'Message',
pretty_plural => 'Messages',
table_name => 'ACS_MESSAGES',
id_column => 'MESSAGE_ID',
name_method => 'ACS_MESSAGE.NAME'
);
acs_object_type.create_type (
supertype => 'content_revision',
object_type => 'acs_message_revision',
pretty_name => 'Message Revision',
pretty_plural => 'Message Revisions',
table_name => 'CR_REVISIONS',
id_column => 'REVISION_ID',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
-- Raw Tables and Comments ---------------------------------------------
create table acs_messages ( -- extends cr_items
message_id integer
constraint acs_messages_message_id_fk
references cr_items (item_id) on delete cascade
constraint acs_messages_pk
primary key,
-- we will need to find a way to make reply_to go to 0 instead of null
-- to improve scalability
reply_to integer
constraint acs_messages_reply_to_fk
references acs_messages (message_id) on delete set null,
sent_date date
constraint acs_messages_sent_date_nn
not null,
sender integer
constraint acs_messages_sender_fk
references parties (party_id),
rfc822_id varchar2(250)
constraint acs_messages_rfc822_id_nn
not null
constraint acs_messages_rfc822_id_un
unique
);
create index acs_messages_reply_to_idx on acs_messages (reply_to);
create index acs_messages_sender_idx on acs_messages (sender);
comment on table acs_messages is '
A generic message which may be attached to any object in the system.
';
comment on column acs_messages.reply_to is '
Pointer to a message this message contains a reply to, for threading.
';
comment on column acs_messages.sent_date is '
The date the message was sent (may be distinct from when it was created
or published in the system.)
';
comment on column acs_messages.sender is '
The person who sent the message (may be distinct from the person who
entered the message in the system.)
';
comment on column acs_messages.rfc822_id is '
The RFC822 message-id of this message, for sending email.
';
create table acs_messages_outgoing (
message_id integer
constraint amo_message_id_fk
references acs_messages (message_id) on delete cascade,
to_address varchar2(1000)
constraint amo_to_address_nn
not null,
grouping_id integer,
wait_until date
constraint amo_wait_until_nn not null,
constraint acs_messages_outgoing_pk
primary key (message_id, to_address)
);
comment on table acs_messages_outgoing is '
Set of messages to be sent to parties. It is assumed that sending a
message either queues it in a real MTA or fails, so no information about
what''s been tried how many times is kept.
';
comment on column acs_messages_outgoing.to_address is '
The email address to send this message to. Note that this will
probably become a party_id again once upgrading a party to a user
is possible.
';
comment on column acs_messages_outgoing.grouping_id is '
This identifier is used to group sets of messages to be sent as
digests. When a message is about to be sent, any other messages
with the same grouping_id will be put together with it in a
digest. It is recommended but not required that an object id is
used. Bboard, for example, might use the forum id that the user''s
subscribed to. For instant (non-digest) updates, it would be
appropriate to use null, which is never equal to anything else.
';
comment on column acs_messages_outgoing.wait_until is '
Don''t schedule a send until after this date. If another message with
the same grouping ID is scheduled to be sent, then this message may be
sent at the same time. (So, for example, daily digests would be
achieved by setting the grouping_id to the same value, and the wait_until
value to the end of the current day. As soon as one message in the group
is to be sent, all will be sent.)
';
@@ acs-messaging-views
@@ acs-messaging-packages
set feedback on
--
-- packages/acs-messaging/sql/acs-messaging-drop.sql
--
-- @author akk@arsdigita.com
-- @creation-date 2000-08-31
-- @cvs-id $Id$
--
begin
acs_object_type.drop_type('acs_message');
end;
/
show errors
drop package acs_message;
drop table acs_messages_outgoing;
drop view acs_messages_all;
drop table acs_messages;
This diff is collapsed.
--
-- packages/acs-messaging/sql/acs-messaging-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2000-11-15
-- @cvs-id $Id$
--
create or replace view acs_messages_all as
select m.message_id, m.reply_to, m.sent_date, m.sender, m.rfc822_id,
r.revision_id, r.title, r.mime_type, r.content
from cr_items i, cr_revisions r, acs_messages m
where i.item_id = m.message_id and r.revision_id = i.live_revision;
create or replace view acs_messages_latest as
select m.message_id, m.reply_to, m.sent_date, m.sender, m.rfc822_id,
r.revision_id, r.title, r.mime_type, r.content
from cr_items i, cr_revisions r, acs_messages m
where i.item_id = m.message_id
and r.revision_id = content_item.get_latest_revision(i.item_id);
--
-- acs-messaging sql/upgrade-4.0-4.0.1a.sql
--
-- @author jmp@arsdigita.com
-- @creation-date 2000-11-03
-- @cvs-id $Id$
--
alter table acs_messages add (
sent_date date
constraint acs_messages_sent_date_nn
not null
disable,
sender integer
constraint acs_messages_sender_fk
references parties (party_id)
disable,
rfc822_id varchar2(250)
constraint acs_messages_rfc822_id_nn
not null
disable
constraint acs_messages_rfc822_id_un
unique
disable
);
create table acs_mess_up (
id integer primary key,
sent_date date,
sender integer,
rfc822_id varchar2(250)
);
insert into acs_mess_up
select m.message_id,
r.publish_date as sent_date,
o.creation_user as sender,
(sysdate || '.' || message_id || '@'
|| utl_inaddr.get_host_name||'.hate') as rfc822_id
from acs_objects o, cr_items i, cr_revisions r, acs_messages m
where m.message_id = i.item_id
and m.message_id = o.object_id
and r.revision_id = i.live_revision;
update acs_messages
set sent_date = (select sent_date from acs_mess_up where id = message_id),
sender = (select sender from acs_mess_up where id = message_id),
rfc822_id = (select rfc822_id from acs_mess_up where id = message_id);
drop table acs_mess_up;
alter table acs_messages modify constraint acs_messages_sent_date_nn enable;
alter table acs_messages modify constraint acs_messages_sender_fk enable;
alter table acs_messages modify constraint acs_messages_rfc822_id_nn enable;
alter table acs_messages modify constraint acs_messages_rfc822_id_un enable;
create or replace view acs_messages_all as
select m.message_id, m.reply_to, m.sent_date, m.sender, m.rfc822_id,
r.title, r.mime_type, r.content, o.context_id
from acs_objects o, cr_items i, cr_revisions r, acs_messages m
where o.object_id = m.message_id and i.item_id = m.message_id
and r.revision_id = i.live_revision;
create table acs_messages_outgoing (
message_id integer
constraint amo_message_id_fk
references acs_messages (message_id) on delete cascade,
recipient_id integer
constraint amo_recipient_id_fk
references parties (party_id),
grouping_id integer,
wait_until date not null,
constraint acs_messages_outgoing_pk
primary key (message_id, recipient_id)
);
comment on column acs_messages_outgoing.grouping_id is '
This identifier is used to group sets of messages to be sent as
digests. When a message is about to be sent, any other messages
with the same grouping_id will be put together with it in a
digest. It is recommended but not required that an object id is
used. Bboard, for example, might use the forum id that the user''s
subscribed to. For instant (non-digest) updates, it would be
appropriate to use null, which is never equal to anything else.
';
comment on column acs_messages_outgoing.wait_until is '
Don''t schedule a send until after this date. If another message with
the same grouping ID is scheduled to be sent, then this message may be
sent at the same time. (So, for example, daily digests would be
achieved by setting the grouping_id to the same value, and the wait_until
value to the end of the current day. As soon as one message in the group
is to be sent, all will be sent.)
';
create or replace package acs_message
as
function new (
message_id in acs_messages.message_id%TYPE default null,
reply_to in acs_messages.reply_to%TYPE default null,
sent_date in acs_messages.sent_date%TYPE default sysdate,
sender in acs_messages.sender%TYPE default null,
rfc822_id in acs_messages.rfc822_id%TYPE default null,
title in cr_revisions.title%TYPE default null,
mime_type in cr_revisions.mime_type%TYPE default 'text/plain',
text in varchar2 default null,
data in cr_revisions.content%TYPE default null,
context_id in acs_objects.context_id%TYPE,
creation_date in acs_objects.creation_date%TYPE default sysdate,
creation_user in acs_objects.creation_user%TYPE default null,
creation_ip in acs_objects.creation_ip%TYPE default null,
object_type in acs_objects.object_type%TYPE default 'acs_message'
) return acs_objects.object_id%TYPE;
procedure delete (
message_id in acs_messages.message_id%TYPE
);
function message_p (
message_id in acs_messages.message_id%TYPE
) return char;
procedure send (
message_id in acs_messages.message_id%TYPE,
recipient_id in parties.party_id%TYPE,
grouping_id in integer default NULL,
wait_until in date default SYSDATE
);
end acs_message;
/
show errors
create or replace package body acs_message
as
function new (
message_id in acs_messages.message_id%TYPE default null,
reply_to in acs_messages.reply_to%TYPE default null,
sent_date in acs_messages.sent_date%TYPE default sysdate,
sender in acs_messages.sender%TYPE default null,
rfc822_id in acs_messages.rfc822_id%TYPE default null,
title in cr_revisions.title%TYPE default null,
mime_type in cr_revisions.mime_type%TYPE default 'text/plain',
text in varchar2 default null,
data in cr_revisions.content%TYPE default null,
context_id in acs_objects.context_id%TYPE,
creation_date in acs_objects.creation_date%TYPE default sysdate,
creation_user in acs_objects.creation_user%TYPE default null,
creation_ip in acs_objects.creation_ip%TYPE default null,
object_type in acs_objects.object_type%TYPE default 'acs_message'
) return acs_objects.object_id%TYPE
is
v_message_id acs_messages.message_id%TYPE;
v_rfc822_id acs_messages.rfc822_id%TYPE;
v_name cr_items.name%TYPE;
begin
if message_id is null then
select acs_object_id_seq.nextval into v_message_id from dual;
else
v_message_id := message_id;
end if;
if rfc822_id is null then
v_rfc822_id := sysdate || '.' || v_message_id || '@' ||
utl_inaddr.get_host_name || '.hate';
else
v_rfc822_id := rfc822_id;
end if;
v_name := v_rfc822_id;
v_message_id := content_item.new (
name => v_name,
parent_id => context_id,
item_id => message_id,
creation_date => creation_date,
creation_user => creation_user,
creation_ip => creation_ip,
item_subtype => object_type,
title => title,
mime_type => mime_type,
text => text,
data => data,
is_live => 't'
);
-- I hate you, milkman CR.
-- Fix the broken permissions stuff content_item.new does
update acs_objects set security_inherit_p = 't'
where object_id = v_message_id;
delete from acs_permissions where object_id = v_message_id;
insert into
acs_messages (message_id, reply_to, sent_date, sender, rfc822_id)
values (v_message_id, reply_to, sent_date, sender, v_rfc822_id);
return v_message_id;
end new;
procedure delete (
message_id in acs_messages.message_id%TYPE
)
is
begin
delete from acs_messages
where message_id = acs_message.delete.message_id;
content_item.delete(message_id);
end;
function message_p (
message_id in acs_messages.message_id%TYPE
) return char
is
v_check_message_id char(1);
begin
select decode(count(message_id),0,'f','t') into v_check_message_id
from acs_messages
where message_id = message_p.message_id;
return v_check_message_id;
end message_p;
procedure send (
message_id in acs_messages.message_id%TYPE,
recipient_id in parties.party_id%TYPE,
grouping_id in integer default NULL,
wait_until in date default SYSDATE
)
is
v_wait_until date;
begin
v_wait_until := nvl(wait_until, SYSDATE);
insert into acs_messages_outgoing
(message_id, recipient_id, grouping_id, wait_until)
values
(message_id, recipient_id, grouping_id, nvl(wait_until,SYSDATE));
end;
end acs_message;
/
show errors
--
-- acs-messaging sql/upgrade-4.0.1-4.1.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2001-01-16
-- @cvs-id $Id$
--
-- do all the views and packages in case something changed
@@ acs-messaging-views
@@ acs-messaging-packages
\ No newline at end of file
--
-- acs-messaging sql/upgrade-4.0.1a-4.0.1.sql
--
-- @author jmp@arsdigita.com
-- @creation-date 2000-11-15
-- @cvs-id $Id$
--
begin
acs_object_type.create_type (
supertype => 'content_revision',
object_type => 'acs_message_revision',
pretty_name => 'Message Revision',
pretty_plural => 'Message Revisions',
table_name => 'CR_REVISIONS',
id_column => 'REVISION_ID',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
alter table acs_messages_outgoing add (
to_address varchar2(1000)
constraint amo_to_address_nn
not null
disable
);
update acs_messages_outgoing
set to_address = (select email from parties where party_id = recipient_id);
alter table acs_messages_outgoing
drop constraint acs_messages_outgoing_pk;
alter table acs_messages_outgoing
add constraint acs_messages_outgoing_pk
primary key (message_id, to_address);
alter table acs_messages_outgoing
modify constraint amo_to_address_nn enable;
alter table acs_messages_outgoing
drop column recipient_id;
@@ acs-messaging-views
@@ acs-messaging-packages
set feedback on
This diff is collapsed.
This diff is collapsed.
--
-- packages/acs-messaging/sql/acs-messaging-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @author Jon Griffin <jon@jongriffin.com>
-- @creation-date 2000-08-27
--
-- @cvs-id $Id$
-- updated for OpenACS
-- Object System Metadata ----------------------------------------------
select acs_object_type__create_type (
'acs_message',
'Message',
'Messages',
'content_item',
'ACS_MESSAGES',
'MESSAGE_ID',
null,
'f',
null,
'ACS_MESSAGE.NAME'
);
select acs_object_type__create_type (
'acs_message_revision',
'Message Revision',
'Message Revisions',
'content_revision',
'CR_REVISIONS',
'REVISION_ID',
null,
'f',
null,
'ACS_OBJECT.DEFAULT_NAME'
);
-- Raw Tables and Comments ---------------------------------------------
create table acs_messages ( -- extends cr_items
message_id integer
constraint acs_messages_message_id_fk
references cr_items (item_id) on delete cascade
constraint acs_messages_pk
primary key,
-- we will need to find a way to make reply_to go to 0 instead of null
-- to improve scalability
reply_to integer
constraint acs_messages_reply_to_fk
references acs_messages (message_id) on delete set null,
sent_date timestamptz
constraint acs_messages_sent_date_nn
not null,
sender integer
constraint acs_messages_sender_fk
references parties (party_id),
rfc822_id varchar(250)
constraint acs_messages_rfc822_id_nn
not null
constraint acs_messages_rfc822_id_un
unique,
tree_sortkey varbit
);
create index acs_messages_tree_skey_idx on acs_messages (tree_sortkey);
create index acs_messages_reply_to_idx on acs_messages (reply_to);
create index acs_messages_sender_idx on acs_messages (sender);
create index acs_messages_sent_idx on acs_messages (sent_date);
comment on table acs_messages is '
A generic message which may be attached to any object in the system.
';
comment on column acs_messages.reply_to is '
Pointer to a message this message contains a reply to, for threading.
';
comment on column acs_messages.sent_date is '
The date the message was sent (may be distinct from when it was created
or published in the system.)
';
comment on column acs_messages.sender is '
The person who sent the message (may be distinct from the person who
entered the message in the system.)
';
comment on column acs_messages.rfc822_id is '
The RFC822 message-id of this message, for sending email.
';
-- support for tree queries on acs_messages
create or replace function acs_message_get_tree_sortkey(integer) returns varbit as '
declare
p_message_id alias for $1;
begin
return tree_sortkey from acs_messages where message_id = p_message_id;
end;' language 'plpgsql' stable strict;
create or replace function acs_message_insert_tr () returns opaque as '
declare
v_parent_sk varbit default null;
v_max_value integer;
begin
if new.reply_to is null then
select max(tree_leaf_key_to_int(tree_sortkey)) into v_max_value
from acs_messages
where reply_to is null;
else
select max(tree_leaf_key_to_int(tree_sortkey)) into v_max_value
from acs_messages
where reply_to = new.reply_to;
select tree_sortkey into v_parent_sk
from acs_messages
where message_id = new.reply_to;
end if;
new.tree_sortkey := tree_next_key(v_parent_sk, v_max_value);
return new;
end;' language 'plpgsql';
create trigger acs_message_insert_tr before insert
on acs_messages
for each row
execute procedure acs_message_insert_tr ();
create function acs_message_update_tr () returns opaque as '
declare
v_parent_sk varbit default null;
v_max_value integer;
v_rec record;
clr_keys_p boolean default ''t'';
begin
if new.message_id = old.message_id and
((new.reply_to = old.reply_to) or
(new.reply_to is null and old.reply_to is null)) then
return new;
end if;
for v_rec in select message_id, reply_to
from acs_messages
where tree_sortkey between new.tree_sortkey and tree_right(new.tree_sortkey)
order by tree_sortkey
LOOP
if clr_keys_p then
update acs_messages set tree_sortkey = null
where tree_sortkey between new.tree_sortkey and tree_right(new.tree_sortkey);
clr_keys_p := ''f'';
end if;
select max(tree_leaf_key_to_int(tree_sortkey)) into v_max_value
from acs_messages
where reply_to = v_rec.reply_to;
select tree_sortkey into v_parent_sk
from acs_messages
where message_id = v_rec.reply_to;
update acs_messages
set tree_sortkey = tree_next_key(v_parent_sk, v_max_value)
where message_id = v_rec.message_id;
end LOOP;
return new;
end;' language 'plpgsql';
create trigger acs_message_update_tr after update
on acs_messages
for each row
execute procedure acs_message_update_tr ();
create table acs_messages_outgoing (
message_id integer