Commit 728d6700 authored by Frank Bergmann's avatar Frank Bergmann

Initial Import

parents
<?xml version="1.0"?>
<!-- Generated by the OpenACS Package Manager -->
<package key="acs-mail" url="http://openacs.org/repository/apm/packages/acs-mail/" type="apm_service">
<package-name>Mail</package-name>
<pretty-plural>Mail 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-mail-5.1.5.apm">
<owner url="mailto:vinod@kurup.com">Vinod Kurup</owner>
<owner url="mailto:prevost@maya.com">John Prevost</owner>
<summary>General messaging system, mark II</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. The acs-mail-lite package is the prefered
interface for new packages and it's anticipated that this package will ultimately be deprecated.</description>
<provides url="acs-mail" 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>
#!/usr/bin/perl
#
# @author John Prevost <jmp@arsdigita.com>
# @creation-date 2001-01-16
# @cvs-id $Id$
### DANGER This script is entirely untested, since I don't yet have an Oracle
### DANGER DBI setup available to me. It will be tested once I do.
sub usage () {
print "$0: db_user db_passwd [envelope_from] [envelope_to]\n";
}
################################################################
# Global Definitions
$db_user = shift;
$db_passwd = shift;
$envelope_from = shift || '';
$envelope_to = shift || '';
# Oracle access
$ORACLE_HOME = "/ora8/m01/app/oracle/product/8.1.6";
$ENV{'ORACLE_HOME'} = $ORACLE_HOME;
$ENV{'ORACLE_BASE'} = "/ora8/m01/app/oracle";
$ENV{'ORACLE_SID'} = "ora8";
$db_datasource = 'dbi:Oracle:';
################################################################
use DBI;
use DBD::Oracle qw(:ora_types);
$content_all = '';
$content_no_header = '';
$header_p = 1;
$header_name = undef;
%headers = ();
while (<>) {
$content_all .= $_;
$content_no_header .= $_ if ( !$header_p );
chomp;
if ( $header_p ) {
if ( /^$/ ) {
$header_p = 0;
} elsif ( /^\S+: / ) {
($header_name, $header_content) = /^(\S+): (.*)$/;
$headers{lc $header_name} .= $header_content;
} elsif ( /^\s+/ ) {
$headers{lc $header_name} .= "\n$_";
}
}
}
# Open the database connection.
$dbh = DBI->connect($db_datasrc, $db_user, $db_passwd,
{ RaiseError => 1, AutoCommit => 0 })
|| die "$0: couldn't connect to database: $!";
# This is supposed to make it possible to write large CLOBs
$dbh->{LongReadLen} = 2**20; # 1 MB max message size
$dbh->{LongTruncOk} = 0;
# Create a message body
$h = $dbh->prepare (qq{
declare
-- blob
header_message_id varchar;
header_reply_to varchar;
header_subject varchar;
header_from varchar;
header_to varchar;
-- envelope to
-- envelope from
body_reply_to integer;
body_from integer;
body_date date;
cont_id integer;
body_id integer;
link_id integer;
begin
cont_id := acs_mail_gc_object.new ( creation_user => null );
insert into acs_contents (content_id, content, searchable_p, mime_type)
values (cont_id, ?, 'f', 'text/plain');
header_message_id := ?;
header_reply_to := ?;
header_subject := ?;
header_from := ?;
header_to := ?;
-- try to get the body_reply_to id by selecting on header_message_id
body_reply_to := null;
-- try to get the body_from id by searching on email
body_from := null
-- get the body date by being handed it from perl
body_date := ?;
body_id := acs_mail_body.new (
body_reply_to => body_reply_to,
body_from => body_from,
body_date => body_date,
header_message_id => header_message_id,
header_reply_to => header_reply_to,
header_subject => header_subject,
header_from => header_from,
header_to => header_to,
content_object_id => cont_id
);
link_id := acs_mail_queue_message.new (
body_id => body_id
);
insert into acs_mail_queue_incoming values (link_id, ?, ?);
end;
});
$h->bind_param(1, $content_no_header, { ora_type => ORA_CLOB, ora_field => 'content' });
if (!$h->execute($content_no_header, $headers{'message-id'},
$headers{'in-reply-to'}, $headers{'subject'},
$headers{'from'}, $headers{'to'}, $envelope_from,
$envelope_to)) {
die "$0: unable to open cursor: $!\n" . $dbh->errstr;
}
$h->finish;
$dbh->disconnect;
#!/bin/bash
. /etc/profile
export ORACLE_BASE=/ora8/m01/app/oracle
export ORACLE_HOME=$ORACLE_BASE/product/8.1.6
export PATH=$PATH:$ORACLE_HOME/bin
export LD_LIBRARY_PATH=$ORACLE_HOME/lib:/lib:/usr/lib
export ORACLE_SID=ora8
export ORACLE_TERM=vt100
export ORA_NLS33=$ORACLE_HOME/ocommon/nls/admin/data
NLS_LANG=.UTF8
export NLS_LANG
NLS_DATE_FORMAT=YYYY-MM-DD
export NLS_DATE_FORMAT
TZ=GMT
export TZ
exec `dirname $0`/queue-message.pl $*
--
-- packages/acs-mail/sql/acs-mail-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2001-01-08
-- @cvs-id $Id$
--
-- Typical usage when creating:
-- For text only
--
-- body_id := acs_mail_body.new ( ... );
-- text_id := acs_mail_object.new ( ... );
-- acs_content.set_parameters ( text_id, ... );
-- update acs_content set content = empty_blob() where object_id = text_id;
-- acs_mail_body.set_content(text_id);
-- bboard_message.new ( ..., body_id );
-- tcl possibilities:
-- set body_id [acs_mail_body_new ...]
-- set text_id [acs_mail_object_new ... -content $text ]
-- acs_mail_body_set_content $body_id $text_id
-- set msg_id [bboard_message_new ... $body_id]
-- *or*
-- set body_id [acs_mail_body_new ... -content $text]
-- set msg_id [bboard_message_new ... $body_id]
-- For attachments (multipart/mixed)
--
-- body_id := acs_mail_body.new ( ... );
-- part_id := acs_mail_multipart.new ( ..., 'multipart/mixed' );
-- text_id := acs_mail_object.new ( ... );
-- { ... content stuff ... }
-- photo_id := acs_mail_object.new ( ... );
-- { ... content stuff ... }
-- acs_mail_multipart.add_content ( part_id, text_id );
-- acs_mail_multipart.add_content ( part_id, photo_id );
-- acs_mail_body.set_content ( part_id );
-- bboard_message.new ( ..., body_id );
-- For alternatives
-- (Same as above, but 'multipart/alternative' instead of 'multipart/mixed')
-- Typical usage when displaying:
-- select ... from ... (tree query)
-- 0 RFC822 Header (ignored)
-- 1 multipart/mixed (attachments!)
-- 1.1 text/plain (spit it out)
-- 1.2 image/gif (inline it)
-- 1.3 text/plain (more text to spit out
-- 1.4 message/rfc822
-- 1.4.0 header of submessage
-- 0000 (not sure about the numbering stuff yet) is always the RFC822
-- header, autogenerated or from incoming email.
-- 0001 will always be the content of the message
-- within 0001 may be more items, depending on the structure of the message.
-- Common headers are also available decomposed into useful forms.
-- Exactly how incoming messages get transformed into this structure
-- and how outgoing messages get transformed from this structure is to
-- be implemented soon.
set feedback off
-- Object System Metadata ----------------------------------------------
-- A messaging object, which is subject to garbage collection by the
-- messaging system. If any object in this table is not found in
-- select body_id as o_id from acs_mail_links
-- union
-- select object_id as o_id from acs_mail_multipart_parts
-- union
-- select body_content as o_id from acs_mail_bodies
-- then it is removed. It is assumed that an object cannot satisfy
-- the above predicate if it ever stops satisfying it (outside of a
-- transaction.)
begin
acs_object_type.create_type (
supertype => 'acs_object',
object_type => 'acs_mail_gc_object',
pretty_name => 'ACS Mail Object',
pretty_plural => 'ACS Mail Objects',
table_name => 'ACS_MAIL_GC_OBJECTS',
id_column => 'GC_OBJECT_ID',
package_name => 'ACS_MAIL_GC_OBJECT',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
-- Mail bodies are automatically GC'd. These contain the data
-- relevant to a single message. These are shared by being pointed to
-- by many acs_mail_links. This should not be subtyped.
begin
acs_object_type.create_type (
supertype => 'acs_mail_gc_object',
object_type => 'acs_mail_body',
pretty_name => 'ACS Mail Body',
pretty_plural => 'ACS Mail Bodies',
table_name => 'ACS_MAIL_BODIES',
id_column => 'BODY_ID',
package_name => 'ACS_MAIL_BODY',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
-- multipart mime parts are automatically GC'd. These contain
-- multiple parts to make up alternatives or mixed content
-- (attachments). These may be shared by belonging to multiple
-- mail_links.
begin
acs_object_type.create_type (
supertype => 'acs_mail_gc_object',
object_type => 'acs_mail_multipart',
pretty_name => 'ACS Mail Multipart Object',
pretty_plural => 'ACS Mail Multipart Objects',
table_name => 'ACS_MAIL_MULTIPARTS',
id_column => 'MULTIPART_ID',
package_name => 'ACS_MAIL_MULTIPART',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
-- A mail_link, subtypable, and used by applications to track messages.
-- Permissions should be set at this level. These should not be
-- shared between applications: rather, an application should create a
-- new mail_link and use it as it wills. When it's done, it should
-- delete this, which will cause the other objects to be garbage
-- collected.
begin
acs_object_type.create_type (
supertype => 'acs_object',
object_type => 'acs_mail_link',
pretty_name => 'ACS Mail Message',
pretty_plural => 'ACS Mail Messages',
table_name => 'ACS_MAIL_LINKS',
id_column => 'MAIL_LINK_ID',
package_name => 'ACS_MAIL_LINK',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
-- Raw Tables and Comments ---------------------------------------------
-- All garbage collectable objects are in this table
create table acs_mail_gc_objects (
gc_object_id integer
constraint acs_mail_gc_objs_object_id_pk
primary key
constraint acs_mail_gc_objs_object_id_fk
references acs_objects
);
-- Mail bodies
create table acs_mail_bodies (
body_id integer
constraint acs_mail_bodies_body_id_pk primary key
constraint acs_mail_bodies_body_id_fk
references acs_mail_gc_objects on delete cascade,
body_reply_to integer
constraint acs_mail_bodies_reply_to_fk
references acs_mail_bodies on delete set null,
body_from integer
constraint acs_mail_bodies_body_from_fk
references parties on delete set null,
body_date date,
header_message_id varchar2(1000)
constraint acs_mail_bodies_h_m_id_un unique
constraint acs_mail_bodies_h_m_id_nn not null,
header_reply_to varchar2(1000),
header_subject varchar2(4000),
header_from varchar2(4000),
header_to varchar2(4000),
content_item_id integer
constraint acs_mail_bodies_content_oid_fk
references acs_objects on delete cascade
);
-- RI Indexes
create index acs_mail_bodies_item_id_idx ON acs_mail_bodies(content_item_id);
create index acs_mail_bodies_body_from_idx ON acs_mail_bodies(body_from);
create index acs_mail_bodies_body_reply_idx ON acs_mail_bodies(body_reply_to);
create table acs_mail_body_headers (
body_id integer
constraint acs_mail_body_heads_body_id_fk
references acs_mail_bodies on delete cascade,
header_name varchar2(1000),
header_content varchar2(4000)
);
create index acs_mail_body_hdrs_body_id_idx
on acs_mail_body_headers (body_id);
-- MIME Multiparts
create table acs_mail_multiparts (
multipart_id integer
constraint acs_mail_multiparts_mp_id_pk primary key
constraint acs_mail_multiparts_mp_id_fk
references acs_mail_gc_objects on delete cascade,
multipart_kind varchar2(120)
constraint acs_mail_multiparts_mp_kind_nn not null
);
create table acs_mail_multipart_parts (
multipart_id integer
constraint acs_mail_mp_parts_mp_id_fk
references acs_mail_multiparts
on delete cascade,
mime_filename varchar2(1000),
mime_disposition varchar2(1000),
sequence_number integer,
content_item_id integer
constraint acs_mail_mp_parts_c_obj_id_fk references cr_items,
constraint acs_mail_multipart_parts_pk
primary key (multipart_id, sequence_number)
);
--RI Index
create index acs_mail_mpp_cr_item_id_idx ON acs_mail_multipart_parts(content_item_id);
-- Mail Links
create table acs_mail_links (
mail_link_id integer
constraint acs_mail_links_ml_id_pk primary key
constraint acs_mail_links_ml_id_fk references acs_objects
on delete cascade,
body_id integer
constraint acs_mail_links_body_id_nn not null
constraint acs_mail_links_body_id_fk references acs_mail_bodies
);
--RI Index
create index acs_mail_links_body_id_idx ON acs_mail_links(body_id);
-- API -----------------------------------------------------------------
-- APIs for the datamodel in this file, separated out for future upgrades
@@ acs-mail-packages-create
-- Supporting Datamodels -----------------------------------------------
-- The mail queue datamodel
@@ acs-mail-queue-create
-- The notification package
@@ acs-mail-nt-create
--
-- packages/acs-mail/sql/postgresql/acs-mail-drop.sql
--
-- @author Vinod Kurup <vkurup@massmed.org>
-- @creation-date 2001-07-05
-- @cvs-id $Id$
--
-- FIXME: This script has NOT been tested! - vinodk
@@ acs-mail-nt-drop
drop package acs_mail_queue_message;
drop table acs_mail_queue_incoming;
drop table acs_mail_queue_outgoing;
drop table acs_mail_queue_messages;
begin
acs_object_type.drop_type (
'acs_mail_queue_message',
't'
);
end;
/
show errors
drop package acs_mail_gc_object;
drop package acs_mail_body;
drop package acs_mail_multipart;
drop package acs_mail_link;
drop index acs_mail_body_hdrs_body_id_idx;
-- drop all acs-mail objects
begin
for v_rec in (select object_id from acs_objects where object_type in ('acs_mail_multipart', 'acs_mail_link', 'acs_mail_body','acs_mail_gc_object') order by object_id desc)
loop
acs_object.del(v_rec.object_id);
end loop;
end;
/
show errors
drop table acs_mail_body_headers;
drop table acs_mail_multipart_parts;
drop table acs_mail_multiparts;
drop table acs_mail_links;
drop table acs_mail_bodies;
drop table acs_mail_gc_objects;
begin
acs_object_type.drop_type (
'acs_mail_multipart',
't'
);
acs_object_type.drop_type (
'acs_mail_link',
't'
);
acs_object_type.drop_type (
'acs_mail_body',
't'
);
acs_object_type.drop_type (
'acs_mail_gc_object',
't'
);
end;
/
show errors
-- acs-mail-nt-create.sql
--
-- replicate basic functionality of acs-notifications in acs-mail
-- This will make acs-notifications obsolete and aggregate
-- all mail and alert functions into acs-mail
--
-- ported from PG to oracle
--
-- @author Vinod Kurup (vkurup@massmed.org)
-- @creation-date 2001-08-04
-- @cvs-id $Id$
create or replace package acs_mail_nt
as
-- /** acs_mail_nt.post_request
-- * Post a notification request
-- * A new CR item will be created and inserted into an acs_mail_body
-- * This acs_mail_body will then be queued.
-- * When tcl proc 'acs_mail_process_queue' gets run (every 15 min),
-- this message will be sent via ns_sendmail
-- * original nt.post_request by Stanislav Freidin
--
-- @author Vinod Kurup
-- @param party_from The id of the sending party
-- @param party_to The id of the sending party
-- @param expand_group part of old nt API - no longer supported
-- @param subject A one-line subject for the message
-- @param message The body of the message
-- @param max_retries part of old nt API - no longer supported
-- @return The id of the new request
-- */
function post_request (
party_from in parties.party_id%TYPE,
party_to in parties.party_id%TYPE,
expand_group in char default 'f',
subject in acs_mail_bodies.header_subject%TYPE,
message in varchar2,
max_retries in integer default 0
) return acs_mail_queue_messages.message_id%TYPE;
-- /** acs_mail_nt.cancel_request
-- * Cancel a notification request
-- * Original author: Stanislav Freidin
--
-- @author Vinod Kurup
-- @param request_id Id of the request to cancel
-- */
procedure cancel_request (
message_id in acs_mail_queue_messages.message_id%TYPE
);
-- /** acs_mail_nt.expand_requests
-- * This was part of the nt package, but is no longer relevant
-- * There is no replacement
--
-- @author Vinod Kurup
-- */
procedure expand_requests;
-- /** acs_mail_nt.update_requests
-- * This was part of the nt package, but is no longer relevant
-- * There is no replacement
--
-- @author Vinod Kurup
-- */
procedure update_requests;
-- /** acs_mail_nt.process_queue
-- * This was part of the nt package, but is no longer relevant
-- * Instead use the tcl proc: acs_mail_process_queue
--
-- @author Vinod Kurup
-- */
procedure process_queue (
host in varchar2,
port in integer default 25
);
-- /** acs_mail_nt.schedule_process
-- * This was part of the nt package, but is no longer relevant
-- * Instead, use ad_schedule_proc to schedule
-- the tcl proc acs_mail_process_queue
-- * Note: this is already done in a default install
-- See packages/acs-mail/tcl/acs-mail-init.tcl
--
-- @author Vinod Kurup
-- */
procedure schedule_process (
interval in number,
host in varchar2,
port in integer default 25
);
end acs_mail_nt;
/
show errors
create or replace package body acs_mail_nt
as
function post_request (
party_from in parties.party_id%TYPE,
party_to in parties.party_id%TYPE,
expand_group in char default 'f',
subject in acs_mail_bodies.header_subject%TYPE,
message in varchar2,
max_retries in integer default 0
) return acs_mail_queue_messages.message_id%TYPE
is
cursor c_expanded_cur is
select email from parties p
where p.party_id in (select member_id from group_approved_member_map
where group_id = party_to);
c_request_row c_expanded_cur%ROWTYPE;
v_header_from acs_mail_bodies.header_from%TYPE;
v_header_to acs_mail_bodies.header_to%TYPE;
v_body_id acs_mail_bodies.body_id%TYPE;
v_item_id cr_items.item_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
v_message_id acs_mail_queue_messages.message_id%TYPE;
v_creation_user acs_objects.creation_user%TYPE;
begin
if max_retries <> 0 then
raise_application_error(-20000,
'max_retries parameter not implemented.'
);
end if;
-- get the sender email address
select max(email) into v_header_from from parties where party_id = party_from;
-- if sender address is null, then use site default OutgoingSender
if v_header_from is null then
select apm.get_value(package_id, 'OutgoingSender') into v_header_from
from apm_packages where package_key='acs-kernel';
end if;
-- make sure that this party is in users table. If not, let creation_user
-- be null to prevent integrity constraint violations on acs_objects
select max(user_id) into v_creation_user
from users where user_id = party_from;
-- get the recipient email address
select max(email) into v_header_to from parties where party_id = party_to;
-- do not let any of these addresses be null
if v_header_from is null or v_header_to is null then
raise_application_error(-20000,
'acs_mail_nt: cannot sent email to blank address or from blank address.'
);
end if;
-- create a mail body with empty content
v_body_id := acs_mail_body.new (
body_from => party_from,
body_date => sysdate,
header_subject => subject,
creation_user => v_creation_user
);
-- create a CR item to stick message into
-- for oracle, we need to stick it in a blob
v_item_id := content_item.new (
name => 'acs-mail message' || v_body_id,
title => subject,
text => message
);
-- content_item__new makes a CR revision. We need to get that revision
-- and make it live
v_revision_id := content_item.get_latest_revision (v_item_id);
content_item.set_live_revision ( v_revision_id );
-- set the content of the message
acs_mail_body.set_content_object( v_body_id, v_item_id );
-- queue the message
v_message_id := acs_mail_queue_message.new (
body_id => v_body_id,
creation_user => v_creation_user
);
-- now put the message into the outgoing queue
-- i know this seems redundant, but that's the way it was built.
-- The idea is that you put a generic message into the main queue
-- without from or to address, and then insert a copy of the message
-- into the outgoing_queue with the specific from and to address
if expand_group = 'f' then
insert into acs_mail_queue_outgoing
( message_id, envelope_from, envelope_to )
values
( v_message_id, v_header_from, v_header_to );
else
-- expand the group
-- FIXME: need to check if this is a group and if there are members
-- if not, do we need to notify sender?
for c_request_row in c_expanded_cur loop
insert into acs_mail_queue_outgoing
( message_id, envelope_from, envelope_to )
values
( v_message_id, v_header_from, c_request_row.email );
end loop;
end if;
return v_message_id;
end post_request;
procedure cancel_request (
message_id in acs_mail_queue_messages.message_id%TYPE
)
is
begin
acs_mail_queue_message.del ( message_id );
end cancel_request;
procedure expand_requests
is
begin
raise_application_error(-20000,
'Procedure expand_requests no longer supported.'
);
end expand_requests;
procedure update_requests
is
begin
raise_application_error(-20000,
'Procedure no longer supported.'
);
end update_requests;
procedure schedule_process (
interval in number,
host in varchar2,
port in integer default 25
)
is
begin
raise_application_error(-20000,
'Procedure no longer supported - see packages/acs-mail/sql/oracle/acs-mail-nt-create.sql.'
);
end schedule_process;
procedure process_queue (
host in varchar2,
port in integer default 25
)
is
begin
raise_application_error(-20000,
'Procedure no longer supported - see packages/acs-mail/sql/oracle/acs-mail-nt-create.sql.'
);
end process_queue;
end acs_mail_nt;
/
show errors
--
-- packages/acs-mail/sql/postgresql/acs-mail-nt-drop.sql
--
-- @author Vinod Kurup <vkurup@massmed.org>
-- @creation-date 2001-07-05
-- @cvs-id $Id$
--
-- FIXME: This script has NOT been tested! - vinodk
drop package acs_mail_nt;
This diff is collapsed.
--
-- packages/acs-mail/sql/acs-mail-queue-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2001-01-08
-- @cvs-id $Id$
--
begin
acs_object_type.create_type (
supertype => 'acs_mail_link',
object_type => 'acs_mail_queue_message',
pretty_name => 'Queued Message',
pretty_plural => 'Queued Messages',
table_name => 'ACS_MESSAGES_QUEUE_MESSAGES',
id_column => 'MESSAGE_ID',
name_method => 'ACS_OBJECT.DEFAULT_NAME'
);
end;
/
show errors
create table acs_mail_queue_messages (
message_id integer
constraint acs_mail_queue_ml_id_pk primary key
constraint acs_mail_queue_ml_id_fk references acs_mail_links
on delete cascade
);
create table acs_mail_queue_incoming (
message_id integer
constraint acs_mail_queue_in_mlid_pk primary key
constraint acs_mail_queue_in_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from varchar2(4000),
envelope_to varchar2(4000)
);
create table acs_mail_queue_outgoing (
message_id integer
constraint acs_mail_queue_out_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from varchar2(4000),
envelope_to varchar2(1500),
constraint acs_mail_queue_out_pk
primary key (message_id, envelope_to)
);
-- API -----------------------------------------------------------------
create or replace package acs_mail_queue_message
as
function new (
mail_link_id in acs_mail_links.mail_link_id%TYPE default null,
body_id in acs_mail_bodies.body_id%TYPE,
context_id in acs_objects.context_id%TYPE default null,
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_mail_link'
) return acs_objects.object_id%TYPE;
procedure del (
message_id in acs_mail_links.mail_link_id%TYPE
);
end acs_mail_queue_message;
/
show errors
create or replace package body acs_mail_queue_message
as
function new (
mail_link_id in acs_mail_links.mail_link_id%TYPE default null,
body_id in acs_mail_bodies.body_id%TYPE,
context_id in acs_objects.context_id%TYPE default null,
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_mail_link'
) return acs_objects.object_id%TYPE
is
v_object_id acs_objects.object_id%TYPE;
begin
v_object_id := acs_mail_link.new (
mail_link_id => mail_link_id,
body_id => body_id,
context_id => context_id,
creation_date => creation_date,
creation_user => creation_user,
creation_ip => creation_ip,
object_type => object_type
);
insert into acs_mail_queue_messages ( message_id )
values ( v_object_id );
return v_object_id;
end;
procedure del (
message_id in acs_mail_links.mail_link_id%TYPE
)
is
begin
delete from acs_mail_queue_messages
where message_id = acs_mail_queue_message.del.message_id;
acs_mail_link.del(message_id);
end;
end acs_mail_queue_message;
/
show errors
-- Needs:
-- Incoming:
-- A way to say "okay, I've accepted this one, go ahead and delete"
-- Outgoing:
-- A way to say "send this message to this person from this person"
-- A way to say "send this message to these people from this person"
-- @author Vinod Kurup vinod@kurup.com
-- @creation-date 2002-10-08
update acs_object_types
set table_name = 'ACS_MESSAGES_QUEUE_MESSAGES'
where lower(object_type) = 'acs_mail_queue_message';
-- @author Vinod Kurup vinod@kurup.com
-- @creation-date 2002-12-15
-- fix the primary key on the outgoing queue
create table acs_mail_o_tmp as select * from acs_mail_queue_outgoing;
drop table acs_mail_queue_outgoing;
create table acs_mail_queue_outgoing (
message_id integer
constraint acs_mail_queue_out_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from varchar2(4000),
envelope_to varchar2(1500),
constraint acs_mail_queue_out_pk
primary key (message_id, envelope_to)
);
insert into acs_mail_queue_outgoing select * from acs_mail_o_tmp;
drop table acs_mail_o_tmp;
-- RI Indexes
create index acs_mail_bodies_item_id_idx ON acs_mail_bodies(content_item_id);
create index acs_mail_bodies_body_from_idx ON acs_mail_bodies(body_from);
create index acs_mail_bodies_body_reply_idx ON acs_mail_bodies(body_reply_to);
create index acs_mail_mpp_cr_item_id_idx ON acs_mail_multipart_parts(content_item_id);
create index acs_mail_links_body_id_idx ON acs_mail_links(body_id);
This diff is collapsed.
--
-- packages/acs-mail/sql/acs-mail-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2001-01-08
-- @cvs-id $Id$
--
-- Typical usage when creating:
-- For text only
--
-- body_id := acs_mail_body.new ( ... );
-- text_id := acs_mail_object.new ( ... );
-- acs_content.set_parameters ( text_id, ... );
-- update acs_content set content = empty_blob() where object_id = text_id;
-- acs_mail_body.set_content(text_id);
-- bboard_message.new ( ..., body_id );
-- tcl possibilities:
-- set body_id [acs_mail_body_new ...]
-- set text_id [acs_mail_object_new ... -content $text ]
-- acs_mail_body_set_content $body_id $text_id
-- set msg_id [bboard_message_new ... $body_id]
-- *or*
-- set body_id [acs_mail_body_new ... -content $text]
-- set msg_id [bboard_message_new ... $body_id]
-- For attachments (multipart/mixed)
--
-- body_id := acs_mail_body.new ( ... );
-- part_id := acs_mail_multipart.new ( ..., 'multipart/mixed' );
-- text_id := acs_mail_object.new ( ... );
-- { ... content stuff ... }
-- photo_id := acs_mail_object.new ( ... );
-- { ... content stuff ... }
-- acs_mail_multipart.add_content ( part_id, text_id );
-- acs_mail_multipart.add_content ( part_id, photo_id );
-- acs_mail_body.set_content ( part_id );
-- bboard_message.new ( ..., body_id );
-- For alternatives
-- (Same as above, but 'multipart/alternative' instead of 'multipart/mixed')
-- Typical usage when displaying:
-- select ... from ... (tree query)
-- 0 RFC822 Header (ignored)
-- 1 multipart/mixed (attachments!)
-- 1.1 text/plain (spit it out)
-- 1.2 image/gif (inline it)
-- 1.3 text/plain (more text to spit out
-- 1.4 message/rfc822
-- 1.4.0 header of submessage
-- 0000 (not sure about the numbering stuff yet) is always the RFC822
-- header, autogenerated or from incoming email.
-- 0001 will always be the content of the message
-- within 0001 may be more items, depending on the structure of the message.
-- Common headers are also available decomposed into useful forms.
-- Exactly how incoming messages get transformed into this structure
-- and how outgoing messages get transformed from this structure is to
-- be implemented soon.
-- set feedback off
-- Object System Metadata ----------------------------------------------
-- A messaging object, which is subject to garbage collection by the
-- messaging system. If any object in this table is not found in
-- select body_id as o_id from acs_mail_links
-- union
-- select object_id as o_id from acs_mail_multipart_parts
-- union
-- select body_content as o_id from acs_mail_bodies
-- then it is removed. It is assumed that an object cannot satisfy
-- the above predicate if it ever stops satisfying it (outside of a
-- transaction.)
select acs_object_type__create_type (
'acs_mail_gc_object',
'ACS Mail Object',
'ACS Mail Objects',
'acs_object',
'acs_mail_gc_objects',
'gc_object_id',
'acs_mail_gc_object',
'f',
null,
'acs_object.default_name'
);
-- Mail bodies are automatically GC'd. These contain the data
-- relevant to a single message. These are shared by being pointed to
-- by many acs_mail_links. This should not be subtyped.
select acs_object_type__create_type (
'acs_mail_body',
'ACS Mail Body',
'ACS Mail Bodies',
'acs_mail_gc_object',
'acs_mail_bodies',
'body_id',
'acs_mail_body',
'f',
null,
'acs_object.default_name'
);
-- multipart mime parts are automatically GC'd. These contain
-- multiple parts to make up alternatives or mixed content
-- (attachments). These may be shared by belonging to multiple
-- mail_links.
select acs_object_type__create_type (
'acs_mail_multipart',
'ACS Mail Multipart Object',
'ACS Mail Multipart Objects',
'acs_mail_gc_object',
'acs_mail_multiparts',
'multipart_id',
'acs_mail_multipart',
'f',
null,
'acs_object.default_name'
);
-- A mail_link, subtypable, and used by applications to track messages.
-- Permissions should be set at this level. These should not be
-- shared between applications: rather, an application should create a
-- new mail_link and use it as it wills. When it's done, it should
-- delete this, which will cause the other objects to be garbage
-- collected.
select acs_object_type__create_type (
'acs_mail_link',
'ACS Mail Message',
'ACS Mail Messages',
'acs_object',
'acs_mail_links',
'mail_link_id',
'acs_mail_link',
'f',
null,
'acs_object.default_name'
);
-- Raw Tables and Comments ---------------------------------------------
-- All garbage collectable objects are in this table
create table acs_mail_gc_objects (
gc_object_id integer
constraint acs_mail_gc_objs_object_id_pk
primary key
constraint acs_mail_gc_objs_object_id_fk
references acs_objects on delete cascade
);
-- Mail bodies
create table acs_mail_bodies (
body_id integer
constraint acs_mail_bodies_body_id_pk
primary key
constraint acs_mail_bodies_body_id_fk
references acs_mail_gc_objects
on delete cascade,
body_reply_to integer
constraint acs_mail_bodies_reply_to_fk
references acs_mail_bodies on delete set null,
body_from integer
constraint acs_mail_bodies_body_from_fk
references parties on delete set null,
body_date timestamptz,
header_message_id varchar(1000)
constraint acs_mail_bodies_h_m_id_un
unique
constraint acs_mail_bodies_h_m_id_nn
not null,
header_reply_to varchar(1000),
header_subject text,
header_from text,
header_to text,
-- content_item_id is a reference to acs_objects
-- if you are creating a simple message,
-- we expect you to create your CR item first before
-- calling acs_mail_bodies__new, so content_item_id will
-- refer to a cr_item
-- if you are creating a multipart message,
-- then create a acs_mail_multipart first and then supply
-- the multipart_id as the content_item_id
content_item_id integer
constraint acs_mail_bodies_content_iid_fk
references acs_objects on delete cascade
);
-- RI Indexes
create index acs_mail_bodies_item_id_idx ON acs_mail_bodies(content_item_id);
create index acs_mail_bodies_body_from_idx ON acs_mail_bodies(body_from);
create index acs_mail_bodies_body_reply_idx ON acs_mail_bodies(body_reply_to);
create table acs_mail_body_headers (
body_id integer
constraint acs_mail_body_heads_body_id_fk
references acs_mail_bodies on delete cascade,
header_name varchar(1000),
header_content text
);
create index acs_mail_body_hdrs_body_id_idx
on acs_mail_body_headers (body_id);
-- MIME Multiparts
create table acs_mail_multiparts (
multipart_id integer
constraint acs_mail_multiparts_mp_id_pk
primary key
constraint acs_mail_multiparts_mp_id_fk
references acs_mail_gc_objects on delete cascade,
multipart_kind varchar(120)
constraint acs_mail_multiparts_mp_kind_nn
not null
);
create table acs_mail_multipart_parts (
multipart_id integer
constraint acs_mail_mp_parts_mp_id_fk
references acs_mail_multiparts on delete cascade,
mime_filename varchar(1000),
mime_disposition varchar(1000),
sequence_number integer,
content_item_id integer
constraint acs_mail_mp_parts_c_itm_id_fk
references cr_items on delete cascade,
constraint acs_mail_multipart_parts_pk
primary key (multipart_id, sequence_number)
);
--RI Index
create index acs_mail_mpp_cr_item_id_idx ON acs_mail_multipart_parts(content_item_id);
-- Mail Links
create table acs_mail_links (
mail_link_id integer
constraint acs_mail_links_ml_id_pk
primary key
constraint acs_mail_links_ml_id_fk
references acs_objects on delete cascade,
body_id integer
constraint acs_mail_links_body_id_nn
not null
constraint acs_mail_links_body_id_fk
references acs_mail_bodies on delete cascade
);
-- RI Index
create index acs_mail_links_body_id_idx ON acs_mail_links(body_id);
-- API -----------------------------------------------------------------
-- APIs for the datamodel in this file, separated out for future upgrades
\i acs-mail-packages-create.sql
-- Supporting Datamodels -----------------------------------------------
-- The mail queue datamodel
\i acs-mail-queue-create.sql
-- The notification package
\i acs-mail-nt-create.sql
--
-- packages/acs-mail/sql/postgresql/acs-mail-drop.sql
--
-- @author Vinod Kurup <vkurup@massmed.org>
-- @creation-date 2001-07-05
-- @cvs-id $Id$
--
-- FIXME: This script has NOT been tested! - vinodk
\i acs-mail-nt-drop.sql
drop function acs_mail_queue_message__new (integer,integer,
integer,timestamptz,integer,varchar,varchar);
drop function acs_mail_queue_message__delete (integer);
drop table acs_mail_queue_incoming;
drop table acs_mail_queue_outgoing;
drop table acs_mail_queue_messages;
select acs_object_type__drop_type (
'acs_mail_queue_message',
't'
);
drop function acs_mail_gc_object__new (integer,varchar,timestamptz,integer,
varchar,integer);
drop function acs_mail_gc_object__delete(integer);
drop function acs_mail_body__new (integer,integer,integer,timestamptz,varchar,
varchar,text,text,text,integer,varchar,date,integer,varchar,integer);
drop function acs_mail_body__delete(integer);
drop function acs_mail_body__body_p(integer);
drop function acs_mail_body__clone (integer,integer,varchar,timestamptz,
integer,varchar,integer);
drop function acs_mail_body__set_content_object (integer,integer);
drop function acs_mail_multipart__new (integer,varchar,varchar,
timestamptz,integer,varchar,integer);
drop function acs_mail_multipart__delete (integer);
drop function acs_mail_multipart__multipart_p (integer);
drop function acs_mail_multipart__add_content (integer,integer);
drop function acs_mail_link__new (integer,integer,integer,timestamptz,
integer,varchar,varchar);
drop function acs_mail_link__delete (integer);
drop function acs_mail_link__link_p (integer);
drop index acs_mail_body_hdrs_body_id_idx;
create function inline_0 ()
returns integer as '
declare
v_rec acs_objects%ROWTYPE;
begin
for v_rec in select object_id from acs_objects where object_type in (''acs_mail_multipart'',''acs_mail_link'',''acs_mail_body'',''acs_mail_gc_object'') order by object_id desc
loop
perform acs_object__delete( v_rec.object_id );
end loop;
return 0;
end;' language 'plpgsql';
select inline_0 ();
drop function inline_0 ();
drop table acs_mail_body_headers;
drop table acs_mail_multipart_parts;
drop table acs_mail_multiparts;
drop table acs_mail_links;
drop table acs_mail_bodies;
drop table acs_mail_gc_objects;
select acs_object_type__drop_type (
'acs_mail_multipart',
't'
);
select acs_object_type__drop_type (
'acs_mail_link',
't'
);
select acs_object_type__drop_type (
'acs_mail_body',
't'
);
select acs_object_type__drop_type (
'acs_mail_gc_object',
't'
);
-- acs-mail-nt-create.sql
--
-- replicate basic functionality of acs-notifications in acs-mail
-- This will make acs-notifications obsolete and aggregate
-- all mail and alert functions into acs-mail
--
-- @author Vinod Kurup (vkurup@massmed.org)
--
-- /** acs_mail_nt__post_request
-- * Post a notification request
-- * A new CR item will be created and inserted into an acs_mail_body
-- * This acs_mail_body will then be queued.
-- * When tcl proc 'acs_mail_process_queue' gets run (every 15 min),
-- this message will be sent via ns_sendmail
-- * original nt.post_request by Stanislav Freidin
--
-- @author Vinod Kurup
-- @param party_from The id of the sending party
-- @param party_to The id of the sending party
-- @param expand_group if t, send email to individual members of group
-- if f, send email to group's email addr only
-- @param subject A one-line subject for the message
-- @param message The body of the message
-- @param max_retries part of old nt API - no longer supported
-- @return The id of the new request
-- */
create function acs_mail_nt__post_request(integer,integer,boolean,varchar,text,integer)
returns integer as '
declare
p_party_from alias for $1;
p_party_to alias for $2;
p_expand_group alias for $3; -- default ''f''
p_subject alias for $4;
p_message alias for $5;
p_max_retries alias for $6; -- default 0
v_header_from acs_mail_bodies.header_from%TYPE;
v_header_to acs_mail_bodies.header_to%TYPE;
v_body_id acs_mail_bodies.body_id%TYPE;
v_item_id cr_items.item_id%TYPE;
v_revision_id cr_revisions.revision_id%TYPE;
v_message_id acs_mail_queue_messages.message_id%TYPE;
v_header_to_rec record;
v_creation_user acs_objects.creation_user%TYPE;
begin
if p_max_retries <> 0 then
raise EXCEPTION '' -20000: max_retries parameter not implemented.'';
end if;
-- get the sender email address
select max(email) into v_header_from from parties where party_id = p_party_from;
-- if sender address is null, then use site default OutgoingSender
if v_header_from is null then
select apm__get_value(package_id, ''OutgoingSender'') into v_header_from
from apm_packages where package_key=''acs-kernel'';
end if;
-- make sure that this party is in users table. If not, let creation_user
-- be null to prevent integrity constraint violations on acs_objects
select max(user_id) into v_creation_user
from users where user_id = p_party_from;
-- get the recipient email address
select max(email) into v_header_to from parties where party_id = p_party_to;
-- do not let any of these addresses be null
if v_header_from is null or v_header_to is null then
raise EXCEPTION '' -20000: acs_mail_nt: cannot sent email to blank address or from blank address.'';
end if;
-- create a mail body with empty content
select acs_mail_body__new (
null, -- p_body_id
null, -- p_body_reply_to
p_party_from, -- p_body_from
now(), -- p_body_date
null, -- p_header_message_id
null, -- p_header_reply_to
p_subject, -- p_header_subject
null, -- p_header_from
null, -- p_header_to
null, -- p_content_item_id
''acs_mail_body'', -- p_object_type
now(), -- p_creation_date
v_creation_user, -- p_creation_user
null, -- p_creation_ip
null -- p_context_id
) into v_body_id;
-- create a CR item to stick p_message into
select content_item__new(
''acs-mail message'' || v_body_id, -- new__name
null, -- new__parent_id
p_subject, -- new__title
null, -- new__description
p_message -- new__text
) into v_item_id;
-- content_item__new makes a CR revision. We need to get that revision
-- and make it live
select content_item__get_latest_revision (v_item_id) into v_revision_id ;
perform content_item__set_live_revision ( v_revision_id );
-- set the content of the message
perform acs_mail_body__set_content_object( v_body_id, v_item_id );
-- queue the message
select acs_mail_queue_message__new (
null, -- p_mail_link_id
v_body_id, -- p_body_id
null, -- p_context_id
now(), -- p_creation_date
v_creation_user, -- p_creation_user
null, -- p_creation_ip
''acs_mail_link'' -- p_object_type
) into v_message_id;
-- now put the message into the outgoing queue
-- i know this seems redundant, but that''s the way it was built
-- the idea is that you put a generic message into the main queue
-- without from or to address, and then insert a copy of the message
-- into the outgoing_queue with the specific from and to address
if p_expand_group = ''f'' then
insert into acs_mail_queue_outgoing
( message_id, envelope_from, envelope_to )
values
( v_message_id, v_header_from, v_header_to );
else
-- expand the group
-- FIXME: need to check if this is a group and if there are members
-- if not, do we need to notify sender?
for v_header_to_rec in
select email from parties p
where party_id in (select member_id from group_approved_member_map
where group_id = p_party_to) loop
insert into acs_mail_queue_outgoing
( message_id, envelope_from, envelope_to )
values
( v_message_id, v_header_from, v_header_to_rec.email );
end loop;
end if;
return v_message_id;
end;' language 'plpgsql';
-- /** acs_mail_nt__post_request
-- * Overloaded function that
-- * only uses the basic params
--
-- @author: Vinod Kurup
-- @param party_from The id of the sending party
-- @param party_to The id of the sending party
-- @param subject A one-line subject for the message
-- @param message The body of the message
-- @return The id of the new request
--
create function acs_mail_nt__post_request(integer,integer,varchar,text)
returns integer as '
declare
p_party_from alias for $1;
p_party_to alias for $2;
p_subject alias for $3;
p_message alias for $4;
begin
return acs_mail_nt__post_request(
p_party_from, -- p_party_from
p_party_to, -- p_party_to
''f'', -- p_expand_group
p_subject, -- p_subject
p_message, -- p_message
0 -- p_max_retries
);
end;' language 'plpgsql';
-- /** acs_mail_nt__cancel_request
-- * Cancel a notification request
-- * Original author: Stanislav Freidin
--
-- @author Vinod Kurup
-- @param request_id Id of the request to cancel
-- */
create function acs_mail_nt__cancel_request (integer)
returns integer as '
declare
p_message_id alias for $1;
begin
perform acs_mail_queue_message__delete ( p_message_id );
return 0;
end;' language 'plpgsql';
-- /** acs_mail_nt__expand_requests
-- * This was part of the nt package, but is no longer relevant
-- * There is no replacement
--
-- @author Vinod Kurup
-- */
create function acs_mail_nt__expand_requests ()
returns integer as '
begin
raise EXCEPTION ''-20000: Procedure no longer supported.'';
return 0;
end;' language 'plpgsql';
-- /** acs_mail_nt__update_requests
-- * This was part of the nt package, but is no longer relevant
-- * There is no replacement
--
-- @author Vinod Kurup
-- */
create function acs_mail_nt__update_requests ()
returns integer as '
begin
raise EXCEPTION ''-20000: Procedure no longer supported.'';
return 0;
end;' language 'plpgsql';
-- /** acs_mail_nt__process_queue
-- * This was part of the nt package, but is no longer relevant
-- * Instead use the tcl proc: acs_mail_process_queue
--
-- @author Vinod Kurup
-- */
create function acs_mail_nt__process_queue (varchar,integer)
returns integer as '
declare
p_host alias for $1;
p_port alias for $2; -- default 25
begin
raise EXCEPTION ''-20000: Procedure no longer supported - see packages/acs-mail/sql/postgresql/acs-mail-nt-create.sql.'';
return 0;
end;' language 'plpgsql';
-- /** acs_mail_nt__schedule_process
-- * This was part of the nt package, but is no longer relevant
-- * Instead, use ad_schedule_proc to schedule
-- the tcl proc acs_mail_process_queue
-- * Note: this is already done in a default install
-- See packages/acs-mail/tcl/acs-mail-init.tcl
--
-- @author Vinod Kurup
-- */
create function acs_mail_nt__schedule_process (numeric,varchar,integer)
returns integer as '
declare
p_interval alias for $1;
p_host alias for $2;
p_port alias for $3; -- default 25
begin
raise EXCEPTION ''-20000: Procedure no longer supported - see packages/acs-mail/sql/postgresql/acs-mail-nt-create.sql. '';
return 0;
end;' language 'plpgsql';
--
-- packages/acs-mail/sql/postgresql/acs-mail-nt-drop.sql
--
-- @author Vinod Kurup <vkurup@massmed.org>
-- @creation-date 2001-07-05
-- @cvs-id $Id$
--
-- FIXME: This script has NOT been tested! - vinodk
drop function acs_mail_nt__post_request(integer,integer,boolean,varchar,text,integer);
drop function acs_mail_nt__post_request(integer,integer,varchar,text);
drop function acs_mail_nt__cancel_request (integer);
drop function acs_mail_nt__expand_requests ();
drop function acs_mail_nt__update_requests ();
drop function acs_mail_nt__process_queue (varchar,integer);
drop function acs_mail_nt__schedule_process (numeric,varchar,integer);
This diff is collapsed.
--
-- packages/acs-mail/sql/acs-mail-queue-create.sql
--
-- @author John Prevost <jmp@arsdigita.com>
-- @creation-date 2001-01-08
-- @cvs-id $Id$
--
select acs_object_type__create_type (
'acs_mail_queue_message',
'Queued Message',
'Queued Messages',
'acs_mail_link',
'acs_mail_queue_messages',
'message_id',
null,
'f',
null,
'acs_object.default_name'
);
create table acs_mail_queue_messages (
message_id integer
constraint acs_mail_queue_ml_id_pk
primary key
constraint acs_mail_queue_ml_id_fk
references acs_mail_links on delete cascade
);
create table acs_mail_queue_incoming (
message_id integer
constraint acs_mail_queue_in_mlid_pk
primary key
constraint acs_mail_queue_in_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from text,
envelope_to text
);
create table acs_mail_queue_outgoing (
message_id integer
constraint acs_mail_queue_out_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from text,
envelope_to text,
constraint acs_mail_queue_out_pk
primary key (message_id, envelope_to)
);
-- API -----------------------------------------------------------------
--create or replace package body acs_mail_queue_message__
create function acs_mail_queue_message__new (integer,integer,integer,timestamptz,integer,varchar,varchar)
returns integer as '
declare
p_mail_link_id alias for $1; -- default null
p_body_id alias for $2;
p_context_id alias for $3; -- default null
p_creation_date alias for $4; -- default now()
p_creation_user alias for $5; -- default null
p_creation_ip alias for $6; -- default null
p_object_type alias for $7; -- default acs_mail_link
v_mail_link_id acs_mail_links.mail_link_id%TYPE;
begin
v_mail_link_id := acs_mail_link__new (
p_mail_link_id, -- mail_link_id
p_body_id, -- body_id
p_context_id, -- context_id
p_creation_date, -- creation_date
p_creation_user, -- creation_user
p_creation_ip, -- creation_ip
p_object_type -- object_type
);
insert into acs_mail_queue_messages
( message_id )
values
( v_mail_link_id );
return v_mail_link_id;
end;' language 'plpgsql';
create function acs_mail_queue_message__delete (integer)
returns integer as '
declare
p_message_id alias for $1;
begin
perform acs_mail_link__delete( p_message_id );
return 1;
end;' language 'plpgsql';
-- end acs_mail_queue_message;
-- Needs:
-- Incoming:
-- A way to say "okay, I've accepted this one, go ahead and delete"
-- Outgoing:
-- A way to say "send this message to this person from this person"
-- A way to say "send this message to these people from this person"
-- @author Vinod Kurup vinod@kurup.com
-- @creation-date 2002-10-08
update acs_object_types
set table_name = 'acs_mail_queue_messages'
where lower(object_type) = 'acs_mail_queue_message';
-- @author Vinod Kurup vinod@kurup.com
-- @creation-date 2002-12-15
-- fix the primary key on the outgoing queue
create table acs_mail_o_tmp as select * from acs_mail_queue_outgoing;
drop table acs_mail_queue_outgoing;
create table acs_mail_queue_outgoing (
message_id integer
constraint acs_mail_queue_out_mlid_fk
references acs_mail_queue_messages on delete cascade,
envelope_from text,
envelope_to text,
constraint acs_mail_queue_out_pk
primary key (message_id, envelope_to)
);
insert into acs_mail_queue_outgoing select * from acs_mail_o_tmp;
drop table acs_mail_o_tmp;
-- RI Indexes
create index acs_mail_links_body_id_idx ON acs_mail_links(body_id);
create index acs_mail_bodies_item_id_idx ON acs_mail_bodies(content_item_id);
create index acs_mail_bodies_body_from_idx ON acs_mail_bodies(body_from);
create index acs_mail_bodies_body_reply_idx ON acs_mail_bodies(body_reply_to);
create index acs_mail_mpp_cr_item_id_idx ON acs_mail_multipart_parts(content_item_id);
ad_library {
Scheduled proc setup for acs-mail
@author John Prevost <jmp@arsdigita.com>
@creation-date 2001-01-19
@cvs-id $Id$
}
# Schedule periodic mail send events. Its own thread, since it does
# network activity. If it ever takes longer than the interval,
# there'll be hell to pay.
# Default interval is 15 minutes.
ad_schedule_proc -thread t 900 acs_mail_process_queue
ad_proc -private acs_mail_check_uuencode { } {
Check if ns_uuencode is properly encoding binary files
} {
# expected result from ns_uuencode
set expected_result "H4sICHH01DsAA2p1bmsAS8zPKU4tKkstAgCaYWMDCQAAAA=="
set file "[file dirname [info script]]/test-binary-file"
# open the binary file
set fd [open $file r]
fconfigure $fd -encoding binary
set file_content [read $fd]
close $fd
# encode it
set encoded_content [ns_uuencode $file_content]
if { [string equal $encoded_content $expected_result] } {
nsv_set acs_mail ns_uuencode_works_p 1
ns_log debug "acs-mail: ns_uuencode works!!"
} else {
nsv_set acs_mail ns_uuencode_works_p 0
ns_log Warning "acs-mail: ns_uuencode broken - will use the slow tcl version"
}
}
acs_mail_check_uuencode
<?xml version="1.0"?>
<queryset>
<rdbms><type>oracle</type><version>8.1.6</version></rdbms>
<fullquery name="acs_mail_set_content.insert_new_content">
<querytext>
begin
:1 := content_item.new (
name => 'acs-mail message $body_id',
creation_user => :creation_user,
creation_ip => :creation_ip,
title => :header_subject,
nls_language => :nls_language,
text => :content,
storage_type => 'lob'
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content.get_latest_revision">
<querytext>
begin
:1 := content_item.get_latest_revision ( :item_id );
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content.set_live_revision">
<querytext>
begin
content_item.set_live_revision(:revision_id);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.insert_new_content">
<querytext>
begin
:1 := content_item.new (
name => 'acs-mail message $body_id',
creation_user => :creation_user,
creation_ip => :creation_ip,
title => :header_subject,
nls_language => :nls_language,
storage_type => 'file'
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.get_latest_revision">
<querytext>
begin
:1 := content_item.get_latest_revision ( :item_id );
end;"
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.set_live_revision">
<querytext>
begin
content_item.set_live_revision(:revision_id);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.update_content">
<querytext>
update cr_revisions
set content = empty_blob()
where revision_id = :revision_id
returning content into :1
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.get_latest_revision">
<querytext>
begin
:1 := content_item.get_latest_revision ( :content_item_id );
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.copy_blob_to_file">
<querytext>
select r.content, i.storage_type
from cr_revisions r, cr_items i
where r.revision_id = $revision_id and
r.item_id = i.item_id
</querytext>
</fullquery>
<fullquery name="acs_mail_body_new.acs_mail_body_new">
<querytext>
begin
:1 := acs_mail_body.new (
body_id => :body_id,
body_reply_to => :body_reply_to,
body_from => :body_from,
body_date => :body_date,
header_message_id => :header_message_id,
header_reply_to => :header_reply_to,
header_subject => :header_subject,
header_from => :header_from,
header_to => :header_to,
content_item_id => :content_item_id,
creation_user => :creation_user,
creation_ip => :creation_ip
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_body_p.acs_mail_body_p">
<querytext>
begin
:1 := acs_mail_body.body_p (:object_id);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_body_clone.acs_mail_body_clone">
<querytext>
begin
:1 := acs_mail_body.clone (
old_body_id => :old_body_id,
body_id => :body_id,
creation_user => :creation_user,
creation_ip => :creation_ip
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_body_set_content_object.acs_mail_body_set_content_object">
<querytext>
begin
acs_mail_body.set_content_object (
body_id => :body_id,
content_item_id => :content_item_id
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_new.acs_mail_multipart_new">
<querytext>
begin
:1 := acs_mail_multipart.new (
multipart_id => :multipart_id,
multipart_kind => :multipart_kind,
creation_user => :creation_user,
creation_ip => :creation_ip
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_p.acs_mail_multipart_p">
<querytext>
begin
:1 := acs_mail_multipart.multipart_p (:object_id);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_add_content.acs_mail_multipart_add_content">
<querytext>
begin
:1 := acs_mail_multipart.add_content (
multipart_id => :multipart_id,
content_item_id => :content_item_id
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_link_new.acs_mail_link_new">
<querytext>
begin
:1 := acs_mail_link.new (
mail_link_id => :mail_link_id,
body_id => :body_id,
context_id => :context_id,
creation_user => :creation_user,
creation_ip => :creation_ip
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_link_p.acs_mail_link_p">
<querytext>
begin
:1 := acs_mail_link.link_p (:object_id);
end;
</querytext>
</fullquery>
</queryset>
<?xml version="1.0"?>
<queryset>
<rdbms><type>postgresql</type><version>7.1</version></rdbms>
<fullquery name="acs_mail_set_content.insert_new_content">
<querytext>
select content_item__new(
'acs-mail message $body_id'::varchar, -- new__name
null::integer, -- new__parent_id
null::integer, -- new__item_id
null::varchar, -- new__locale
current_timestamp, -- new__creation_date
:creation_user::integer, -- new__creation_user
null::integer, -- new__context_id
:creation_ip::varchar, -- new__creation_ip
'content_item'::varchar, -- new__item_subtype
'content_revision'::varchar, -- new__content_type
:header_subject::varchar, -- new__title
null::varchar, -- new__description
:content_type, -- new__mime_type
:nls_language, -- new__nls_language
:content, -- new__text
'text' -- new__storage_type
)
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content.get_latest_revision">
<querytext>
begin
return content_item__get_latest_revision ( :item_id );
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content.set_live_revision">
<querytext>
select content_item__set_live_revision(:revision_id);
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.insert_new_content">
<querytext>
begin
return content_item__new(
varchar 'acs-mail message $body_id', -- new__name
null, -- new__parent_id
null, -- new__item_id
null, -- new__locale
now(), -- new__creation_date
:creation_user, -- new__creation_user
null, -- new__context_id
:creation_ip, -- new__creation_ip
'content_item', -- new__item_subtype
'content_revision', -- new__content_type
:header_subject, -- new__title
null, -- new__description
:content_type, -- new__mime_type
:nls_language, -- new__nls_language
null, -- new__text
'file' -- new__storage_type
);
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.get_latest_revision">
<querytext>
begin
return content_item__get_latest_revision ( :item_id );
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.set_live_revision">
<querytext>
select content_item__set_live_revision(:revision_id)
</querytext>
</fullquery>
<fullquery name="acs_mail_set_content_file.update_content">
<querytext>
update cr_revisions
set content = '[cr_create_content_file $item_id $revision_id $content_file]'
where revision_id = :revision_id
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.get_latest_revision">
<querytext>
begin
return content_item__get_latest_revision ( :content_item_id );
end;
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.copy_blob_to_file">
<querytext>
select r.lob as content, i.storage_type
from cr_revisions r, cr_items i
where r.revision_id = $revision_id and
r.item_id = i.item_id
</querytext>
</fullquery>
<fullquery name="acs_mail_content_new.acs_mail_content_new">
<querytext>
select acs_mail_gc_object__new (
:object_id, -- gc_object_id
'acs_mail_gc_object', -- object_type
now(), -- creation_date
:creation_user, -- creation_user
:creation_ip, -- creation_ip
null -- context_id
);
</querytext>
</fullquery>
<fullquery name="acs_mail_body_new.acs_mail_body_new">
<querytext>
select acs_mail_body__new (
:body_id, -- body_id
:body_reply_to, -- body_reply_to
:body_from, -- body_from
:body_date, -- body_date
:header_message_id, -- header_message_id
:header_reply_to, -- header_reply_to
:header_subject, -- header_subject
:header_from, -- header_from
:header_to, -- header_to
:content_item_id, -- content_item_id
'acs_mail_body', -- object_type
now(), -- creation_date
:creation_user, -- creation_user
:creation_ip, -- creation_ip
null -- context_id
);
</querytext>
</fullquery>
<fullquery name="acs_mail_body_p.acs_mail_body_p">
<querytext>
select acs_mail_body__body_p (:object_id);
</querytext>
</fullquery>
<fullquery name="acs_mail_body_clone.acs_mail_body_clone">
<querytext>
select acs_mail_body__clone (
:old_body_id, -- old_body_id
:body_id, -- body_id
:creation_user, -- creation_user
:creation_ip -- creation_ip
);
</querytext>
</fullquery>
<fullquery name="acs_mail_body_set_content_object.acs_mail_body_set_content_object">
<querytext>
select acs_mail_body__set_content_object (
:body_id, -- body_id
:content_item_id -- content_item_id
);
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_new.acs_mail_multipart_new">
<querytext>
select acs_mail_multipart__new (
:multipart_id, -- multipart_id
:multipart_kind, -- multipart_kind
'acs_mail_multipart', -- object_type
now(), -- creation_date
:creation_user, -- creation_user
:creation_ip, -- creation_ip
null -- context_id
);
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_p.acs_mail_multipart_p">
<querytext>
select acs_mail_multipart__multipart_p (:object_id);
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_add_content.acs_mail_multipart_add_content">
<querytext>
select acs_mail_multipart__add_content (
:multipart_id, -- multipart_id
:content_item_id -- content_item_id
);
</querytext>
</fullquery>
<fullquery name="acs_mail_link_new.acs_mail_link_new">
<querytext>
select acs_mail_link__new (
:mail_link_id, -- mail_link_id
:body_id, -- body_id
:context_id, -- context_id
:creation_user, -- creation_user
:creation_ip -- creation_ip
);
</querytext>
</fullquery>
<fullquery name="acs_mail_link_p.acs_mail_link_p">
<querytext>
select acs_mail_link__link_p (:object_id);
</querytext>
</fullquery>
</queryset>
This diff is collapsed.
<?xml version="1.0"?>
<queryset>
<fullquery name="acs_mail_encode_content.get_storage_type">
<querytext>
select storage_type from cr_items
where item_id = :content_item_id
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.acs_mail_body_to_mime_get_content_simple">
<querytext>
select content, mime_type as v_content_type
from cr_revisions
where revision_id = :revision_id
</querytext>
</fullquery>
<fullquery name="acs_mail_encode_content.acs_mail_body_to_mime_get_contents">
<querytext>
select mime_filename, mime_disposition, content_item_id as ci_id
from acs_mail_multipart_parts
where multipart_id = :content_item_id
order by sequence_number
</querytext>
</fullquery>
<fullquery name="acs_mail_body_to_output_format.acs_mail_body_to_mime_get_body">
<querytext>
select body_id from acs_mail_links where mail_link_id = :link_id
</querytext>
</fullquery>
<fullquery name="acs_mail_body_to_output_format.acs_mail_body_to_mime_data">
<querytext>
select header_message_id, header_reply_to, header_subject,
header_from, header_to, content_item_id
from acs_mail_bodies
where body_id = :body_id
</querytext>
</fullquery>
<fullquery name="acs_mail_body_to_output_format.acs_mail_body_to_mime_headers">
<querytext>
select header_name, header_content from acs_mail_body_headers
where body_id = :body_id
</querytext>
</fullquery>
<fullquery name="acs_mail_process_queue.acs_message_send">
<querytext>
select message_id, envelope_from, envelope_to from acs_mail_queue_outgoing
</querytext>
</fullquery>
<fullquery name="acs_mail_process_queue.acs_message_delete_sent">
<querytext>
delete from acs_mail_queue_outgoing
where message_id = :message_id
and envelope_from = :envelope_from
and envelope_to = :envelope_to
</querytext>
</fullquery>
<fullquery name="acs_mail_process_queue.acs_message_cleanup_queue">
<querytext>
delete from acs_mail_queue_messages
where message_id not in
(select message_id from acs_mail_queue_outgoing)
and message_id not in
(select message_id from acs_mail_queue_incoming)
</querytext>
</fullquery>
<fullquery name="acs_mail_multipart_type.acs_mail_multipart_type">
<querytext>
select multipart_kind from acs_mail_multiparts
where multipart_id = :object_id
</querytext>
</fullquery>
<fullquery name="acs_mail_link_get_body_id.acs_mail_link_get_body_id">
<querytext>
select body_id from acs_mail_links where mail_link_id = :link_id
</querytext>
</fullquery>
</queryset>
ad_library {
Automated tests.
@author Joel Aufrecht
@creation-date 2 Nov 2003
@cvs-id $Id$
}
aa_register_case acs_mail_trivial_smoke_test {
Minimal smoke test.
} {
aa_run_with_teardown \
-rollback \
-test_code {
# initialize random values
set name [ad_generate_random_string]
set name_2 [ad_generate_random_string]
# there is no function in the api to directly retrieve a key
# so instead we have to create a child of another and then
# retrieve the parent's child
set new_multipart_id [acs_mail_multipart_new -multipart_kind mixed]
aa_true "created a new multipart" [exists_and_not_null new_multipart_id]
aa_true "verify that a multipart was created" [acs_mail_multipart_p $new_multipart_id]
# would test that delete works but there's no relevant function in the API
}
}
\ No newline at end of file
<pre>
Mail System Design
------------------
1. The mail store
The mail store is a complex problem. On the one hand, we
could simply store RFC822 messages in raw form.
Unfortunately, this could lead to serious problems when trying
to manipulate messages. (For example, the code to parse out
part 2.1.5 of a message would have to actuall parse MIME.) It
might be better to use a view in which MIME messages are
pre-separated into parts. Or perhaps a single message is
stored and a "part" table describes the ranges covered by
various MIME parts.
More research into this needs to be done. For the short term,
using a non-MIME mechanism for storing information we wish to
send out (attachments in bboard, the like) is sufficient. The
conversion can be done at mail send time. Received email can
be treated as text/plain for the moment, even when it is
richer.
Here's a plan for the table design:
message_body
------------
rfc822_id
header_from
header_date
header_message_id
header_content_type
... others
message
-------
message_id
rfc822_id
env_from
env_to
With each message_body being associated with a content value
from the acs_contents table (or CR revisions table.)
Notice that each message body belongs to one *or more*
messages. This is because the same message might be addressed
to more than one recipient, but still be the same message.
Because of this it is recommended that editing messages take
place via "copy on write" rather than "modify in place". This
will allow messages to be edited, but for old versions in
other locations not be be lost. (Keep the message_id the
same, but point it at a new rfc822_id for the body.)
Separating messages from message_bodies also makes it more
clear how to determine what access control and URL any message
belongs to. Each message belongs in only one place, but the
message_body may be shared.
The above design for message_body should include whatever
header fields are determined to be necessary and useful.
Difficulties arise, since for email addresses it would be nice
for this version to point at parties, but the "from" header of
messages may actually contain more than one address, and so
on. Some thought needs to be applied here.
2. Sending email
The first iteration should send email using ns_sendmail or the
Oracle UTL_SMTP stuff. ns_sendmail is preferred, since it's
much higher level than UTL_SMTP.
A simple queue should be sufficient for sending. Each message
may be queued to be sent to various people, like so:
outgoing_message_queue
----------------------
message_id
Notice that the pointer is to a message, not a message body.
The expectation is that a new message is created (to contain
the new envelope information), and that that message is
recorded in this queue.
Once the message is sent, the message is removed from this
queue (and possibly added to an audit trail? Kept in the
queue marked as done?)
The requirement to be able to delete messages from the system
immediately after deletion means that there are some other
issues here. See "open issues" below.
3. Receiving email
The simplest design for receiving email into various queues
assumes that each message actually belongs to one and only one
queue:
incoming_message_queue
----------------------
message_id
queue_name
A table can describe a set of rules (with like patterns?) to
use to determine what queue_name should be used for initial
insertion. This gives any application the capability to
periodically find all new messages that it's interested in
processing. Removal from the queue is per application
request.
An alternative method is for messages to go in all queues with
matching requirements. The same as above, only unique on the
pair instead of just message_id. This would allow messages to
be placed into multiple queues for processing by more than one
application. I suspect this is unnecessary.
A final thought is that it would be possible to simply record
message ids in this table (as in the outgoing queue.) Then
individual applications do a select over the incoming message
queue, looking for interesting messages. When they are
finished, they delete the message. Again, this is based on
the "no message will belong to more than one application"
model.
4. Manipulating messages
This is a difficult task in Tcl, since MIME is fairly
complicated. There is already a good API for Java. I suggest
that for the Tcl API, simple abilities to deal with encoding
(and later possibly decoding) messages with multipart/mixed
and multipart/alternative content types. This will require
good base64 encoding tools in Tcl.
5. Open questions
The biggest open question is garbage collection.
Paradoxically, the split into messages and message_bodys may
help with this. Since we can imagine that each application
keeps its own message_body object, the application is allowed
to delete that message_body in a reasonable way. At that
point, it's sufficient to periodically clear the message store
of any message bodies that have no associated messages!
Extension of the message class also becomes more possible.
When a new message comes in to be entered into a bboard forum,
the bboard application can create a new message object
pointing at the same message body. The new message object can
be a "bboard_message". Previously, acs_messaging would create
the message object, and bboard would have to deal with it even
if it were a "normal" message.
It is unclear at this point whether this system should
actually provide mechanisms to automatically build digests.
On the one hand, it already has scheduled tasks to do such
things. On the other hand, putting the generic mechanisms to
handle collation and the like into the system is messy. And
on top of that, there are optimizations that applications can
do. (For example, bboard could build a single message_body
for a daily digest and send it out to all subscribers, instead
of messaging building a customized message for each
subscriber, because it can't determine that they would all be
the same.)
6. Data model in short:
outgoing_message_queue
| (message_id)
|
message_body -- message --<|------------ [ extended by application ]
(rfc822_id) | (message_id)
|
incoming_message_queue
(message_id, queue_name)
A scheduled process periodically sends any messages in the
outgoing message_queue and deletes the message entry.
When messages arrive, some MTA mechanism inserts them as a
message_body, with a message containing the envelope info, and
puts that message into the appropriate
incoming_message_queues.
A scheduled process periodically deletes any message_body for
which there exists no referencing message.
Each message belongs to an individual application. That
application is responsible for removing it once it is no
longer needed (and then GC can be accomplished.)
</pre>
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN">
<html>
<head>
<title>OpenACS acs-mail package</title>
</head>
<body bgcolor=white>
<h2>OpenACS acs-mail package</h2>
openacs version by Jon Griffin & Vinod Kurup
<hr>
Pieces:
<ul>
<li><a href="requirements.html">Original Requirements Document</a> </li>
<li><a href="design.html">Original Design Document</a> </li>
<li><a href="openacs-mail.html">OpenACS usage document</a> </li>
</ul>
<hr>
<address><a href="mailto:vkurup@massmed.org"></a></address>
<!-- Created: Mon Aug 13 14:17:34 EDT 2001 -->
<!-- hhmts start -->
Last modified: Mon Aug 13 14:20:40 EDT 2001
<!-- hhmts end -->
</body>
</html>
This diff is collapsed.
<pre>
Mail System Requirements
------------------------
1. The system will be able to store messages as rich as MIME
compliant email messages. In order to do so:
a. The system must be able to store messages with complex
sub-part structure, with mixed character sets. This
includes attachments, digital signatures, and
multi-variety messages, as well as embedded MIME messages.
b. The system must be capable of fully representing RFC822
and MIME email messages. Semantics-preserving operations
(such as limited header reordering) may be allowable, but
in general, the system should be able to receive a message
and then later send out that same message bit-for-bit
identically.
c. The system should be able to record extra envelope
information outside the message itself, for reference when
processing messages.
2. The system will be able to send messages via SMTP, and
possibly other mechanisms.
a. The initial version must be able to send mail via an SMTP
connection to the local host. This solution is easy to
implement and provides the most portable (if not the most
efficient) mechanism available.
b. In order to best support sysadmins, the system should be
able to call external programs to queue mail instead of
using an SMTP connection.
c. While all messages may be stored in the message store at
some point, it must be possible to send a message in
"delete immediately mode" so that it is not stored
forever. This is to support sending of passwords via
email.
3. The system will be able to receive messages via various
mechanisms and queue the messages up for review by other
systems.
a. Each incoming message should be stored in the message
store.
b. When a message arrives, some set of rules should determine
what queues the message belongs to. Most likely, pattern
matching on a small number of headers will suffice.
c. A variety of mechanisms for message insertion may be
supported further in the future, but the initial version
must support at least a simple delivery program that
accepts the message on stdin, envelope information as
arguments, and places the message into the database.
4. The system will be able to manipulate complex MIME messages.
The full set of operations is not yet clear, but it must
certainly be possible to access individual parts of messages,
get header information about a given message, and create a
message based on some set of parts to be included. In
addition, mechanisms to do conversion between character sets,
content types, and encoding should eventually be supported.
Some of these mechanisms already exist, and their suitability
for the use of the system should be examined.
</pre>
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