Commit b1277875 authored by Frank Bergmann's avatar Frank Bergmann

- Added missing OpenACS 5.9.1 upgrade scripts

parent a907b415
--
-- 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',
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_message_id_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
--
-- Some old installations (e.g. openacs.org) have non-stub
-- acs_message__new/16 versions (in versions post 2004, this is just a
-- wrapper for acs_message__new/17. So, delete the old function,
-- replace it with the newer owe with a default value for package_id.
--
DROP FUNCTION IF EXISTS acs_message__new(integer, integer, timestamp with time zone, integer, character varying, character varying, character varying, character varying, text, integer, integer, integer, integer, character varying, character varying, boolean );
--
-- procedure acs_message__new/17 (callable with 16 or 17 args)
--
CREATE OR REPLACE FUNCTION acs_message__new(
p_message_id integer, --default null,
p_reply_to integer, --default null,
p_sent_date timestamptz, --default sysdate,
p_sender integer, --default null,
p_rfc822_id varchar, --default null,
p_title varchar, --default null,
p_description varchar, --default null,
p_mime_type varchar, --default 'text/plain',
p_text text, --default null,
p_data integer, --default null,
p_parent_id integer, --default 0,
p_context_id integer,
p_creation_user integer, --default null,
p_creation_ip varchar, --default null,
p_object_type varchar, --default 'acs_message',
p_is_live boolean, --default 't'
p_package_id integer default null
) RETURNS integer AS $$
DECLARE
p_creation_date timestamptz := current_timestamp; -- alias for $13 --default sysdate,
v_message_id acs_messages.message_id%TYPE;
v_rfc822_id acs_messages.rfc822_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
v_system_url varchar;
v_domain_name varchar;
v_idx integer;
BEGIN
-- generate a message id now so we can get an rfc822 message-id
if p_message_id is null then
select nextval('t_acs_object_id_seq') into v_message_id;
else
v_message_id := p_message_id;
end if;
-- need to make this mandatory also - jg
-- this needs to be fixed up, but Oracle doesn't give us a way
-- to get the FQDN
-- vk: get SystemURL parameter and use it to extract domain name
select apm__get_value(package_id, 'SystemURL') into v_system_url
from apm_packages where package_key='acs-kernel';
v_idx := position('http://' in v_system_url);
v_domain_name := trim (substr(v_system_url, v_idx + 7));
if p_rfc822_id is null then
v_rfc822_id := current_date || '.' || v_message_id || '@' ||
v_domain_name || '.hate';
else
v_rfc822_id := p_rfc822_id;
end if;
v_message_id := content_item__new (
v_rfc822_id, -- 1 name
p_parent_id, -- 2 parent_id
p_message_id, -- 3 item_id
null, -- 4 locale
p_creation_date, -- 5 creation_date
p_creation_user, -- 6 creation_user
p_context_id, -- 7 context_id
p_creation_ip, -- 8 creation_ip
p_object_type, -- 9 item_subtype
'acs_message_revision', -- 10 content_type
null, -- 11 title
null, -- 12 description
'text/plain', -- 13 mime_type
null, -- 14 nls_language
null, -- 15 text
'text', -- 16 storage_type
p_package_id -- 17 package_id
);
insert into acs_messages
(message_id, reply_to, sent_date, sender, rfc822_id)
values
(v_message_id, p_reply_to, p_sent_date, p_sender, v_rfc822_id);
-- create an initial revision for the new message
v_revision_id := acs_message__edit (
v_message_id, -- message_id
p_title, -- title
p_description, -- description
p_mime_type, -- mime_type
p_text, -- text
p_data, -- data
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
p_is_live -- is_live
);
return v_message_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION acs_message__new(
p_message_id integer, --default null,
p_reply_to integer, --default null,
p_sent_date timestamptz, --default sysdate,
p_sender integer, --default null,
p_rfc822_id varchar, --default null,
p_title varchar, --default null,
p_description varchar, --default null,
p_mime_type varchar, --default 'text/plain',
p_text text, --default null,
p_data integer, --default null,
p_parent_id integer, --default 0,
p_context_id integer,
p_creation_user integer, --default null,
p_creation_ip varchar, --default null,
p_object_type varchar, --default 'acs_message',
p_is_live boolean, --default 't'
p_package_id integer default null
) RETURNS integer AS $$
DECLARE
p_creation_date timestamptz := current_timestamp; -- alias for $13 --default sysdate,
v_message_id acs_messages.message_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
BEGIN
-- -- generate a message id now so we can get an rfc822 message-id
-- if p_message_id is null then
-- select nextval('t_acs_object_id_seq') into v_message_id;
-- else
-- v_message_id := p_message_id;
-- end if;
-- -- need to make this mandatory also - jg
-- -- this needs to be fixed up, but Oracle doesn't give us a way
-- -- to get the FQDN
-- -- vk: get SystemURL parameter and use it to extract domain name
-- select apm__get_value(package_id, 'SystemURL') into v_system_url
-- from apm_packages where package_key='acs-kernel';
-- v_idx := position('http://' in v_system_url);
-- v_domain_name := trim (substr(v_system_url, v_idx + 7));
-- if p_rfc822_id is null then
-- v_rfc822_id := current_date || '.' || v_message_id || '@' ||
-- v_domain_name || '.hate';
-- else
-- v_rfc822_id := p_rfc822_id;
-- end if;
-- Antonio Pisano 2016-09-20
-- rfc822_id MUST come from the tcl, no more
-- sql tricks to retrieve one if missing.
-- Motivations:
-- 1) duplication. We have same logics in acs_mail_lite::generate_message_id
-- 2) what if SystemURL is https?
-- 3) empty SystemURL would break General Comments
if p_rfc822_id is null then
RAISE null_value_not_allowed;
end if;
v_message_id := content_item__new (
p_rfc822_id, -- 1 name
p_parent_id, -- 2 parent_id
p_message_id, -- 3 item_id
null, -- 4 locale
p_creation_date, -- 5 creation_date
p_creation_user, -- 6 creation_user
p_context_id, -- 7 context_id
p_creation_ip, -- 8 creation_ip
p_object_type, -- 9 item_subtype
'acs_message_revision', -- 10 content_type
null, -- 11 title
null, -- 12 description
'text/plain', -- 13 mime_type
null, -- 14 nls_language
null, -- 15 text
'text', -- 16 storage_type
p_package_id -- 17 package_id
);
insert into acs_messages
(message_id, reply_to, sent_date, sender, rfc822_id)
values
(v_message_id, p_reply_to, p_sent_date, p_sender, p_rfc822_id);
-- create an initial revision for the new message
v_revision_id := acs_message__edit (
v_message_id, -- message_id
p_title, -- title
p_description, -- description
p_mime_type, -- mime_type
p_text, -- text
p_data, -- data
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
p_is_live -- is_live
);
return v_message_id;
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_message__edit/10
--
CREATE OR REPLACE FUNCTION acs_message__edit(
p_message_id integer,
p_title varchar, -- default null
p_description varchar, -- default null
p_mime_type varchar, -- default 'text/plain'
p_text text, -- default null
p_data integer, -- default null
p_creation_date timestamptz, -- default sysdate
p_creation_user integer, -- default null
p_creation_ip varchar, -- default null
p_is_live boolean -- default 't'
) RETURNS integer AS $$
DECLARE
v_revision_id cr_revisions.revision_id%TYPE;
BEGIN
-- create a new revision using whichever call is appropriate
if p_data is not null then
-- need to take care of blob?
v_revision_id := content_revision__new (
p_title, -- title
p_description, -- description
now(), -- publish_date
p_mime_type, -- mime_type
null, -- nls_language
p_data, -- data
p_message_id, -- item_id
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip -- creation_ip
);
else if p_title is not null or p_text is not null then
v_revision_id := content_revision__new (
p_title, -- title
p_description, -- description
now(), -- publish_date
p_mime_type, -- mime_type
null, -- nls_language
p_text, -- text
p_message_id, -- item_id
null, -- revision_id
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
null, -- content_length
null -- package_id
);
end if;
end if;
-- test for auto approval of revision
if p_is_live then
perform content_item__set_live_revision(v_revision_id);
end if;
return v_revision_id;
END;
$$ LANGUAGE plpgsql;
DROP FUNCTION IF EXISTS acs_message__new_file(integer,integer,character varying,character varying,text,character varying,integer,timestamp with time zone,integer,character varying,boolean,character varying,integer);
DROP FUNCTION IF EXISTS acs_message__new_file(integer,integer,character varying,character varying,text,character varying,integer,timestamp with time zone,integer,character varying,boolean,character varying);
CREATE OR REPLACE FUNCTION acs_message__new_file(
p_message_id integer,
p_file_id integer, -- default null
p_file_name varchar,
p_title varchar, -- default null
p_description text, -- default null
p_mime_type varchar, -- default 'text/plain'
p_data integer, -- default null
p_creation_date timestamptz, -- default sysdate
p_creation_user integer, -- default null
p_creation_ip varchar, -- default null
p_is_live boolean, -- default 't'
p_storage_type cr_items.storage_type%TYPE, -- default 'file'
p_package_id integer default null
) RETURNS integer AS $$
DECLARE
v_file_id cr_items.item_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
BEGIN
v_file_id := content_item__new (
p_file_name, -- name
p_message_id, -- parent_id
p_file_id, -- item_id
null, -- locale
p_creation_date, -- creation_date
p_creation_user, -- creation_user
null, -- context_id
p_creation_ip, -- creation_ip
'content_item', -- item_subtype
'content_revision', -- content_type
null, -- title
null, -- description
'text/plain', -- mime_type
null, -- nls_language
null, -- text
null, -- data
null, -- relation_tag
false, -- is_live
p_storage_type, -- storage_type
p_package_id, -- package_id
true -- with_child_rels
);
-- create an initial revision for the new attachment
v_revision_id := acs_message__edit_file (
v_file_id, -- file_id
p_title, -- title
p_description, -- description
p_mime_type, -- mime_type
p_data, -- data
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
p_is_live -- is_live
);
return v_file_id;
END;
$$ LANGUAGE plpgsql;
DROP FUNCTION IF EXISTS acs_message__new_image(integer,integer,character varying,character varying,text,character varying,integer,integer,integer,timestamp with time zone,integer,character varying,boolean,character varying);
DROP FUNCTION IF EXISTS acs_message__new_image(integer,integer,character varying,character varying,text,character varying,integer,integer,integer,timestamp with time zone,integer,character varying,boolean,character varying,integer);
--
-- procedure acs_message__new_image/15
--
CREATE OR REPLACE FUNCTION acs_message__new_image(
p_message_id integer,
p_image_id integer, -- default null
p_file_name varchar,
p_title varchar, -- default null
p_description text, -- default null
p_mime_type varchar, -- default 'text/plain'
p_data integer, -- default null
p_width integer, -- default null
p_height integer, -- default null
p_creation_date timestamptz, -- default sysdate
p_creation_user integer, -- default null
p_creation_ip varchar, -- default null
p_is_live boolean, -- default 't'
p_storage_type cr_items.storage_type%TYPE, -- default 'file'
p_package_id integer default null
) RETURNS integer AS $$
DECLARE
v_image_id cr_items.item_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
BEGIN
v_image_id := content_item__new (
p_file_name, -- name
p_message_id, -- parent_id
p_image_id, -- item_id
null, -- locale
p_creation_date, -- creation_date
p_creation_user, -- creation_user
null, -- context_id
p_creation_ip, -- creation_ip
'content_item', -- item_subtype
'content_revision', -- content_type
null, -- title
null, -- description
'text/plain', -- mime_type
null, -- nls_language
null, -- text
p_storage_type, -- storage_type
p_package_id -- package_id
);
-- create an initial revision for the new attachment
v_revision_id := acs_message__edit_image (
v_image_id, -- image_id
p_title, -- title
p_description, -- description
p_mime_type, -- mime_type
p_data, -- data
p_width, -- width
p_height, -- height
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
p_is_live -- is_live
);
return v_image_id;
END;
$$ LANGUAGE plpgsql;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment