Index: openacs-4/packages/acs-events/sql/oracle/upgrade/upgrade-0.3d-0.4d.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-events/sql/oracle/upgrade/upgrade-0.3d-0.4d.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-events/sql/oracle/upgrade/upgrade-0.3d-0.4d.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,1732 @@ +-- packages/acs-events/sql/acs-events-create.sql +-- +-- @author smeeks@arsdigita.com +-- @creation-date 2000-11-16 +-- @cvs-id $Id: upgrade-0.3d-0.4d.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +create or replace package acs_event +as + function new ( + -- Creates a new event (20.10.10) + -- @author W. Scott Meeks + -- @param event_id optional id to use for new event + -- @param name optional Name of the new event + -- @param description optional Description of the new event + -- @param html_p optional Description is html + -- @param status_summary optional status information to add to name + -- @param timespan_id optional initial time interval set + -- @param activity_id optional initial activity + -- @param recurrence_id optional id of recurrence information + -- @param object_type 'acs_event' + -- @param creation_date default sysdate + -- @param creation_user acs_object param + -- @param creation_ip acs_object param + -- @param context_id acs_object param + -- @return The id of the new event. + -- + event_id in acs_events.event_id%TYPE default null, + name in acs_events.name%TYPE default null, + description in acs_events.description%TYPE default null, + html_p in acs_events.html_p%TYPE default null, + status_summary in acs_events.status_summary%TYPE default null, + timespan_id in acs_events.timespan_id%TYPE default null, + activity_id in acs_events.activity_id%TYPE default null, + recurrence_id in acs_events.recurrence_id%TYPE default null, + object_type in acs_object_types.object_type%TYPE default 'acs_event', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_events.event_id%TYPE; + + procedure del ( + -- Deletes an event (20.10.40) + -- Also deletes party mappings (via on delete cascade). + -- If this is the last instance of a recurring event, the recurrence + -- info is deleted as well + -- @author W. Scott Meeks + -- @param event_id id of event to delete + -- + event_id in acs_events.event_id%TYPE + ); + + procedure delete_all ( + -- Deletes all instances of an event. + -- @author W. Scott Meeks + -- @param event_id All events with the same recurrence_id as this one will be deleted. + -- + event_id in acs_events.event_id%TYPE + ); + + procedure delete_all_recurrences ( + -- Deletes all instances of an event. + -- @author W. Scott Meeks + -- @param recurrence_id All events with this recurrence_id will be deleted. + -- + recurrence_id in recurrences.recurrence_id%TYPE default null + ); + + function get_name ( + -- Returns the name or the name of the activity associated with the event if + -- name is null. + -- @author W. Scott Meeks + -- @param event_id id of event to get name for + -- + event_id in acs_events.event_id%TYPE + ) return acs_events.name%TYPE; + + function get_description ( + -- Returns the description or the description of the activity associated + -- with the event if description is null. + -- @author W. Scott Meeks + -- @param event_id id of event to get description for + -- + event_id in acs_events.event_id%TYPE + ) return acs_events.description%TYPE; + + function get_html_p ( + -- Returns html_p or html_p of the activity associated with the event if + -- html_p is null. + -- @author W. Scott Meeks + -- @param event_id id of event to get html_p for + -- + event_id in acs_events.event_id%TYPE + ) return acs_events.html_p%TYPE; + + function get_status_summary ( + -- Returns status_summary or status_summary of the activity associated with the event if + -- status_summary is null. + -- @author W. Scott Meeks + -- @param event_id id of event to get status_summary for + -- + event_id in acs_events.event_id%TYPE + ) return acs_events.status_summary%TYPE; + + procedure timespan_set ( + -- Sets the time span for an event (20.10.15) + -- @author W. Scott Meeks + -- @param event_id id of event to update + -- @param timespan_id new time interval set + -- + event_id in acs_events.event_id%TYPE, + timespan_id in timespans.timespan_id%TYPE + ); + + procedure recurrence_timespan_edit ( + event_id in acs_events.event_id%TYPE, + start_date in time_intervals.start_date%TYPE, + end_date in time_intervals.end_date%TYPE + ); + + procedure activity_set ( + -- Sets the activity for an event (20.10.20) + -- @author W. Scott Meeks + -- @param event_id id of event to update + -- @param activity_id new activity + -- + event_id in acs_events.event_id%TYPE, + activity_id in acs_activities.activity_id%TYPE + ); + + procedure party_map ( + -- Adds a party mapping to an event (20.10.30) + -- @author W. Scott Meeks + -- @param event_id event to add mapping to + -- @param party_id party to add mapping for + -- + event_id in acs_events.event_id%TYPE, + party_id in parties.party_id%TYPE + ); + + procedure party_unmap ( + -- Deletes a party mapping from an event (20.10.30) + -- @author W. Scott Meeks + -- @param event_id id of event to delete mapping from + -- @param party_id id of party to delete mapping for + -- + event_id in acs_events.event_id%TYPE, + party_id in parties.party_id%TYPE + ); + + function recurs_p ( + -- Returns 't' if event recurs, 'f' otherwise (20.50.40) + -- @author W. Scott Meeks + -- @param event_id id of event to check + -- @return 't' or 'f' + -- + event_id in acs_events.event_id%TYPE + ) return char; + + function instances_exist_p ( + -- Returns 't' if events with the given recurrence_id exist, 'f' otherwise + -- @author W. Scott Meeks + -- @param recurrence_id id of recurrence to check + -- @return 't' or 'f' + -- + recurrence_id in acs_events.recurrence_id%TYPE + ) return char; + + procedure insert_instances ( + -- This is the key procedure creating recurring events. This procedure + -- uses the interval set and recurrence information referenced by the event + -- to insert additional information to represent the recurrences. + -- Events will be added up until the earlier of recur_until and + -- cutoff_date. The procedure enforces a hard internal + -- limit of adding no more than 10,000 recurrences at once to reduce the + -- risk of demolishing the DB because of application bugs. The date of the + -- last recurrence added is marked as the db_populated_until date. + -- + -- The application is responsible for calling this function again if + -- necessary to populate to a later date. + -- + -- @author W. Scott Meeks + -- @param event_id The id of the event to recur. If the + -- event's recurrence_id is null, nothing happens. + -- @param cutoff_date optional If provided, determines how far out to + -- prepopulate the DB. If not provided, then + -- defaults to sysdate plus the value of the + -- EventFutureLimit site parameter. + event_id in acs_events.event_id%TYPE, + cutoff_date in date default null + ); + + procedure shift ( + -- Shifts the timespan of an event by the given offsets. + -- @author W. Scott Meeks + -- @param event_id Event to shift. + -- @param start_offset optional If provided, adds this number to the + -- start_dates of the timespan of the event. + -- No effect on any null start_date. + -- @param end_offset optional If provided, adds this number to the + -- end_dates of the timespan of the event. + -- No effect on any null end_date. + -- + event_id in acs_events.event_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ); + + procedure shift_all ( + -- Shifts the timespan of all instances of a recurring event + -- by the given offsets. + -- @author W. Scott Meeks + -- @param event_id All events with the same + -- recurrence_id as this one will be shifted. + -- @param start_offset optional If provided, adds this number to the + -- start_dates of the timespan of the event + -- instances. No effect on any null start_date. + -- @param end_offset optional If provided, adds this number to the + -- end_dates of the timespan of the event + -- instances. No effect on any null end_date. + -- + event_id in acs_events.event_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ); + + procedure shift_all ( + -- Same as above but invoked using recurrence Id + recurrence_id in recurrences.recurrence_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ); + +end acs_event; +/ +show errors + +create or replace package body acs_event +as + function new ( + event_id in acs_events.event_id%TYPE default null, + name in acs_events.name%TYPE default null, + description in acs_events.description%TYPE default null, + html_p in acs_events.html_p%TYPE default null, + status_summary in acs_events.status_summary%TYPE default null, + timespan_id in acs_events.timespan_id%TYPE default null, + activity_id in acs_events.activity_id%TYPE default null, + recurrence_id in acs_events.recurrence_id%TYPE default null, + object_type in acs_object_types.object_type%TYPE default 'acs_event', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_events.event_id%TYPE + is + new_event_id acs_events.event_id%TYPE; + begin + new_event_id := acs_object.new( + object_id => event_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into acs_events + (event_id, name, description, html_p, status_summary, activity_id, timespan_id, recurrence_id) + values + (new_event_id, name, description, html_p, status_summary, activity_id, timespan_id, recurrence_id); + + return new_event_id; + end new; + + procedure del ( + event_id in acs_events.event_id%TYPE + ) + is + recurrence_id acs_events.recurrence_id%TYPE; + begin + select recurrence_id into recurrence_id + from acs_events + where event_id = acs_event.del.event_id; + + -- acs_events and acs_event_party_map deleted via on delete cascade + acs_object.del(event_id); + + -- Check for no more instances and delete recurrence if exists + if instances_exist_p(recurrence_id) = 'f' then + recurrence.del(recurrence_id); + end if; + end del; + + procedure delete_all ( + event_id in acs_events.event_id%TYPE + ) + is + recurrence_id acs_events.recurrence_id%TYPE; + begin + + select recurrence_id into recurrence_id + from acs_events + where event_id = delete_all.event_id; + + delete_all_recurrences(recurrence_id); + end delete_all; + + procedure delete_all_recurrences ( + recurrence_id in recurrences.recurrence_id%TYPE default null + ) + is + cursor event_id_cursor is + select event_id + from acs_events + where recurrence_id = delete_all_recurrences.recurrence_id; + event_id event_id_cursor%ROWTYPE; + begin + if recurrence_id is not null then + for event_id in event_id_cursor loop + acs_event.del(event_id.event_id); + end loop; + end if; + end delete_all_recurrences; + + -- Equivalent functionality to get_name and get_description provided by + -- acs_event_activity view + + function get_name ( + event_id in acs_events.event_id%TYPE + ) return acs_events.name%TYPE + is + name acs_events.name%TYPE; + begin + select nvl(e.name, a.name) into name + from acs_events e, + acs_activities a + where event_id = get_name.event_id + and e.activity_id = a.activity_id(+); + + return name; + end get_name; + + function get_description ( + event_id in acs_events.event_id%TYPE + ) return acs_events.description%TYPE + is + description acs_events.description%TYPE; + begin + select nvl(e.description, a.description) into description + from acs_events e, acs_activities a + where event_id = get_description.event_id + and e.activity_id = a.activity_id(+); + + return description; + end get_description; + + function get_html_p ( + event_id in acs_events.event_id%TYPE + ) return acs_events.html_p%TYPE + is + html_p acs_events.html_p%TYPE; + begin + select nvl(e.html_p, a.html_p) into html_p + from acs_events e, acs_activities a + where event_id = get_html_p.event_id + and e.activity_id = a.activity_id(+); + + return html_p; + end get_html_p; + + function get_status_summary ( + event_id in acs_events.event_id%TYPE + ) return acs_events.status_summary%TYPE + is + status_summary acs_events.status_summary%TYPE; + begin + select nvl(e.status_summary, a.status_summary) into status_summary + from acs_events e, acs_activities a + where event_id = get_status_summary.event_id + and e.activity_id = a.activity_id(+); + + return status_summary; + end get_status_summary; + + procedure timespan_set ( + event_id in acs_events.event_id%TYPE, + timespan_id in timespans.timespan_id%TYPE + ) + is + begin + update acs_events + set timespan_id = timespan_set.timespan_id + where event_id = timespan_set.event_id; + end timespan_set; + + procedure recurrence_timespan_edit ( + event_id in acs_events.event_id%TYPE, + start_date in time_intervals.start_date%TYPE, + end_date in time_intervals.end_date%TYPE + ) + is + v_timespan timespans%ROWTYPE; + v_one_start_date time_intervals.start_date%TYPE; + v_one_end_date time_intervals.end_date%TYPE; + begin + -- get the initial offsets + select start_date, end_date into v_one_start_date, v_one_end_date + from time_intervals, timespans, acs_events + where time_intervals.interval_id = timespans.interval_id and + timespans.timespan_id = acs_events.timespan_id and + event_id= recurrence_timespan_edit.event_id; + + for v_timespan in + (select * from time_intervals where interval_id in (select interval_id from timespans where timespan_id in (select timespan_id from acs_events where recurrence_id = (select recurrence_id from acs_events where event_id = recurrence_timespan_edit.event_id)))) + LOOP + time_interval.edit(v_timespan.interval_id, v_timespan.start_date + (start_date - v_one_start_date), v_timespan.end_date + (end_date - v_one_end_date)); + END LOOP; + end recurrence_timespan_edit; + + procedure activity_set ( + event_id in acs_events.event_id%TYPE, + activity_id in acs_activities.activity_id%TYPE + ) + as + begin + update acs_events + set activity_id = activity_set.activity_id + where event_id = activity_set.event_id; + end activity_set; + + procedure party_map ( + event_id in acs_events.event_id%TYPE, + party_id in parties.party_id%TYPE + ) + is + begin + insert into acs_event_party_map + (event_id, party_id) + values + (event_id, party_id); + end party_map; + + procedure party_unmap ( + event_id in acs_events.event_id%TYPE, + party_id in parties.party_id%TYPE + ) + is + begin + delete from acs_event_party_map + where event_id = party_unmap.event_id + and party_id = party_unmap.party_id; + end party_unmap; + + function recurs_p ( + event_id in acs_events.event_id%TYPE + ) return char + is + result char; + begin + select decode(recurrence_id, null, 'f', 't') into result + from acs_events + where event_id = recurs_p.event_id; + + return result; + end recurs_p; + + function instances_exist_p ( + recurrence_id in acs_events.recurrence_id%TYPE + ) return char + is + result char; + begin + -- Only need to check if any rows exist. + select count(*) into result + from dual + where exists (select recurrence_id + from acs_events + where recurrence_id = instances_exist_p.recurrence_id); + + if result = 0 then + return 'f'; + else + return 't'; + end if; + end instances_exist_p; + + -- This function is used internally by insert_instances + function get_value ( + parameter_name in apm_parameters.parameter_name%TYPE + ) return apm_parameter_values.attr_value%TYPE + is + package_id apm_packages.package_id%TYPE; + begin + select package_id into package_id + from apm_packages + where package_key = 'acs-events'; + + return apm.get_value(package_id, parameter_name); + end get_value; + + -- This function is used internally by insert_instances + function new_instance ( + event_id in acs_events.event_id%TYPE, + date_offset in integer + ) return acs_events.event_id%TYPE + is + event acs_events%ROWTYPE; + object acs_objects%ROWTYPE; + new_event_id acs_events.event_id%TYPE; + new_timespan_id acs_events.timespan_id%TYPE; + begin + select * into event + from acs_events + where event_id = new_instance.event_id; + + select * into object + from acs_objects + where object_id = event_id; + + new_timespan_id := timespan.copy(event.timespan_id, date_offset); + + new_event_id := new( + name => event.name, + description => event.description, + html_p => event.html_p, + status_summary => event.status_summary, + timespan_id => new_timespan_id, + activity_id => event.activity_id, + recurrence_id => event.recurrence_id, + creation_user => object.creation_user, + creation_ip => object.creation_ip, + context_id => object.context_id + ); + + return new_event_id; + end new_instance; + + procedure insert_instances ( + event_id in acs_events.event_id%TYPE, + cutoff_date in date default null + ) + is + event acs_events%ROWTYPE; + recurrence recurrences%ROWTYPE; + new_event_id acs_events.event_id%TYPE; + interval_name recurrence_interval_types.interval_name%TYPE; + n_intervals recurrence.every_nth_interval%TYPE; + days_of_week recurrence.days_of_week%TYPE; + last_date_done date; + stop_date date; + start_date date; + event_date date; + diff integer; + current_date date; + v_last_day date; + week_date date; + instance_count integer; + days_length integer; + days_index integer; + day_num integer; + begin + select * into event + from acs_events + where event_id = insert_instances.event_id; + + select * into recurrence + from recurrences + where recurrence_id = event.recurrence_id; + + -- Set cutoff date + -- EventFutureLimit is in years. + if cutoff_date is null then + stop_date := add_months(sysdate, 12 * get_value('EventFutureLimit')); + else + stop_date := cutoff_date; + end if; + + -- Events only populated until max(cutoff_date, recur_until) + -- If recur_until null, then defaults to cutoff_date + if recurrence.recur_until < stop_date then + stop_date := recurrence.recur_until; + end if; + + -- Figure out the date to start from + select trunc(min(start_date)) + into event_date + from acs_events_dates + where event_id = insert_instances.event_id; + + if recurrence.db_populated_until is null then + start_date := event_date; + else + start_date := recurrence.db_populated_until; + end if; + + current_date := start_date; + last_date_done := start_date; + n_intervals := recurrence.every_nth_interval; + + -- Case off of the interval_name to make code easier to read + select interval_name into interval_name + from recurrences r, + recurrence_interval_types t + where recurrence_id = recurrence.recurrence_id + and r.interval_type = t.interval_type; + + -- Week has to be handled specially. + -- Start with the beginning of the week containing the start date. + + if interval_name = 'week' then + current_date := NEXT_DAY(current_date - 7, 'SUNDAY'); + days_of_week := recurrence.days_of_week; + days_length := LENGTH(days_of_week); + end if; + + -- Check count to prevent runaway in case of error + instance_count := 0; + while instance_count < 10000 and (trunc(last_date_done) <= trunc(stop_date)) + loop + instance_count := instance_count + 1; + + -- Calculate next date based on interval type + if interval_name = 'day' then + current_date := current_date + n_intervals; + elsif interval_name = 'month_by_date' then + current_date := ADD_MONTHS(current_date, n_intervals); + elsif interval_name = 'month_by_day' then + -- Find last day of month before correct month + v_last_day := ADD_MONTHS(LAST_DAY(current_date), n_intervals - 1); + -- Find correct week and go to correct day of week + current_date := NEXT_DAY(v_last_day + (7 * (to_char(current_date, 'W') - 1)), + to_char(current_date, 'DAY')); + elsif interval_name = 'last_of_month' then + -- Find last day of correct month + v_last_day := LAST_DAY(ADD_MONTHS(current_date, n_intervals)); + -- Back up one week and find correct day of week + current_date := NEXT_DAY(v_last_day - 7, to_char(current_date, 'DAY')); + elsif interval_name = 'year' then + current_date := ADD_MONTHS(current_date, 12 * n_intervals); + -- Deal with custom function + elsif interval_name = 'custom' then + execute immediate 'current_date := ' || + recurrence.custom_func || '(' || current_date || ', ' || n_intervals || ');'; + end if; + + -- Check to make sure we're not going past Trunc because dates aren't integral + exit when trunc(current_date) > trunc(stop_date); + + -- Have to handle week specially + if interval_name = 'week' then + -- loop over days_of_week extracting each day number + -- add day number and insert + days_index := 1; + week_date := current_date; + while days_index <= days_length loop + day_num := SUBSTR(days_of_week, days_index, 1); + week_date := current_date + day_num; + if trunc(week_date) > trunc(start_date) and trunc(week_date) <= trunc(stop_date) then + -- This is where we add the event + new_event_id := new_instance( + event_id, + trunc(week_date) - trunc(event_date) + ); + last_date_done := week_date; + elsif trunc(week_date) > trunc(stop_date) then + -- Gone too far + exit; + end if; + days_index := days_index + 2; + end loop; + + -- Now move to next week with repeats. + current_date := current_date + 7 * n_intervals; + else + -- All other interval types + -- This is where we add the event + new_event_id := new_instance( + event_id, + trunc(current_date) - trunc(event_date) + ); + last_date_done := current_date; + end if; + end loop; + + update recurrences + set db_populated_until = last_date_done + where recurrence_id = recurrence.recurrence_id; + + end insert_instances; + + + procedure shift ( + event_id in acs_events.event_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ) + is + begin + update acs_events_dates + set start_date = start_date + start_offset, + end_date = end_date + end_offset + where event_id = shift.event_id; + end shift; + + procedure shift_all ( + event_id in acs_events.event_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ) + is + begin + update acs_events_dates + set start_date = start_date + start_offset, + end_date = end_date + end_offset + where recurrence_id = (select recurrence_id + from acs_events + where event_id = shift_all.event_id); + end shift_all; + + procedure shift_all ( + recurrence_id in recurrences.recurrence_id%TYPE default null, + start_offset in number default 0, + end_offset in number default 0 + ) + is + begin + update acs_events_dates + set start_date = start_date + start_offset, + end_date = end_date + end_offset + where recurrence_id = shift_all.recurrence_id; + end shift_all; + +end acs_event; +/ +show errors + +-- packages/acs-events/sql/activity-create.sql +-- +-- @author W. Scott Meeks +-- @author Gary Jin (gjin@arsdigita.com) +-- $Id: upgrade-0.3d-0.4d.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- +-- The activity object + + +create or replace package acs_activity +as + function new ( + -- Create a new activity + -- @author W. Scott Meeks + -- @param activity_id optional id to use for new activity + -- @param name Name of the activity + -- @param description optional description of the activity + -- @param html_p optional description is html + -- @param status_summary optional additional status to display + -- @param object_type 'acs_activity' + -- @param creation_date default sysdate + -- @param creation_user acs_object param + -- @param creation_ip acs_object param + -- @param context_id acs_object param + -- @return The id of the new activity. + -- + activity_id in acs_activities.activity_id%TYPE default null, + name in acs_activities.name%TYPE, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default 'f', + status_summary in acs_activities.status_summary%TYPE default null, + object_type in acs_object_types.object_type%TYPE default 'acs_activity', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_activities.activity_id%TYPE; + + function name ( + -- name method + -- @author gjin@arsdigita.com + -- @param activity_id + -- + activity_id in acs_activities.activity_id%TYPE + + ) return acs_activities.name%TYPE; + + procedure del ( + -- Deletes an activity + -- @author W. Scott Meeks + -- @param activity_id id of activity to delete + activity_id in acs_activities.activity_id%TYPE + ); + + + -- NOTE: can't use update + + procedure edit ( + -- Update the name or description of an activity + -- @author W. Scott Meeks + -- @param activity_id activity to update + -- @param name optional New name for this activity + -- @param description optional New description for this activity + -- @param html_p optional New value of html_p for this activity + activity_id in acs_activities.activity_id%TYPE, + name in acs_activities.name%TYPE default null, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default null, + status_summary in acs_activities.status_summary%TYPE default null + ); + + procedure object_map ( + -- Adds an object mapping to an activity + -- @author W. Scott Meeks + -- @param activity_id id of activity to add mapping to + -- @param object_id id of object to add mapping for + -- + activity_id in acs_activities.activity_id%TYPE, + object_id in acs_objects.object_id%TYPE + ); + + procedure object_unmap ( + -- Deletes an object mapping from an activity + -- @author W. Scott Meeks + -- @param activity_id activity to delete mapping from + -- @param object_id object to delete mapping for + -- + activity_id in acs_activities.activity_id%TYPE, + object_id in acs_objects.object_id%TYPE + ); + +end acs_activity; +/ +show errors + +create or replace package body acs_activity +as + function new ( + activity_id in acs_activities.activity_id%TYPE default null, + name in acs_activities.name%TYPE, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default 'f', + status_summary in acs_activities.status_summary%TYPE default null, + object_type in acs_object_types.object_type%TYPE default 'acs_activity', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_activities.activity_id%TYPE + is + new_activity_id acs_activities.activity_id%TYPE; + begin + new_activity_id := acs_object.new( + object_id => activity_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into acs_activities + (activity_id, name, description, html_p, status_summary) + values + (new_activity_id, name, description, html_p, status_summary); + + return new_activity_id; + end new; + + + function name ( + -- name method + -- @author gjin@arsdigita.com + -- @param activity_id + -- + activity_id in acs_activities.activity_id%TYPE + + ) return acs_activities.name%TYPE + + is + new_activity_name acs_activities.name%TYPE; + + begin + select name + into new_activity_name + from acs_activities + where activity_id = name.activity_id; + + return new_activity_name; + end; + + + procedure del ( + activity_id in acs_activities.activity_id%TYPE + ) + is + begin + -- Cascade will cause delete from acs_activities + -- and acs_activity_object_map + + acs_object.del(activity_id); + end del; + + -- NOTE: can't use update + + procedure edit ( + activity_id in acs_activities.activity_id%TYPE, + name in acs_activities.name%TYPE default null, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default null, + status_summary in acs_activities.status_summary%TYPE default null + ) + is + begin + update acs_activities + set name = nvl(edit.name, name), + description = nvl(edit.description, description), + html_p = nvl(edit.html_p, html_p), + status_summary = nvl(edit.status_summary, status_summary) + where activity_id = edit.activity_id; + end edit; + + procedure object_map ( + activity_id in acs_activities.activity_id%TYPE, + object_id in acs_objects.object_id%TYPE + ) + is + begin + insert into acs_activity_object_map + (activity_id, object_id) + values + (activity_id, object_id); + end object_map; + + procedure object_unmap ( + activity_id in acs_activities.activity_id%TYPE, + object_id in acs_objects.object_id%TYPE + ) + is + begin + delete from acs_activity_object_map + where activity_id = object_unmap.activity_id + and object_id = object_unmap.object_id; + end object_unmap; + +end acs_activity; +/ +show errors + + +-- packages/acs-events/sql/recurrence-create.sql +-- +-- Support for temporal recurrences +-- +-- $Id: upgrade-0.3d-0.4d.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +-- These columns describe how an event recurs. The are modeled on the Palm DateBook. +-- The interval_type 'custom' indicates that the PL/SQL function referenced in +-- custom_func should be used to generate the recurrences. + +create or replace package recurrence +as + function new ( + -- Creates a new recurrence + -- @author W. Scott Meeks + -- @param interval_type Sets interval_type of new recurrence + -- @param every_nth_interval Sets every_nth_interval of new recurrence + -- @param days_of_week optional If provided, sets days_of_week + -- of new recurrence + -- @param recur_until optional If provided, sets recur_until + -- of new recurrence + -- @param custom_func optional If provided, set name of + -- custom recurrence function + -- @return id of new recurrence + -- + interval_type in recurrence_interval_types.interval_name%TYPE, + every_nth_interval in recurrences.every_nth_interval%TYPE, + days_of_week in recurrences.days_of_week%TYPE default null, + recur_until in recurrences.recur_until%TYPE default null, + custom_func in recurrences.custom_func%TYPE default null + ) return recurrences.recurrence_id%TYPE; + + procedure del ( + -- Deletes the recurrence + -- @author W. Scott Meeks + -- @param recurrence_id id of recurrence to delete + -- + recurrence_id in recurrences.recurrence_id%TYPE + ); + +end recurrence; +/ +show errors + +create or replace package body recurrence +as + function new ( + interval_type in recurrence_interval_types.interval_name%TYPE, + every_nth_interval in recurrences.every_nth_interval%TYPE, + days_of_week in recurrences.days_of_week%TYPE default null, + recur_until in recurrences.recur_until%TYPE default null, + custom_func in recurrences.custom_func%TYPE default null + ) return recurrences.recurrence_id%TYPE + is + recurrence_id recurrences.recurrence_id%TYPE; + interval_type_id recurrence_interval_types.interval_type%TYPE; + begin + select recurrence_seq.nextval into recurrence_id from dual; + + select interval_type + into interval_type_id + from recurrence_interval_types + where interval_name = new.interval_type; + + insert into recurrences + (recurrence_id, + interval_type, + every_nth_interval, + days_of_week, + recur_until, + custom_func) + values + (recurrence_id, + interval_type_id, + every_nth_interval, + days_of_week, + recur_until, + custom_func); + + return recurrence_id; + end new; + + -- Note: this will fail if there are any events_with this recurrence + procedure del ( + recurrence_id in recurrences.recurrence_id%TYPE + ) + is + begin + delete from recurrences + where recurrence_id = recurrence.del.recurrence_id; + end del; + +end recurrence; +/ +show errors + + +-- packages/acs-events/sql/timespan-create.sql +-- + +create or replace package time_interval +as + function new ( + -- Creates a new time interval + -- @author W. Scott Meeks + -- @param start_date optional Sets this as start_date of new interval + -- @param end_date optional Sets this as end_date of new interval + -- @return id of new time interval + -- + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return time_intervals.interval_id%TYPE; + + procedure del ( + -- Deletes the given time interval + -- @author W. Scott Meeks + -- @param interval_id id of the interval to delete + -- + interval_id in time_intervals.interval_id%TYPE + ); + + -- NOTE: update is reserved and cannot be used for PL/SQL procedure names + + procedure edit ( + -- Updates the start_date or end_date of an interval + -- @author W. Scott Meeks + -- @param interval_id id of the interval to update + -- @param start_date optional If provided, sets this as the new + -- start_date of the interval. + -- @param end_date optional If provided, sets this as the new + -- start_date of the interval. + -- + interval_id in time_intervals.interval_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ); + + procedure shift ( + -- Updates the start_date or end_date of an interval based on offsets of + -- fractional days. + -- @author W. Scott Meeks + -- @param interval_id The interval to update. + -- @param start_offset optional If provided, adds this number to the + -- start_date of the interval. No effect if + -- start_date is null. + -- @param end_offset optional If provided, adds this number to the + -- end_date of the interval. No effect if + -- end_date is null. + -- + interval_id in time_intervals.interval_id%TYPE, + start_offset in number default 0, + end_offset in number default 0 + ); + + function overlaps_p ( + -- Returns 't' if the two intervals overlap, 'f' otherwise. + -- @author W. Scott Meeks + -- @param interval_1_id + -- @param interval_2_id + -- @return 't' or 'f' + -- + interval_1_id in time_intervals.interval_id%TYPE, + interval_2_id in time_intervals.interval_id%TYPE + ) return char; + + function overlaps_p ( + -- Returns 't if the interval bounded by the given start_date or + -- end_date overlaps the given interval, 'f' otherwise. + -- @author W. Scott Meeks + -- @param start_date optional If provided, see if it overlaps + -- the interval. + -- @param end_date optional If provided, see if it overlaps + -- the interval. + -- @return 't' or 'f' + -- + interval_id in time_intervals.interval_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return char; + + function overlaps_p ( + start_1 in time_intervals.start_date%TYPE, + end_1 in time_intervals.end_date%TYPE, + start_2 in time_intervals.start_date%TYPE, + end_2 in time_intervals.end_date%TYPE + ) return char; + + function eq ( + -- Checks if two intervals are equivalent + -- @author W. Scott Meeks + -- @param interval_1_id First interval + -- @param interval_2_id Second interval + -- @return boolean + -- + interval_1_id in time_intervals.interval_id%TYPE, + interval_2_id in time_intervals.interval_id%TYPE + ) return boolean; + + function copy ( + -- Creates a new copy of a time interval, offset by optional offset + -- @author W. Scott Meeks + -- @param interval_id Interval to copy + -- @param offset optional If provided, interval is + -- offset by this number of days. + -- @return interval_id + -- + interval_id in time_intervals.interval_id%TYPE, + offset in integer default 0 + ) return time_intervals.interval_id%TYPE; + +end time_interval; +/ +show errors + +create or replace package body time_interval +as + function new ( + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return time_intervals.interval_id%TYPE + is + interval_id time_intervals.interval_id%TYPE; + begin + select timespan_seq.nextval into interval_id from dual; + + insert into time_intervals + (interval_id, start_date, end_date) + values + (interval_id, start_date, end_date); + + return interval_id; + end new; + + procedure del ( + interval_id in time_intervals.interval_id%TYPE + ) + is + begin + delete time_intervals + where interval_id = time_interval.del.interval_id; + end del; + + procedure edit ( + interval_id in time_intervals.interval_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) + is + begin + -- Null for start_date or end_date means don't change. + if start_date is not null and end_date is not null then + update time_intervals + set start_date = edit.start_date, + end_date = edit.end_date + where interval_id = edit.interval_id; + elsif start_date is not null then + update time_intervals + set start_date = edit.start_date + where interval_id = edit.interval_id; + elsif end_date is not null then + update time_intervals + set end_date = edit.end_date + where interval_id = edit.interval_id; + end if; + end edit; + + procedure shift ( + interval_id in time_intervals.interval_id%TYPE, + start_offset in number default 0, + end_offset in number default 0 + ) + is + begin + update time_intervals + set start_date = start_date + start_offset, + end_date = end_date + end_offset + where interval_id = shift.interval_id; + end shift; + + function overlaps_p ( + interval_1_id in time_intervals.interval_id%TYPE, + interval_2_id in time_intervals.interval_id%TYPE + ) return char + is + start_1 date; + start_2 date; + end_1 date; + end_2 date; + begin + -- Pull out the start and end dates and call the main overlaps_p. + select start_date, + end_date + into start_1, + end_1 + from time_intervals + where interval_id = interval_1_id; + + select start_date, + end_date + into start_2, + end_2 + from time_intervals + where interval_id = interval_2_id; + + return overlaps_p(start_1, end_1, start_2, end_2); + end overlaps_p; + + function overlaps_p ( + interval_id in time_intervals.interval_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return char + is + interval_start time_intervals.start_date%TYPE; + interval_end time_intervals.end_date%TYPE; + begin + -- Pull out the start and end date and call the main overlaps_p. + select start_date, + end_date + into interval_start, + interval_end + from time_intervals + where interval_id = overlaps_p.interval_id; + + return overlaps_p(interval_start, interval_end, start_date, end_date); + end overlaps_p; + + function overlaps_p ( + start_1 in time_intervals.start_date%TYPE, + end_1 in time_intervals.end_date%TYPE, + start_2 in time_intervals.start_date%TYPE, + end_2 in time_intervals.end_date%TYPE + ) return char + is + begin + if start_1 is null then + -- No overlap if 2nd interval starts after 1st ends + if end_1 < start_2 then + return 'f'; + else + return 't'; + end if; + elsif start_2 is null then + -- No overlap if 2nd interval ends before 1st starts + if end_2 < start_1 then + return 'f'; + else + return 't'; + end if; + -- Okay, both start dates are not null + elsif start_1 <= start_2 then + -- 1st starts before 2nd + if end_1 < start_2 then + -- No overlap if 1st ends before 2nd starts + return 'f'; + else + -- No overlap or at least one null + return 't'; + end if; + else + -- 1st starts after 2nd + if end_2 < start_1 then + -- No overlap if 2nd ends before 1st starts + return 'f'; + else + -- No overlap or at least one null + return 't'; + end if; + end if; + end overlaps_p; + + function eq ( + -- Checks if two intervals are equivalent + interval_1_id in time_intervals.interval_id%TYPE, + interval_2_id in time_intervals.interval_id%TYPE + ) return boolean + is + interval_1 time_intervals%ROWTYPE; + interval_2 time_intervals%ROWTYPE; + begin + select * into interval_1 + from time_intervals + where interval_id = interval_1_id; + + select * into interval_2 + from time_intervals + where interval_id = interval_2_id; + + if interval_1.start_date = interval_2.start_date and + interval_1.end_date = interval_2.end_date then + return true; + else + return false; + end if; + end eq; + + function copy ( + interval_id in time_intervals.interval_id%TYPE, + offset in integer default 0 + ) return time_intervals.interval_id%TYPE + is + interval time_intervals%ROWTYPE; + begin + select * into interval + from time_intervals + where interval_id = copy.interval_id; + + return new(interval.start_date + offset, interval.end_date + offset); + end copy; + +end time_interval; +/ +show errors + + +create or replace package timespan +as + function new ( + -- Creates a new timespan (20.20.10) + -- given a time_interval + -- Copies the interval so the caller is responsible for deleting it + interval_id in time_intervals.interval_id%TYPE default null + ) return timespans.timespan_id%TYPE; + + function new ( + -- Creates a new timespan (20.20.10) + -- given a start_date and end_date + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return timespans.timespan_id%TYPE; + + procedure del ( + -- Deletes the timespan and any contained intervals + -- @author W. Scott Meeks + -- @param timespan_id id of timespan to delete + timespan_id in timespans.timespan_id%TYPE + ); + + -- Join a new timespan or time interval to an existing timespan + + procedure join ( + -- timespan_1_id is modified, timespan_2_id is not + timespan_1_id in timespans.timespan_id%TYPE, + timespan_2_id in timespans.timespan_id%TYPE + ); + + -- Unfortunately, Oracle can't distinguish the signature of this function + -- with the previous because the args have the same underlying types + -- + procedure join_interval ( + -- interval is copied to the timespan + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE, + copy_p in boolean default true + ); + + procedure join ( + timespan_id in timespans.timespan_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ); + + + procedure interval_delete ( + -- Deletes an interval from the given timespan + -- @author W. Scott Meeks + -- @param timespan_id timespan to delete from + -- @param interval_id delete this interval from the set + -- + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE + ); + + -- Information + + function exists_p ( + -- If its contained intervals are all deleted, then a timespan will + -- automatically be deleted. This checks a timespan_id to make sure it's + -- still valid. + -- @author W. Scott Meeks + -- @param timespan_id id of timespan to check + -- @return 't' or 'f' + timespan_id in timespans.timespan_id%TYPE + ) return char; + + function multi_interval_p ( + -- Returns 't' if timespan contains more than one interval, + -- 'f' otherwise ( + -- @author W. Scott Meeks + -- @param timespan_id id of set to check + -- @return 't' or 'f' + timespan_id in timespans.timespan_id%TYPE + ) return char; + + + function overlaps_p ( + -- Checks to see if a given interval overlaps any of the intervals + -- in the given timespan. + timespan_1_id in timespans.timespan_id%TYPE, + timespan_2_id in timespans.timespan_id%TYPE + ) return char; + + -- Unfortunately, Oracle can't distinguish the signature of this function + -- with the previous because the args have the same underlying types + -- + function overlaps_interval_p ( + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE default null + ) return char; + + function overlaps_p ( + timespan_id in timespans.timespan_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return char; + + function copy ( + -- Creates a new copy of a timespan, offset by optional offset + -- @author W. Scott Meeks + -- @param timespan_id Timespan to copy + -- @param offset optional If provided, all dates in timespan + -- are offset by this number of days. + -- @return timespan_id + -- + timespan_id in timespans.timespan_id%TYPE, + offset in integer default 0 + ) return timespans.timespan_id%TYPE; + +end timespan; +/ +show errors + +create or replace package body timespan +as + function new ( + interval_id in time_intervals.interval_id%TYPE + ) return timespans.timespan_id%TYPE + is + timespan_id timespans.timespan_id%TYPE; + new_interval_id time_intervals.interval_id%TYPE; + begin + select timespan_seq.nextval into timespan_id from dual; + + new_interval_id := time_interval.copy(interval_id); + + insert into timespans + (timespan_id, interval_id) + values + (timespan_id, new_interval_id); + + return timespan_id; + end new; + + function new ( + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return timespans.timespan_id%TYPE + is + begin + return new(time_interval.new(start_date, end_date)); + end new; + + procedure del ( + timespan_id in timespans.timespan_id%TYPE + ) + is + begin + -- Delete intervals, corresponding timespan entries deleted by + -- cascading constraints + delete from time_intervals + where interval_id in (select interval_id + from timespans + where timespan_id = timespan.del.timespan_id); + end del; + + -- + -- Join a new timespan or time interval to an existing timespan + -- + procedure join ( + timespan_1_id in timespans.timespan_id%TYPE, + timespan_2_id in timespans.timespan_id%TYPE + ) + is + cursor timespan_cursor is + select * + from timespans + where timespan_id = timespan_2_id; + timespan_val timespan_cursor%ROWTYPE; + begin + -- Loop over intervals in 2nd timespan, join with 1st. + for timespan_val in timespan_cursor + loop + join_interval(timespan_1_id, timespan_val.interval_id); + end loop; + end join; + + -- Optional argument to copy interval + procedure join_interval ( + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE, + copy_p in boolean default true + ) + is + new_interval_id time_intervals.interval_id%TYPE; + begin + if copy_p then + new_interval_id := time_interval.copy(interval_id); + else + new_interval_id := interval_id; + end if; + + insert into timespans + (timespan_id, interval_id) + values + (timespan_id, new_interval_id); + end join_interval; + + procedure join ( + timespan_id in timespans.timespan_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) + is + begin + join_interval( + timespan_id => timespan_id, + interval_id => time_interval.new(start_date, end_date), + copy_p => false + ); + end join; + + procedure interval_delete ( + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE + ) + is + begin + delete from timespans + where timespan_id = interval_delete.timespan_id + and interval_id = interval_delete.interval_id; + end interval_delete; + + -- Information + + function exists_p ( + timespan_id in timespans.timespan_id%TYPE + ) return char + is + result integer; + begin + -- Only need to check if any rows exist. + select count(*) + into result + from dual + where exists (select timespan_id + from timespans + where timespan_id = exists_p.timespan_id); + if result = 0 then + return 'f'; + else + return 't'; + end if; + end exists_p; + + function multi_interval_p ( + timespan_id in timespans.timespan_id%TYPE + ) return char + is + result char; + begin + -- 'f' if 0 or 1 intervals, 't' otherwise + select decode(count(timespan_id), 0, 'f', 1, 'f', 't') + into result + from timespans + where timespan_id = multi_interval_p.timespan_id; + + return result; + end multi_interval_p; + + + function overlaps_p ( + -- Checks to see if any intervals in a timespan overlap any of the intervals + -- in the second timespan. + timespan_1_id in timespans.timespan_id%TYPE, + timespan_2_id in timespans.timespan_id%TYPE + ) return char + is + result char; + cursor timespan_cursor is + select * + from timespans + where timespan_id = timespan_2_id; + timespan_val timespan_cursor%ROWTYPE; + begin + -- Loop over 2nd timespan, checking each interval against 1st + for timespan_val in timespan_cursor + loop + result := overlaps_interval_p + (timespan_1_id, + timespan_val.interval_id + ); + if result = 't' then + return 't'; + end if; + end loop; + return 'f'; + end overlaps_p; + + function overlaps_interval_p ( + timespan_id in timespans.timespan_id%TYPE, + interval_id in time_intervals.interval_id%TYPE default null + ) return char + is + start_date date; + end_date date; + begin + select start_date, end_date + into start_date, end_date + from time_intervals + where interval_id = overlaps_interval_p.interval_id; + + return overlaps_p(timespan_id, start_date, end_date); + end overlaps_interval_p; + + function overlaps_p ( + timespan_id in timespans.timespan_id%TYPE, + start_date in time_intervals.start_date%TYPE default null, + end_date in time_intervals.end_date%TYPE default null + ) return char + is + result char; + cursor timespan_cursor is + select * + from timespans + where timespan_id = overlaps_p.timespan_id; + timespan_val timespan_cursor%ROWTYPE; + begin + -- Loop over each interval in timespan, checking against dates. + for timespan_val in timespan_cursor + loop + result := time_interval.overlaps_p( + timespan_val.interval_id, + start_date, + end_date + ); + + if result = 't' then + return 't'; + end if; + end loop; + return 'f'; + end overlaps_p; + + function copy ( + timespan_id in timespans.timespan_id%TYPE, + offset in integer default 0 + ) return timespans.timespan_id%TYPE + is + cursor timespan_cursor is + select * + from timespans + where timespan_id = copy.timespan_id; + timespan_val timespan_cursor%ROWTYPE; + new_interval_id timespans.interval_id%TYPE; + new_timespan_id timespans.timespan_id%TYPE; + begin + new_timespan_id := null; + + -- Loop over each interval in timespan, creating a new copy + for timespan_val in timespan_cursor + loop + new_interval_id := time_interval.copy(timespan_val.interval_id, offset); + + if new_timespan_id is null then + new_timespan_id := new(new_interval_id); + else + join_interval(new_timespan_id, new_interval_id); + end if; + end loop; + return new_timespan_id; + end copy; + +end timespan; +/ +show errors + Index: openacs-4/packages/acs-interface/sql/oracle/upgrade-4.0.1-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-interface/sql/oracle/upgrade-4.0.1-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-interface/sql/oracle/upgrade-4.0.1-5.0d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,424 @@ +-- +-- packages/acs-interfaces/sql/acs-interface-create.sql +-- +-- @author khy@arsdigita.com +-- @creation-date 2000-11-24 +-- @cvs-id $Id: upgrade-4.0.1-5.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +create or replace package acs_interface +as + function new ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + enabled_p in acs_interfaces.enabled_p%TYPE, + description in acs_interfaces.description%TYPE, + creation_date in acs_interfaces.creation_date%TYPE default sysdate, + creation_user in acs_interfaces.creation_user%TYPE default null, + creation_ip in acs_interfaces.creation_ip%TYPE default null + ) return acs_interfaces.interface_id%TYPE; + + procedure del ( + interface_id in acs_interfaces.interface_id%TYPE + ); + procedure del ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE + ); + procedure assoc_obj_type_with_interface ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE, + object_type_imp in varchar2 default null + ); + + procedure remove_obj_type_impl ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ); + + function get_interface_id ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE + ) return acs_interfaces.interface_id%TYPE; + + function add_method ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + method_name in acs_interface_methods.method_name%TYPE, + method_type in acs_interface_methods.method_type%TYPE, + return_type in acs_interface_methods.return_type%TYPE, + method_desc in acs_interface_methods.method_desc%TYPE + ) return acs_interface_methods.method_id%TYPE; + + procedure add_param_to_method ( + method_id in acs_interface_method_params.method_id%TYPE, + param_name in acs_interface_method_params.param_name%TYPE, + param_type in acs_interface_method_params.param_type%TYPE, + position in acs_interface_method_params.position%TYPE default null, + param_desc in acs_interface_method_params.param_desc%TYPE default null, + param_spec in acs_interface_method_params.param_spec%TYPE default null, + param_ref_p in acs_interface_method_params.param_ref_p%TYPE default 'f', + required_p in acs_interface_method_params.required_p%TYPE default 't' + ); + + procedure remove_method ( + method_id in acs_interface_methods.method_id%TYPE + ); + + procedure remove_param_from_method ( + method_id in acs_interface_methods.method_id%TYPE, + position in acs_interface_method_params.position%TYPE + ); + + function object_type_implement_p ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ) return char; + + function object_id_implement_p ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_id in acs_objects.object_id%TYPE + ) return char; + + -- returns the object type that provides the implementation for passed in + -- object type, if none specified then return the object type + function obj_provide_implement ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ) return varchar2; + +end acs_interface; +/ + + +create or replace package body acs_interface +as + function new ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + enabled_p in acs_interfaces.enabled_p%TYPE, + description in acs_interfaces.description%TYPE, + creation_date in acs_interfaces.creation_date%TYPE default sysdate, + creation_user in acs_interfaces.creation_user%TYPE default null, + creation_ip in acs_interfaces.creation_ip%TYPE default null + ) return acs_interfaces.interface_id%TYPE + is + v_interface_id integer; + begin + + select acs_interface_all_id_sequence.nextval into v_interface_id + from dual; + + insert into acs_interfaces ( + interface_id, + interface_name, + programming_language, + enabled_p, + description, + creation_date, + creation_user, + creation_ip + ) values ( + v_interface_id, + interface_name, + programming_language, + enabled_p, + description, + creation_date, + creation_user, + creation_ip + ); + return v_interface_id; + end new; + + procedure del ( + interface_id in acs_interfaces.interface_id%TYPE + ) + is + begin + + delete from acs_interfaces + where interface_id = acs_interface.del.interface_id; + end del; + + procedure del ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE + ) + is + v_interface_id integer; + begin + delete from acs_interfaces + where interface_name = acs_interface.del.interface_name + and programming_language = acs_interface.del.programming_language; + + return; + + end del; + + procedure assoc_obj_type_with_interface ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE, + object_type_imp in varchar2 default null + ) + is + v_interface_id integer; + begin + + v_interface_id := acs_interface.get_interface_id ( + interface_name => interface_name, + programming_language => programming_language + ); + + insert into acs_interface_obj_type_map ( + interface_id, + object_type, + object_type_impl_interface + ) values ( + v_interface_id, + object_type, + object_type_imp + ); + end assoc_obj_type_with_interface; + + procedure remove_obj_type_impl ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ) + is + begin + delete from acs_interface_obj_type_map + where object_type = remove_obj_type_impl.object_type + and interface_id = get_interface_id (interface_name, programming_language); + end; + + + function get_interface_id ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE + ) return acs_interfaces.interface_id%TYPE + is + v_interface_id integer; + begin + select interface_id into v_interface_id + from acs_interfaces + where interface_name = acs_interface.get_interface_id.interface_name + and programming_language = acs_interface.get_interface_id.programming_language; + + return v_interface_id; + + exception + when no_data_found then + raise_application_error(-20001, 'Interface for '|| programming_language ||' '||interface_name|| 'does not exist!'); + + end get_interface_id; + + function add_method ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + method_name in acs_interface_methods.method_name%TYPE, + method_type in acs_interface_methods.method_type%TYPE, + return_type in acs_interface_methods.return_type%TYPE, + method_desc in acs_interface_methods.method_desc%TYPE default null + ) return acs_interface_methods.method_id%TYPE + is + v_interface_id integer; + v_method_id integer; + begin + + v_interface_id := acs_interface.get_interface_id ( + interface_name => interface_name, + programming_language => programming_language); + + select acs_interface_all_id_sequence.nextval into v_method_id + from dual; + + insert into acs_interface_methods ( + interface_id, + method_id, + method_name, + method_type, + return_type, + method_desc + ) values ( + v_interface_id, + v_method_id, + method_name, + method_type, + return_type, + method_desc + ); + return v_method_id; + end add_method; + + -- position is null indicates the last parameter + -- if not null, shift parameters to the right and insert + procedure add_param_to_method ( + method_id in acs_interface_method_params.method_id%TYPE , + param_name in acs_interface_method_params.param_name%TYPE , + param_type in acs_interface_method_params.param_type%TYPE , + position in acs_interface_method_params.position%TYPE default null, + param_desc in acs_interface_method_params.param_desc%TYPE default null, + param_spec in acs_interface_method_params.param_spec%TYPE default null, + param_ref_p in acs_interface_method_params.param_ref_p%TYPE default 'f', + required_p in acs_interface_method_params.required_p%TYPE default 't' + ) + is + v_isnull integer; + begin + select decode (position,null,1,0) into v_isnull + from dual; + + + if v_isnull = 0 then + -- if the position is not null + -- Increment the other params' positions whose + -- placement is at the specified 'position' or higher. + update acs_interface_method_params + set position = position + 1 + where method_id >= acs_interface.add_param_to_method.param_name; + + -- insert the new parameter at the specified 'position' + insert into acs_interface_method_params ( + method_id , + param_name , + param_type , + param_ref_p , + param_desc , + param_spec , + position , + required_p + ) values ( + acs_interface.add_param_to_method.method_id , + acs_interface.add_param_to_method.param_name , + acs_interface.add_param_to_method.param_type , + acs_interface.add_param_to_method.param_ref_p , + acs_interface.add_param_to_method.param_desc , + acs_interface.add_param_to_method.param_spec , + acs_interface.add_param_to_method.position , + acs_interface.add_param_to_method.required_p + ); + else + -- Position was not specified, place the new parameter at the end of the parameter list. + + insert into acs_interface_method_params ( + method_id , + param_name , + param_type , + param_ref_p , + param_desc , + param_spec , + required_p , + position + ) select acs_interface.add_param_to_method.method_id, + acs_interface.add_param_to_method.param_name , + acs_interface.add_param_to_method.param_type , + acs_interface.add_param_to_method.param_ref_p , + acs_interface.add_param_to_method.param_desc , + acs_interface.add_param_to_method.param_spec , + acs_interface.add_param_to_method.required_p , + decode(max(position),null,0,max(position))+1 + from acs_interface_method_params + where method_id = acs_interface.add_param_to_method.method_id; + end if; + end add_param_to_method; + + -- removes methods from the interface + procedure remove_method ( + method_id in acs_interface_methods.method_id%TYPE + ) + is + begin + delete from acs_interface_methods + where method_id = acs_interface.remove_method.method_id; + end remove_method; + + procedure remove_param_from_method ( + method_id in acs_interface_methods.method_id%TYPE, + position in acs_interface_method_params.position%TYPE + ) + is + begin + delete from acs_interface_method_params + where method_id = acs_interface.remove_param_from_method.method_id + and position = acs_interface.remove_param_from_method.position; + end remove_param_from_method; + + function object_type_implement_p ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ) return char + is + v_implement_p char(1); + begin + select decode (count(*),0,'f','t') into v_implement_p + from acs_interface_obj_type_map aiopm, + acs_interfaces ai + where aiopm.object_type = acs_interface.object_type_implement_p.object_type + and aiopm.interface_id = ai.interface_id + and ai.interface_name = acs_interface.object_type_implement_p.interface_name + and ai.programming_language = acs_interface.object_type_implement_p.programming_language; + + return v_implement_p; + end object_type_implement_p; + + function object_id_implement_p ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_id in acs_objects.object_id%TYPE + ) return char + is + v_implement_p char(1); + begin + select decode (count(*),0,'f','t') into v_implement_p + from acs_interface_obj_type_map aiopm, + acs_interfaces ai, + acs_objects ao + where ao.object_id = object_id + and aiopm.object_type = ao.object_type + and aiopm.interface_id = ai.interface_id + and ai.interface_name = acs_interface.object_id_implement_p.interface_name + and ai.programming_language = acs_interface.object_id_implement_p.programming_language; + + return v_implement_p; + + end object_id_implement_p; + + function obj_provide_implement ( + interface_name in acs_interfaces.interface_name%TYPE, + programming_language in acs_interfaces.programming_language%TYPE, + object_type in acs_object_types.object_type%TYPE + ) return varchar2 + is + object_type_imp varchar2(30); + begin + + object_type_imp := object_type; + + for obj_type_impl_row in (select object_type_impl_interface + from acs_interface_obj_type_map + where interface_id = + acs_interface.get_interface_id(interface_name,programming_language) + and object_type = acs_interface.obj_provide_implement.object_type) loop + object_type_imp := obj_type_impl_row.object_type_impl_interface; + end loop; + + return object_type_imp; + end; +end acs_interface; +/ + + + + + + + Index: openacs-4/packages/acs-kernel/sql/oracle/upgrade/upgrade-5.0d9-5.0d13.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-kernel/sql/oracle/upgrade/upgrade-5.0d9-5.0d13.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-kernel/sql/oracle/upgrade/upgrade-5.0d9-5.0d13.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,5255 @@ +-- +-- acs-kernel/sql/acs-objects-create.sql +-- +-- A base object type that provides auditing columns, permissioning, +-- attributes, and relationships to any subtypes. +-- +-- @author Michael Yoon (michael@arsdigita.com) +-- @author Rafael Schloming (rhs@mit.edu) +-- @author Jon Salz (jsalz@mit.edu) +-- +-- @creation-date 2000-05-18 +-- +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + + + +create or replace package acs_object +as + + function new ( + object_id in acs_objects.object_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'acs_object', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + object_id in acs_objects.object_id%TYPE + ); + + function name ( + object_id in acs_objects.object_id%TYPE + ) return varchar2; + + -- The acs_object_types.name_method for "acs_object" + -- + function default_name ( + object_id in acs_objects.object_id%TYPE + ) return varchar2; + + -- Determine where the attribute is stored and what sql needs to be + -- in the where clause to retreive it + -- Used in get_attribute and set_attribute + procedure get_attribute_storage ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE, + v_column out varchar2, + v_table_name out varchar2, + v_key_sql out varchar2 + ); + + -- Get/set the value of an object attribute, as long as + -- the type can be cast to varchar2 + function get_attribute ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE + ) return varchar2; + + procedure set_attribute ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE, + value_in in varchar2 + ); + + function check_representation ( + object_id in acs_objects.object_id%TYPE + ) return char; + + procedure update_last_modified ( + object_id in acs_objects.object_id%TYPE, + modifying_user in acs_objects.modifying_user%TYPE, + modifying_ip in acs_objects.modifying_ip%TYPE, + last_modified in acs_objects.last_modified%TYPE default sysdate + ); + +end acs_object; +/ +show errors + +create or replace package body acs_object +as + + procedure initialize_attributes ( + object_id in acs_objects.object_id%TYPE + ) + is + v_object_type acs_objects.object_type%TYPE; + begin + -- XXX This should be fixed to initialize supertypes properly. + + -- Initialize dynamic attributes + insert into acs_attribute_values + (object_id, attribute_id, attr_value) + select + initialize_attributes.object_id, a.attribute_id, a.default_value + from acs_attributes a, acs_objects o + where a.object_type = o.object_type + and o.object_id = initialize_attributes.object_id + and a.storage = 'generic' + and a.static_p = 'f'; + + -- Retreive type for static attributes + select object_type into v_object_type from acs_objects + where object_id = initialize_attributes.object_id; + + -- Initialize static attributes + begin + insert into acs_static_attr_values + (object_type, attribute_id, attr_value) + select + v_object_type, a.attribute_id, a.default_value + from acs_attributes a, acs_objects o + where a.object_type = o.object_type + and o.object_id = initialize_attributes.object_id + and a.storage = 'generic' + and a.static_p = 't' + and not exists (select 1 from acs_static_attr_values + where object_type = a.object_type); + exception when no_data_found then null; + end; + + end initialize_attributes; + + function new ( + object_id in acs_objects.object_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'acs_object', + 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, + context_id in acs_objects.context_id%TYPE default null + ) + return acs_objects.object_id%TYPE + is + v_object_id acs_objects.object_id%TYPE; + begin + if object_id is null then + select acs_object_id_seq.nextval + into v_object_id + from dual; + else + v_object_id := object_id; + end if; + + insert into acs_objects + (object_id, object_type, context_id, + creation_date, creation_user, creation_ip) + values + (v_object_id, object_type, context_id, + creation_date, creation_user, creation_ip); + + acs_object.initialize_attributes(v_object_id); + + return v_object_id; + end new; + + procedure del ( + object_id in acs_objects.object_id%TYPE + ) + is + v_exists_p char; + begin + + -- Delete dynamic/generic attributes + delete from acs_attribute_values where object_id = acs_object.del.object_id; + + -- Delete directly assigned permissions + -- + -- JCD: We do this as an execute rather than just a direct query since + -- the acs_permissions table is not created when this file is + -- sourced. We need to clean up the creates and once that is done + -- we can turn this into a simple delete statement. + -- + execute immediate 'delete from acs_permissions where object_id = :object_id' + using in object_id; + + for object_type + in (select table_name, id_column + from acs_object_types + start with object_type = (select object_type + from acs_objects o + where o.object_id = acs_object.del.object_id) + connect by object_type = prior supertype) + loop + -- Delete from the table if it exists. + select decode(count(*),0,'f','t') into v_exists_p + from user_tables + where table_name = upper(object_type.table_name); + + if v_exists_p = 't' then + execute immediate 'delete from ' || object_type.table_name || + ' where ' || object_type.id_column || ' = :object_id' + using in object_id; + end if; + + end loop; + + end del; + + function name ( + object_id in acs_objects.object_id%TYPE + ) + return varchar2 + is + object_name varchar2(500); + v_object_id integer := object_id; + begin + -- Find the name function for this object, which is stored in the + -- name_method column of acs_object_types. Starting with this + -- object's actual type, traverse the type hierarchy upwards until + -- a non-null name_method value is found. + -- + for object_type + in (select name_method + from acs_object_types + start with object_type = (select object_type + from acs_objects o + where o.object_id = name.object_id) + connect by object_type = prior supertype) + loop + if object_type.name_method is not null then + + -- Execute the first name_method we find (since we're traversing + -- up the type hierarchy from the object's exact type) using + -- Native Dynamic SQL, to ascertain the name of this object. + -- + --execute immediate 'select ' || object_type.name_method || '(:1) from dual' + execute immediate 'begin :1 := ' || object_type.name_method || '(:2); end;' + using out object_name, in object_id; + --into object_name + + exit; + end if; + end loop; + + return object_name; + end name; + + function default_name ( + object_id in acs_objects.object_id%TYPE + ) return varchar2 + is + object_type_pretty_name acs_object_types.pretty_name%TYPE; + begin + select ot.pretty_name + into object_type_pretty_name + from acs_objects o, acs_object_types ot + where o.object_id = default_name.object_id + and o.object_type = ot.object_type; + + return object_type_pretty_name || ' ' || object_id; + end default_name; + + procedure get_attribute_storage ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE, + v_column out varchar2, + v_table_name out varchar2, + v_key_sql out varchar2 + ) + is + v_object_type acs_attributes.object_type%TYPE; + v_static acs_attributes.static_p%TYPE := null; + v_attr_id acs_attributes.attribute_id%TYPE := null; + v_storage acs_attributes.storage%TYPE := null; + v_attr_name acs_attributes.attribute_name%TYPE := null; + v_id_column varchar2(200) := null; + v_sql varchar2(4000) := null; + v_return varchar2(4000) := null; + + -- Fetch the most inherited attribute + cursor c_attribute is + select + a.attribute_id, a.static_p, a.storage, a.table_name, a.attribute_name, + a.object_type, a.column_name, t.id_column + from + acs_attributes a, + (select + object_type, id_column + from + acs_object_types + connect by + object_type = prior supertype + start with + object_type = (select object_type from acs_objects + where object_id = object_id_in) + ) t + where + a.attribute_name = attribute_name_in + and + a.object_type = t.object_type; + + begin + + -- Determine the attribute parameters + open c_attribute; + fetch c_attribute into + v_attr_id, v_static, v_storage, v_table_name, v_attr_name, + v_object_type, v_column, v_id_column; + if c_attribute%NOTFOUND then + close c_attribute; + raise_application_error (-20000, + 'No such attribute ' || v_object_type || '::' || attribute_name_in || + ' in acs_object.get_attribute_storage.'); + end if; + close c_attribute; + + -- This should really be done in a trigger on acs_attributes, + -- instead of generating it each time in this function + + -- If there is no specific table name for this attribute, + -- figure it out based on the object type + if v_table_name is null then + + -- Determine the appropriate table name + if v_storage = 'generic' then + -- Generic attribute: table name/column are hardcoded + + v_column := 'attr_value'; + + if v_static = 'f' then + v_table_name := 'acs_attribute_values'; + v_key_sql := '(object_id = ' || object_id_in || ' and ' || + 'attribute_id = ' || v_attr_id || ')'; + else + v_table_name := 'acs_static_attr_values'; + v_key_sql := '(object_type = ''' || v_object_type || ''' and ' || + 'attribute_id = ' || v_attr_id || ')'; + end if; + + else + -- Specific attribute: table name/column need to be retreived + + if v_static = 'f' then + select + table_name, id_column + into + v_table_name, v_id_column + from + acs_object_types + where + object_type = v_object_type; + else + raise_application_error(-20000, + 'No table name specified for storage specific static attribute ' || + v_object_type || '::' || attribute_name_in || + ' in acs_object.get_attribute_storage.'); + end if; + + end if; + else + -- There is a custom table name for this attribute. + -- Get the id column out of the acs_object_tables + -- Raise an error if not found + select id_column into v_id_column from acs_object_type_tables + where object_type = v_object_type + and table_name = v_table_name; + + end if; + + if v_column is null then + + if v_storage = 'generic' then + v_column := 'attr_value'; + else + v_column := v_attr_name; + end if; + + end if; + + if v_key_sql is null then + if v_static = 'f' then + v_key_sql := v_id_column || ' = ' || object_id_in ; + else + v_key_sql := v_id_column || ' = ''' || v_object_type || ''''; + end if; + end if; + + exception when no_data_found then + if c_attribute%ISOPEN then + close c_attribute; + end if; + raise_application_error(-20000, 'No data found for attribute ' || + v_object_type || '::' || attribute_name_in || + ' in acs_object.get_attribute_storage'); + + end get_attribute_storage; + + -- Get/set the value of an object attribute, as long as + -- the type can be cast to varchar2 + function get_attribute ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE + ) return varchar2 + is + v_table_name varchar2(200); + v_column varchar2(200); + v_key_sql varchar2(4000); + v_return varchar2(4000); + begin + + get_attribute_storage(object_id_in, attribute_name_in, + v_column, v_table_name, v_key_sql); + + begin + execute immediate 'select ' + || v_column || ' from ' || v_table_name || ' where ' || v_key_sql + into + v_return; + exception when no_data_found then + return null; + end; + + return v_return; + end get_attribute; + + procedure set_attribute ( + object_id_in in acs_objects.object_id%TYPE, + attribute_name_in in acs_attributes.attribute_name%TYPE, + value_in in varchar2 + ) + is + v_table_name varchar2(200); + v_column varchar2(200); + v_key_sql varchar2(4000); + v_return varchar2(4000); + v_dummy integer; + begin + + get_attribute_storage(object_id_in, attribute_name_in, + v_column, v_table_name, v_key_sql); + + execute immediate 'update ' + || v_table_name || ' set ' || v_column || ' = :value where ' || v_key_sql + using value_in; + + end set_attribute; + + function check_context_index ( + object_id in acs_objects.object_id%TYPE, + ancestor_id in acs_objects.object_id%TYPE, + n_generations in integer + ) return char + is + n_rows integer; + n_gens integer; + begin + -- Verify that this row exists in the index. + select decode(count(*),0,0,1) into n_rows + from acs_object_context_index + where object_id = check_context_index.object_id + and ancestor_id = check_context_index.ancestor_id; + + if n_rows = 1 then + -- Verify that the count is correct. + select n_generations into n_gens + from acs_object_context_index + where object_id = check_context_index.object_id + and ancestor_id = check_context_index.ancestor_id; + + if n_gens != n_generations then + acs_log.error('acs_object.check_representation', 'Ancestor ' || + ancestor_id || ' of object ' || object_id || + ' reports being generation ' || n_gens || + ' when it is actually generation ' || n_generations || + '.'); + return 'f'; + else + return 't'; + end if; + else + acs_log.error('acs_object.check_representation', 'Ancestor ' || + ancestor_id || ' of object ' || object_id || + ' is missing an entry in acs_object_context_index.'); + return 'f'; + end if; + end; + + function check_object_ancestors ( + object_id in acs_objects.object_id%TYPE, + ancestor_id in acs_objects.object_id%TYPE, + n_generations in integer + ) return char + is + context_id acs_objects.context_id%TYPE; + security_inherit_p acs_objects.security_inherit_p%TYPE; + n_rows integer; + n_gens integer; + result char(1); + begin + -- OBJECT_ID is the object we are verifying + -- ANCESTOR_ID is the current ancestor we are tracking + -- N_GENERATIONS is how far ancestor_id is from object_id + + -- Note that this function is only supposed to verify that the + -- index contains each ancestor for OBJECT_ID. It doesn''t + -- guarantee that there aren''t extraneous rows or that + -- OBJECT_ID''s children are contained in the index. That is + -- verified by seperate functions. + + result := 't'; + + -- Grab the context and security_inherit_p flag of the current + -- ancestor''s parent. + select context_id, security_inherit_p into context_id, security_inherit_p + from acs_objects + where object_id = check_object_ancestors.ancestor_id; + + if ancestor_id = 0 then + if context_id is null then + result := 't'; + else + -- This can be a constraint, can''t it? + acs_log.error('acs_object.check_representation', + 'Object 0 doesn''t have a null context_id'); + result := 'f'; + end if; + else + if context_id is null or security_inherit_p = 'f' then + context_id := 0; + end if; + + if check_context_index(object_id, ancestor_id, n_generations) = 'f' then + result := 'f'; + end if; + + if check_object_ancestors(object_id, context_id, + n_generations + 1) = 'f' then + result := 'f'; + end if; + end if; + + return result; + end; + + function check_object_descendants ( + object_id in acs_objects.object_id%TYPE, + descendant_id in acs_objects.object_id%TYPE, + n_generations in integer + ) return char + is + result char(1); + begin + -- OBJECT_ID is the object we are verifying. + -- DESCENDANT_ID is the current descendant we are tracking. + -- N_GENERATIONS is how far the current DESCENDANT_ID is from + -- OBJECT_ID. + + -- This function will verfy that each actualy descendant of + -- OBJECT_ID has a row in the index table. It does not check that + -- there aren't extraneous rows or that the ancestors of OBJECT_ID + -- are maintained correctly. + + result := 't'; + + -- First verify that OBJECT_ID and DESCENDANT_ID are actually in + -- the index. + if check_context_index(descendant_id, object_id, n_generations) = 'f' then + result := 'f'; + end if; + + -- For every child that reports inheriting from OBJECT_ID we need to call + -- ourselves recursively. + for obj in (select * + from acs_objects + where context_id = descendant_id + and security_inherit_p = 't') loop + if check_object_descendants(object_id, obj.object_id, + n_generations + 1) = 'f' then + result := 'f'; + end if; + end loop; + + return result; + end; + + function check_path ( + object_id in acs_objects.object_id%TYPE, + ancestor_id in acs_objects.object_id%TYPE + ) return char + is + context_id acs_objects.context_id%TYPE; + security_inherit_p acs_objects.security_inherit_p%TYPE; + begin + if object_id = ancestor_id then + return 't'; + end if; + + select context_id, security_inherit_p into context_id, security_inherit_p + from acs_objects + where object_id = check_path.object_id; + + if context_id is null or security_inherit_p = 'f' then + context_id := 0; + end if; + + return check_path(context_id, ancestor_id); + end; + + function check_representation ( + object_id in acs_objects.object_id%TYPE + ) return char + is + result char(1); + object_type acs_objects.object_type%TYPE; + n_rows integer; + begin + result := 't'; + acs_log.notice('acs_object.check_representation', + 'Running acs_object.check_representation on object_id = ' || + object_id || '.'); + + -- If this fails then there isn''t even an object associated with + -- this id. I'm going to let that error propogate as an exception. + select object_type into object_type + from acs_objects + where object_id = check_representation.object_id; + + acs_log.notice('acs_object.check_representation', + 'OBJECT STORAGE INTEGRITY TEST'); + + -- Let's look through every primary storage table associated with + -- this object type and all of its supertypes and make sure there + -- is a row with OBJECT_ID as theh primary key. + for t in (select t.object_type, t.table_name, t.id_column + from acs_object_type_supertype_map m, acs_object_types t + where m.ancestor_type = t.object_type + and m.object_type = check_representation.object_type + union + select object_type, table_name, id_column + from acs_object_types + where object_type = check_representation.object_type) loop + execute immediate 'select decode(count(*),0,0,1) from ' || t.table_name || + ' where ' || t.id_column || ' = ' || object_id + into n_rows; + + if n_rows = 0 then + result := 'f'; + acs_log.error('acs_object.check_representation', + 'Table ' || t.table_name || ' (primary storage for ' || + t.object_type || ') doesn''t have a row for object ' || + object_id || ' of type ' || object_type || '.'); + end if; + end loop; + + acs_log.notice('acs_object.check_representation', + 'OBJECT CONTEXT INTEGRITY TEST'); + + -- Do a bunch of dirt simple sanity checks. + + -- First let's check that all of our ancestors appear in + -- acs_object_context_index with the correct generation listed. + if check_object_ancestors(object_id, object_id, 0) = 'f' then + result := 'f'; + end if; + + -- Now let's check that all of our descendants appear in + -- acs_object_context_index with the correct generation listed. + if check_object_descendants(object_id, object_id, 0) = 'f' then + result := 'f'; + end if; + + -- Ok, we know that the index contains every entry that it is + -- supposed to have. Now let's make sure it doesn't contain any + -- extraneous entries. + for row in (select * + from acs_object_context_index + where object_id = check_representation.object_id + or ancestor_id = check_representation.object_id) loop + if check_path(row.object_id, row.ancestor_id) = 'f' then + acs_log.error('acs_object.check_representation', + 'acs_object_context_index contains an extraneous row: ' || + 'object_id = ' || row.object_id || ', ancestor_id = ' || + row.ancestor_id || ', n_generations = ' || + row.n_generations || '.'); + result := 'f'; + end if; + end loop; + + acs_log.notice('acs_object.check_representation', + 'Done running acs_object.check_representation ' || + 'on object_id = ' || object_id || '.'); + return result; + end check_representation; + + procedure update_last_modified ( + object_id in acs_objects.object_id%TYPE, + modifying_user in acs_objects.modifying_user%TYPE, + modifying_ip in acs_objects.modifying_ip%TYPE, + last_modified in acs_objects.last_modified%TYPE default sysdate + ) + is + v_parent_id acs_objects.context_id%TYPE; + begin + update acs_objects + set acs_objects.last_modified = acs_object.update_last_modified.last_modified, acs_objects.modifying_user = acs_object.update_last_modified.modifying_user, acs_objects.modifying_ip = acs_object.update_last_modified.modifying_ip + where acs_objects.object_id in (select ao.object_id + from acs_objects ao + connect by prior ao.context_id = ao.object_id + start with ao.object_id = acs_object.update_last_modified.object_id) + and acs_objects.context_id is not null + and acs_objects.object_id != 0; + end update_last_modified; + +end acs_object; +/ +show errors + + +create or replace package acs_rel_type +as + + procedure create_role ( + role in acs_rel_roles.role%TYPE, + pretty_name in acs_rel_roles.pretty_name%TYPE default null, + pretty_plural in acs_rel_roles.pretty_plural%TYPE default null + ); + + procedure drop_role ( + role in acs_rel_roles.role%TYPE + ); + + function role_pretty_name ( + role in acs_rel_roles.role%TYPE + ) return acs_rel_roles.pretty_name%TYPE; + + function role_pretty_plural ( + role in acs_rel_roles.role%TYPE + ) return acs_rel_roles.pretty_plural%TYPE; + + procedure create_type ( + rel_type in acs_rel_types.rel_type%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE, + pretty_plural in acs_object_types.pretty_plural%TYPE, + supertype in acs_object_types.supertype%TYPE + default 'relationship', + table_name in acs_object_types.table_name%TYPE, + id_column in acs_object_types.id_column%TYPE, + package_name in acs_object_types.package_name%TYPE, + abstract_p in acs_object_types.abstract_p%TYPE default 'f', + type_extension_table in acs_object_types.type_extension_table%TYPE + default null, + name_method in acs_object_types.name_method%TYPE default null, + object_type_one in acs_rel_types.object_type_one%TYPE, + role_one in acs_rel_types.role_one%TYPE default null, + min_n_rels_one in acs_rel_types.min_n_rels_one%TYPE, + max_n_rels_one in acs_rel_types.max_n_rels_one%TYPE, + object_type_two in acs_rel_types.object_type_two%TYPE, + role_two in acs_rel_types.role_two%TYPE default null, + min_n_rels_two in acs_rel_types.min_n_rels_two%TYPE, + max_n_rels_two in acs_rel_types.max_n_rels_two%TYPE + ); + + procedure drop_type ( + rel_type in acs_rel_types.rel_type%TYPE, + cascade_p in char default 'f' + ); + +end acs_rel_type; +/ +show errors + +create or replace package body acs_rel_type +as + + procedure create_role ( + role in acs_rel_roles.role%TYPE, + pretty_name in acs_rel_roles.pretty_name%TYPE default null, + pretty_plural in acs_rel_roles.pretty_plural%TYPE default null + ) + is + begin + insert into acs_rel_roles + (role, pretty_name, pretty_plural) + values + (create_role.role, nvl(create_role.pretty_name,create_role.role), nvl(create_role.pretty_plural,create_role.role)); + end; + + procedure drop_role ( + role in acs_rel_roles.role%TYPE + ) + is + begin + delete from acs_rel_roles + where role = drop_role.role; + end; + + function role_pretty_name ( + role in acs_rel_roles.role%TYPE + ) return acs_rel_roles.pretty_name%TYPE + is + v_pretty_name acs_rel_roles.pretty_name%TYPE; + begin + select r.pretty_name into v_pretty_name + from acs_rel_roles r + where r.role = role_pretty_name.role; + + return v_pretty_name; + end role_pretty_name; + + + function role_pretty_plural ( + role in acs_rel_roles.role%TYPE + ) return acs_rel_roles.pretty_plural%TYPE + is + v_pretty_plural acs_rel_roles.pretty_plural%TYPE; + begin + select r.pretty_plural into v_pretty_plural + from acs_rel_roles r + where r.role = role_pretty_plural.role; + + return v_pretty_plural; + end role_pretty_plural; + + procedure create_type ( + rel_type in acs_rel_types.rel_type%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE, + pretty_plural in acs_object_types.pretty_plural%TYPE, + supertype in acs_object_types.supertype%TYPE + default 'relationship', + table_name in acs_object_types.table_name%TYPE, + id_column in acs_object_types.id_column%TYPE, + package_name in acs_object_types.package_name%TYPE, + abstract_p in acs_object_types.abstract_p%TYPE default 'f', + type_extension_table in acs_object_types.type_extension_table%TYPE + default null, + name_method in acs_object_types.name_method%TYPE default null, + object_type_one in acs_rel_types.object_type_one%TYPE, + role_one in acs_rel_types.role_one%TYPE default null, + min_n_rels_one in acs_rel_types.min_n_rels_one%TYPE, + max_n_rels_one in acs_rel_types.max_n_rels_one%TYPE, + object_type_two in acs_rel_types.object_type_two%TYPE, + role_two in acs_rel_types.role_two%TYPE default null, + min_n_rels_two in acs_rel_types.min_n_rels_two%TYPE, + max_n_rels_two in acs_rel_types.max_n_rels_two%TYPE + ) + is + begin + acs_object_type.create_type( + object_type => rel_type, + pretty_name => pretty_name, + pretty_plural => pretty_plural, + supertype => supertype, + table_name => table_name, + id_column => id_column, + package_name => package_name, + abstract_p => abstract_p, + type_extension_table => type_extension_table, + name_method => name_method + ); + + insert into acs_rel_types + (rel_type, + object_type_one, role_one, + min_n_rels_one, max_n_rels_one, + object_type_two, role_two, + min_n_rels_two, max_n_rels_two) + values + (create_type.rel_type, + create_type.object_type_one, create_type.role_one, + create_type.min_n_rels_one, create_type.max_n_rels_one, + create_type.object_type_two, create_type.role_two, + create_type.min_n_rels_two, create_type.max_n_rels_two); + end; + + procedure drop_type ( + rel_type in acs_rel_types.rel_type%TYPE, + cascade_p in char default 'f' + ) + is + begin + -- XXX do cascade_p + delete from acs_rel_types + where acs_rel_types.rel_type = acs_rel_type.drop_type.rel_type; + + acs_object_type.drop_type(acs_rel_type.drop_type.rel_type, acs_rel_type.drop_type.cascade_p); + end; + +end acs_rel_type; +/ +show errors + + +create or replace package acs_rel +as + + function new ( + rel_id in acs_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'relationship', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + context_id in acs_objects.context_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return acs_rels.rel_id%TYPE; + + procedure del ( + rel_id in acs_rels.rel_id%TYPE + ); + +end; +/ +show errors + +create or replace package body acs_rel +as + + function new ( + rel_id in acs_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'relationship', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + context_id in acs_objects.context_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return acs_rels.rel_id%TYPE + is + v_rel_id acs_rels.rel_id%TYPE; + begin + -- XXX This should check that object_id_one and object_id_two are + -- of the appropriate types. + v_rel_id := acs_object.new ( + object_id => rel_id, + object_type => rel_type, + context_id => context_id, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into acs_rels + (rel_id, rel_type, object_id_one, object_id_two) + values + (v_rel_id, new.rel_type, new.object_id_one, new.object_id_two); + + return v_rel_id; + end; + + procedure del ( + rel_id in acs_rels.rel_id%TYPE + ) + is + begin + acs_object.del(rel_id); + end; + +end; +/ +show errors + + + +-- /packages/acs-kernel/sql/apm-create.sql +-- +-- Data model for the OpenACS Package Manager (APM) +-- +-- @author Bryan Quinn (bquinn@arsdigita.com) +-- @author Jon Salz (jsalz@mit.edu) +-- @creation-date 2000/04/30 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + + + +-- Public Programmer level API. +create or replace package apm +as + procedure register_package ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + package_type in apm_package_types.package_type%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ); + + function update_package ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE + default null, + pretty_plural in apm_package_types.pretty_plural%TYPE + default null, + package_uri in apm_package_types.package_uri%TYPE + default null, + package_type in apm_package_types.package_type%TYPE + default null, + initial_install_p in apm_package_types.initial_install_p%TYPE + default null, + singleton_p in apm_package_types.singleton_p%TYPE + default null, + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) return apm_package_types.package_type%TYPE; + + procedure unregister_package ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 't' + ); + + function register_p ( + package_key in apm_package_types.package_key%TYPE + ) return integer; + + -- Informs the APM that this application is available for use. + procedure register_application ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ); + + -- Remove the application from the system. + procedure unregister_application ( + package_key in apm_package_types.package_key%TYPE, + -- Delete all objects associated with this application. + cascade_p in char default 'f' + ); + + procedure register_service ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ); + + -- Remove the service from the system. + procedure unregister_service ( + package_key in apm_package_types.package_key%TYPE, + -- Delete all objects associated with this service. + cascade_p in char default 'f' + ); + + -- Indicate to APM that a parameter is available to the system. + function register_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE + default null, + package_key in apm_parameters.package_key%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE, + description in apm_parameters.description%TYPE + default null, + datatype in apm_parameters.datatype%TYPE + default 'string', + default_value in apm_parameters.default_value%TYPE + default null, + section_name in apm_parameters.section_name%TYPE + default null, + min_n_values in apm_parameters.min_n_values%TYPE + default 1, + max_n_values in apm_parameters.max_n_values%TYPE + default 1 + ) return apm_parameters.parameter_id%TYPE; + + function update_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + default null, + description in apm_parameters.description%TYPE + default null, + datatype in apm_parameters.datatype%TYPE + default 'string', + default_value in apm_parameters.default_value%TYPE + default null, + section_name in apm_parameters.section_name%TYPE + default null, + min_n_values in apm_parameters.min_n_values%TYPE + default 1, + max_n_values in apm_parameters.max_n_values%TYPE + default 1 + ) return apm_parameters.parameter_name%TYPE; + + function parameter_p( + package_key in apm_package_types.package_key%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + ) return integer; + + -- Remove any uses of this parameter. + procedure unregister_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE + default null + ); + + -- Return the value of this parameter for a specific package and parameter. + function get_value ( + parameter_id in apm_parameter_values.parameter_id%TYPE, + package_id in apm_packages.package_id%TYPE + ) return apm_parameter_values.attr_value%TYPE; + + function get_value ( + package_id in apm_packages.package_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + ) return apm_parameter_values.attr_value%TYPE; + + -- Sets a value for a parameter for a package instance. + procedure set_value ( + parameter_id in apm_parameter_values.parameter_id%TYPE, + package_id in apm_packages.package_id%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ); + + procedure set_value ( + package_id in apm_packages.package_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ); + + +end apm; +/ +show errors + +create or replace package apm_package +as + +function new ( + package_id in apm_packages.package_id%TYPE + default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_packages.package_key%TYPE, + object_type in acs_objects.object_type%TYPE + default 'apm_package', + 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, + context_id in acs_objects.context_id%TYPE + default null + ) return apm_packages.package_id%TYPE; + + procedure del ( + package_id in apm_packages.package_id%TYPE + ); + + function initial_install_p ( + package_key in apm_packages.package_key%TYPE + ) return integer; + + function singleton_p ( + package_key in apm_packages.package_key%TYPE + ) return integer; + + function num_instances ( + package_key in apm_package_types.package_key%TYPE + ) return integer; + + function name ( + package_id in apm_packages.package_id%TYPE + ) return varchar2; + + function highest_version ( + package_key in apm_package_types.package_key%TYPE + ) return apm_package_versions.version_id%TYPE; + + function parent_id ( + package_id in apm_packages.package_id%TYPE + ) return apm_packages.package_id%TYPE; + +end apm_package; +/ +show errors + +create or replace package apm_package_version +as + function new ( + version_id in apm_package_versions.version_id%TYPE + default null, + package_key in apm_package_versions.package_key%TYPE, + version_name in apm_package_versions.version_name%TYPE + default null, + version_uri in apm_package_versions.version_uri%TYPE, + summary in apm_package_versions.summary%TYPE, + description_format in apm_package_versions.description_format%TYPE, + description in apm_package_versions.description%TYPE, + release_date in apm_package_versions.release_date%TYPE, + vendor in apm_package_versions.vendor%TYPE, + vendor_uri in apm_package_versions.vendor_uri%TYPE, + auto_mount in apm_package_versions.auto_mount%TYPE, + installed_p in apm_package_versions.installed_p%TYPE + default 'f', + data_model_loaded_p in apm_package_versions.data_model_loaded_p%TYPE + default 'f' + ) return apm_package_versions.version_id%TYPE; + + procedure del ( + version_id in apm_packages.package_id%TYPE + ); + + procedure enable ( + version_id in apm_package_versions.version_id%TYPE + ); + + procedure disable ( + version_id in apm_package_versions.version_id%TYPE + ); + + function edit ( + new_version_id in apm_package_versions.version_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + version_name in apm_package_versions.version_name%TYPE + default null, + version_uri in apm_package_versions.version_uri%TYPE, + summary in apm_package_versions.summary%TYPE, + description_format in apm_package_versions.description_format%TYPE, + description in apm_package_versions.description%TYPE, + release_date in apm_package_versions.release_date%TYPE, + vendor in apm_package_versions.vendor%TYPE, + vendor_uri in apm_package_versions.vendor_uri%TYPE, + auto_mount in apm_package_versions.auto_mount%TYPE, + installed_p in apm_package_versions.installed_p%TYPE + default 'f', + data_model_loaded_p in apm_package_versions.data_model_loaded_p%TYPE + default 'f' + ) return apm_package_versions.version_id%TYPE; + + -- Add an interface provided by this version. + function add_interface( + interface_id in apm_package_dependencies.dependency_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + interface_uri in apm_package_dependencies.service_uri%TYPE, + interface_version in apm_package_dependencies.service_version%TYPE + ) return apm_package_dependencies.dependency_id%TYPE; + + procedure remove_interface( + interface_id in apm_package_dependencies.dependency_id%TYPE + ); + + procedure remove_interface( + interface_uri in apm_package_dependencies.service_uri%TYPE, + interface_version in apm_package_dependencies.service_version%TYPE, + version_id in apm_package_versions.version_id%TYPE + ); + + -- Add a requirement for this version. A requirement is some interface that this + -- version depends on. + function add_dependency( + dependency_id in apm_package_dependencies.dependency_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + dependency_uri in apm_package_dependencies.service_uri%TYPE, + dependency_version in apm_package_dependencies.service_version%TYPE + ) return apm_package_dependencies.dependency_id%TYPE; + + procedure remove_dependency( + dependency_id in apm_package_dependencies.dependency_id%TYPE + ); + + procedure remove_dependency( + dependency_uri in apm_package_dependencies.service_uri%TYPE, + dependency_version in apm_package_dependencies.service_version%TYPE, + version_id in apm_package_versions.version_id%TYPE + ); + + -- Given a version_name (e.g. 3.2a), return + -- something that can be lexicographically sorted. + function sortable_version_name ( + version_name in apm_package_versions.version_name%TYPE + ) return varchar2; + + -- Given two version names, return 1 if one > two, -1 if two > one, 0 otherwise. + -- Deprecate? + function version_name_greater( + version_name_one in apm_package_versions.version_name%TYPE, + version_name_two in apm_package_versions.version_name%TYPE + ) return integer; + + function upgrade_p( + path in varchar2, + initial_version_name in apm_package_versions.version_name%TYPE, + final_version_name in apm_package_versions.version_name%TYPE + ) return integer; + + procedure upgrade( + version_id in apm_package_versions.version_id%TYPE + ); + +end apm_package_version; +/ +show errors + +create or replace package apm_package_type +as + procedure create_type( + package_key in apm_package_types.package_key%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE, + pretty_plural in acs_object_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + package_type in apm_package_types.package_type%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE, + singleton_p in apm_package_types.singleton_p%TYPE, + spec_file_path in apm_package_types.spec_file_path%TYPE default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE default null + ); + + function update_type ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE + default null, + pretty_plural in acs_object_types.pretty_plural%TYPE + default null, + package_uri in apm_package_types.package_uri%TYPE + default null, + package_type in apm_package_types.package_type%TYPE + default null, + initial_install_p in apm_package_types.initial_install_p%TYPE + default null, + singleton_p in apm_package_types.singleton_p%TYPE + default null, + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) return apm_package_types.package_type%TYPE; + + procedure drop_type ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 'f' + ); + + function num_parameters ( + package_key in apm_package_types.package_key%TYPE + ) return integer; + +end apm_package_type; +/ +show errors + + + +-- Private APM System API for managing parameter values. +create or replace package apm_parameter_value +as + function new ( + value_id in apm_parameter_values.value_id%TYPE default null, + package_id in apm_packages.package_id%TYPE, + parameter_id in apm_parameter_values.parameter_id%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ) return apm_parameter_values.value_id%TYPE; + + procedure del ( + value_id in apm_parameter_values.value_id%TYPE default null + ); + end apm_parameter_value; +/ +show errors + +create or replace package apm_application +as + +function new ( + application_id in acs_objects.object_id%TYPE default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_package_types.package_key%TYPE, + object_type in acs_objects.object_type%TYPE + default 'apm_application', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + application_id in acs_objects.object_id%TYPE + ); + +end; +/ +show errors + + +create or replace package apm_service +as + + function new ( + service_id in acs_objects.object_id%TYPE default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_package_types.package_key%TYPE, + object_type in acs_objects.object_type%TYPE default 'apm_service', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + service_id in acs_objects.object_id%TYPE + ); + +end; +/ +show errors + +create or replace package body apm +as + procedure register_package ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + package_type in apm_package_types.package_type%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) + is + begin + apm_package_type.create_type( + package_key => register_package.package_key, + pretty_name => register_package.pretty_name, + pretty_plural => register_package.pretty_plural, + package_uri => register_package.package_uri, + package_type => register_package.package_type, + initial_install_p => register_package.initial_install_p, + singleton_p => register_package.singleton_p, + spec_file_path => register_package.spec_file_path, + spec_file_mtime => spec_file_mtime + ); + end register_package; + + function update_package ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE + default null, + pretty_plural in apm_package_types.pretty_plural%TYPE + default null, + package_uri in apm_package_types.package_uri%TYPE + default null, + package_type in apm_package_types.package_type%TYPE + default null, + initial_install_p in apm_package_types.initial_install_p%TYPE + default null, + singleton_p in apm_package_types.singleton_p%TYPE + default null, + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) return apm_package_types.package_type%TYPE + is + begin + + return apm_package_type.update_type( + package_key => update_package.package_key, + pretty_name => update_package.pretty_name, + pretty_plural => update_package.pretty_plural, + package_uri => update_package.package_uri, + package_type => update_package.package_type, + initial_install_p => update_package.initial_install_p, + singleton_p => update_package.singleton_p, + spec_file_path => update_package.spec_file_path, + spec_file_mtime => update_package.spec_file_mtime + ); + + end update_package; + + + procedure unregister_package ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 't' + ) + is + begin + apm_package_type.drop_type( + package_key => unregister_package.package_key, + cascade_p => unregister_package.cascade_p + ); + end unregister_package; + + function register_p ( + package_key in apm_package_types.package_key%TYPE + ) return integer + is + v_register_p integer; + begin + select decode(count(*),0,0,1) into v_register_p from apm_package_types + where package_key = register_p.package_key; + return v_register_p; + end register_p; + + procedure register_application ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) + is + begin + apm.register_package( + package_key => register_application.package_key, + pretty_name => register_application.pretty_name, + pretty_plural => register_application.pretty_plural, + package_uri => register_application.package_uri, + package_type => 'apm_application', + initial_install_p => register_application.initial_install_p, + singleton_p => register_application.singleton_p, + spec_file_path => register_application.spec_file_path, + spec_file_mtime => register_application.spec_file_mtime + ); + end register_application; + + procedure unregister_application ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 'f' + ) + is + begin + apm.unregister_package ( + package_key => unregister_application.package_key, + cascade_p => unregister_application.cascade_p + ); + end unregister_application; + + procedure register_service ( + package_key in apm_package_types.package_key%TYPE, + pretty_name in apm_package_types.pretty_name%TYPE, + pretty_plural in apm_package_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE + default 'f', + singleton_p in apm_package_types.singleton_p%TYPE + default 'f', + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) + is + begin + apm.register_package( + package_key => register_service.package_key, + pretty_name => register_service.pretty_name, + pretty_plural => register_service.pretty_plural, + package_uri => register_service.package_uri, + package_type => 'apm_service', + initial_install_p => register_service.initial_install_p, + singleton_p => register_service.singleton_p, + spec_file_path => register_service.spec_file_path, + spec_file_mtime => register_service.spec_file_mtime + ); + end register_service; + + procedure unregister_service ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 'f' + ) + is + begin + apm.unregister_package ( + package_key => unregister_service.package_key, + cascade_p => unregister_service.cascade_p + ); + end unregister_service; + + -- Indicate to APM that a parameter is available to the system. + function register_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE + default null, + package_key in apm_parameters.package_key%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE, + description in apm_parameters.description%TYPE + default null, + datatype in apm_parameters.datatype%TYPE + default 'string', + default_value in apm_parameters.default_value%TYPE + default null, + section_name in apm_parameters.section_name%TYPE + default null, + min_n_values in apm_parameters.min_n_values%TYPE + default 1, + max_n_values in apm_parameters.max_n_values%TYPE + default 1 + ) return apm_parameters.parameter_id%TYPE + is + v_parameter_id apm_parameters.parameter_id%TYPE; + cursor all_parameters is + select ap.package_id, p.parameter_id, p.default_value + from apm_parameters p, apm_parameter_values v, apm_packages ap + where p.package_key = ap.package_key + and p.parameter_id = v.parameter_id (+) + and v.attr_value is null + and p.package_key = register_parameter.package_key; + begin + -- Create the new parameter. + v_parameter_id := acs_object.new( + object_id => parameter_id, + object_type => 'apm_parameter' + ); + + insert into apm_parameters + (parameter_id, parameter_name, description, package_key, datatype, + default_value, section_name, min_n_values, max_n_values) + values + (v_parameter_id, register_parameter.parameter_name, register_parameter.description, + register_parameter.package_key, register_parameter.datatype, + register_parameter.default_value, register_parameter.section_name, + register_parameter.min_n_values, register_parameter.max_n_values); + -- Propagate parameter to new instances. + for cur_val in all_parameters + loop + apm.set_value( + package_id => cur_val.package_id, + parameter_id => cur_val.parameter_id, + attr_value => cur_val.default_value + ); + end loop; + return v_parameter_id; + end register_parameter; + + function update_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + default null, + description in apm_parameters.description%TYPE + default null, + datatype in apm_parameters.datatype%TYPE + default 'string', + default_value in apm_parameters.default_value%TYPE + default null, + section_name in apm_parameters.section_name%TYPE + default null, + min_n_values in apm_parameters.min_n_values%TYPE + default 1, + max_n_values in apm_parameters.max_n_values%TYPE + default 1 + ) return apm_parameters.parameter_name%TYPE + is + begin + update apm_parameters + set parameter_name = nvl(update_parameter.parameter_name, parameter_name), + default_value = nvl(update_parameter.default_value, default_value), + datatype = nvl(update_parameter.datatype, datatype), + description = nvl(update_parameter.description, description), + section_name = nvl(update_parameter.section_name, section_name), + min_n_values = nvl(update_parameter.min_n_values, min_n_values), + max_n_values = nvl(update_parameter.max_n_values, max_n_values) + where parameter_id = update_parameter.parameter_id; + return parameter_id; + end; + + function parameter_p( + package_key in apm_package_types.package_key%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + ) return integer + is + v_parameter_p integer; + begin + select decode(count(*),0,0,1) into v_parameter_p + from apm_parameters + where package_key = parameter_p.package_key + and parameter_name = parameter_p.parameter_name; + return v_parameter_p; + end parameter_p; + + procedure unregister_parameter ( + parameter_id in apm_parameters.parameter_id%TYPE + default null + ) + is + begin + delete from apm_parameter_values + where parameter_id = unregister_parameter.parameter_id; + delete from apm_parameters + where parameter_id = unregister_parameter.parameter_id; + acs_object.del(parameter_id); + end unregister_parameter; + + function id_for_name ( + parameter_name in apm_parameters.parameter_name%TYPE, + package_key in apm_parameters.package_key%TYPE + ) return apm_parameters.parameter_id%TYPE + is + a_parameter_id apm_parameters.parameter_id%TYPE; + begin + select parameter_id into a_parameter_id + from apm_parameters p + where p.parameter_name = id_for_name.parameter_name and + p.package_key = id_for_name.package_key; + return a_parameter_id; + end id_for_name; + + function get_value ( + parameter_id in apm_parameter_values.parameter_id%TYPE, + package_id in apm_packages.package_id%TYPE + ) return apm_parameter_values.attr_value%TYPE + is + value apm_parameter_values.attr_value%TYPE; + begin + select attr_value into value from apm_parameter_values v + where v.package_id = get_value.package_id + and parameter_id = get_value.parameter_id; + return value; + end get_value; + + function get_value ( + package_id in apm_packages.package_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE + ) return apm_parameter_values.attr_value%TYPE + is + v_parameter_id apm_parameter_values.parameter_id%TYPE; + begin + select parameter_id into v_parameter_id + from apm_parameters + where parameter_name = get_value.parameter_name + and package_key = (select package_key from apm_packages + where package_id = get_value.package_id); + return apm.get_value( + parameter_id => v_parameter_id, + package_id => get_value.package_id + ); + end get_value; + + + -- Sets a value for a parameter for a package instance. + procedure set_value ( + parameter_id in apm_parameter_values.parameter_id%TYPE, + package_id in apm_packages.package_id%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ) + is + v_value_id apm_parameter_values.value_id%TYPE; + begin + -- Determine if the value exists + select value_id into v_value_id from apm_parameter_values + where parameter_id = set_value.parameter_id + and package_id = set_value.package_id; + update apm_parameter_values set attr_value = set_value.attr_value + where parameter_id = set_value.parameter_id + and package_id = set_value.package_id; + exception + when NO_DATA_FOUND + then + v_value_id := apm_parameter_value.new( + package_id => set_value.package_id, + parameter_id => set_value.parameter_id, + attr_value => set_value.attr_value + ); + end set_value; + + procedure set_value ( + package_id in apm_packages.package_id%TYPE, + parameter_name in apm_parameters.parameter_name%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ) + is + v_parameter_id apm_parameter_values.parameter_id%TYPE; + begin + select parameter_id into v_parameter_id + from apm_parameters + where parameter_name = set_value.parameter_name + and package_key = (select package_key from apm_packages + where package_id = set_value.package_id); + apm.set_value( + parameter_id => v_parameter_id, + package_id => set_value.package_id, + attr_value => set_value.attr_value + ); + exception + when NO_DATA_FOUND + then + RAISE_APPLICATION_ERROR(-20000, 'The parameter named ' || set_value.parameter_name || ' that you attempted to set does not exist AND/OR the specified package ' || set_value.package_id || ' does not exist in the system.'); + end set_value; +end apm; +/ +show errors + +create or replace package body apm_package +as + procedure initialize_parameters ( + package_id in apm_packages.package_id%TYPE, + package_key in apm_package_types.package_key%TYPE + ) + is + v_value_id apm_parameter_values.value_id%TYPE; + cursor cur is + select parameter_id, default_value + from apm_parameters + where package_key = initialize_parameters.package_key; + begin + -- need to initialize all params for this type + for cur_val in cur + loop + v_value_id := apm_parameter_value.new( + package_id => initialize_parameters.package_id, + parameter_id => cur_val.parameter_id, + attr_value => cur_val.default_value + ); + end loop; + end initialize_parameters; + + function new ( + package_id in apm_packages.package_id%TYPE + default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_packages.package_key%TYPE, + object_type in acs_objects.object_type%TYPE + default 'apm_package', + 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, + context_id in acs_objects.context_id%TYPE + default null + ) return apm_packages.package_id%TYPE + is + v_singleton_p integer; + v_package_type apm_package_types.package_type%TYPE; + v_num_instances integer; + v_package_id apm_packages.package_id%TYPE; + v_instance_name apm_packages.instance_name%TYPE; + begin + v_singleton_p := apm_package.singleton_p( + package_key => apm_package.new.package_key + ); + v_num_instances := apm_package.num_instances( + package_key => apm_package.new.package_key + ); + + if v_singleton_p = 1 and v_num_instances >= 1 then + select package_id into v_package_id + from apm_packages + where package_key = apm_package.new.package_key; + return v_package_id; + else + v_package_id := acs_object.new( + object_id => package_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + if instance_name is null then + v_instance_name := package_key || ' ' || v_package_id; + else + v_instance_name := instance_name; + end if; + + select package_type into v_package_type + from apm_package_types + where package_key = apm_package.new.package_key; + + insert into apm_packages + (package_id, package_key, instance_name) + values + (v_package_id, package_key, v_instance_name); + + if v_package_type = 'apm_application' then + insert into apm_applications + (application_id) + values + (v_package_id); + else + insert into apm_services + (service_id) + values + (v_package_id); + end if; + + initialize_parameters( + package_id => v_package_id, + package_key => apm_package.new.package_key + ); + return v_package_id; + + end if; +end new; + + procedure del ( + package_id in apm_packages.package_id%TYPE + ) + is + cursor all_values is + select value_id from apm_parameter_values + where package_id = apm_package.del.package_id; + cursor all_site_nodes is + select node_id from site_nodes + where object_id = apm_package.del.package_id; + begin + -- Delete all parameters. + for cur_val in all_values loop + apm_parameter_value.del(value_id => cur_val.value_id); + end loop; + delete from apm_applications where application_id = apm_package.del.package_id; + delete from apm_services where service_id = apm_package.del.package_id; + delete from apm_packages where package_id = apm_package.del.package_id; + -- Delete the site nodes for the objects. + for cur_val in all_site_nodes loop + site_node.del(cur_val.node_id); + end loop; + -- Delete the object. + acs_object.del ( + object_id => package_id + ); + end del; + + function initial_install_p ( + package_key in apm_packages.package_key%TYPE + ) return integer + is + v_initial_install_p integer; + begin + select 1 into v_initial_install_p + from apm_package_types + where package_key = initial_install_p.package_key + and initial_install_p = 't'; + return v_initial_install_p; + + exception + when NO_DATA_FOUND + then + return 0; + end initial_install_p; + + function singleton_p ( + package_key in apm_packages.package_key%TYPE + ) return integer + is + v_singleton_p integer; + begin + select 1 into v_singleton_p + from apm_package_types + where package_key = singleton_p.package_key + and singleton_p = 't'; + return v_singleton_p; + + exception + when NO_DATA_FOUND + then + return 0; + end singleton_p; + + function num_instances ( + package_key in apm_package_types.package_key%TYPE + ) return integer + is + v_num_instances integer; + begin + select count(*) into v_num_instances + from apm_packages + where package_key = num_instances.package_key; + return v_num_instances; + + exception + when NO_DATA_FOUND + then + return 0; + end num_instances; + + function name ( + package_id in apm_packages.package_id%TYPE + ) return varchar2 + is + v_result apm_packages.instance_name%TYPE; + begin + select instance_name into v_result + from apm_packages + where package_id = name.package_id; + + return v_result; + end name; + + function highest_version ( + package_key in apm_package_types.package_key%TYPE + ) return apm_package_versions.version_id%TYPE + is + v_version_id apm_package_versions.version_id%TYPE; + begin + select version_id into v_version_id + from apm_package_version_info i + where apm_package_version.sortable_version_name(version_name) = + (select max(apm_package_version.sortable_version_name(v.version_name)) + from apm_package_version_info v where v.package_key = highest_version.package_key) + and package_key = highest_version.package_key; + return v_version_id; + exception + when NO_DATA_FOUND + then + return 0; + end highest_version; + + function parent_id ( + package_id in apm_packages.package_id%TYPE + ) return apm_packages.package_id%TYPE + is + v_package_id apm_packages.package_id%TYPE; + begin + select sn1.object_id + into v_package_id + from site_nodes sn1 + where sn1.node_id = (select sn2.parent_id + from site_nodes sn2 + where sn2.object_id = apm_package.parent_id.package_id); + + return v_package_id; + + exception when NO_DATA_FOUND then + return -1; + end parent_id; + +end apm_package; +/ +show errors + + +create or replace package body apm_package_version +as + function new ( + version_id in apm_package_versions.version_id%TYPE + default null, + package_key in apm_package_versions.package_key%TYPE, + version_name in apm_package_versions.version_name%TYPE + default null, + version_uri in apm_package_versions.version_uri%TYPE, + summary in apm_package_versions.summary%TYPE, + description_format in apm_package_versions.description_format%TYPE, + description in apm_package_versions.description%TYPE, + release_date in apm_package_versions.release_date%TYPE, + vendor in apm_package_versions.vendor%TYPE, + vendor_uri in apm_package_versions.vendor_uri%TYPE, + auto_mount in apm_package_versions.auto_mount%TYPE, + installed_p in apm_package_versions.installed_p%TYPE + default 'f', + data_model_loaded_p in apm_package_versions.data_model_loaded_p%TYPE + default 'f' + ) return apm_package_versions.version_id%TYPE + is + v_version_id apm_package_versions.version_id%TYPE; + begin + if version_id is null then + select acs_object_id_seq.nextval + into v_version_id + from dual; + else + v_version_id := version_id; + end if; + v_version_id := acs_object.new( + object_id => v_version_id, + object_type => 'apm_package_version' + ); + insert into apm_package_versions + (version_id, package_key, version_name, version_uri, summary, description_format, description, + release_date, vendor, vendor_uri, auto_mount, installed_p, data_model_loaded_p) + values + (v_version_id, package_key, version_name, version_uri, + summary, description_format, description, + release_date, vendor, vendor_uri, auto_mount, + installed_p, data_model_loaded_p); + return v_version_id; + end new; + + procedure del ( + version_id in apm_packages.package_id%TYPE + ) + is + begin + delete from apm_package_owners + where version_id = apm_package_version.del.version_id; + + delete from apm_package_dependencies + where version_id = apm_package_version.del.version_id; + + delete from apm_package_versions + where version_id = apm_package_version.del.version_id; + + acs_object.del(apm_package_version.del.version_id); + + end del; + + procedure enable ( + version_id in apm_package_versions.version_id%TYPE + ) + is + begin + update apm_package_versions set enabled_p = 't' + where version_id = enable.version_id; + end enable; + + procedure disable ( + version_id in apm_package_versions.version_id%TYPE + ) + is + begin + update apm_package_versions + set enabled_p = 'f' + where version_id = disable.version_id; + end disable; + + function copy( + version_id in apm_package_versions.version_id%TYPE, + new_version_id in apm_package_versions.version_id%TYPE default null, + new_version_name in apm_package_versions.version_name%TYPE, + new_version_uri in apm_package_versions.version_uri%TYPE + ) return apm_package_versions.version_id%TYPE + is + v_version_id integer; + begin + v_version_id := acs_object.new( + object_id => new_version_id, + object_type => 'apm_package_version' + ); + + insert into apm_package_versions(version_id, package_key, version_name, + version_uri, summary, description_format, description, + release_date, vendor, vendor_uri, auto_mount) + select v_version_id, package_key, copy.new_version_name, + copy.new_version_uri, summary, description_format, description, + release_date, vendor, vendor_uri, auto_mount + from apm_package_versions + where version_id = copy.version_id; + + insert into apm_package_dependencies(dependency_id, version_id, dependency_type, service_uri, service_version) + select acs_object_id_seq.nextval, v_version_id, dependency_type, service_uri, service_version + from apm_package_dependencies + where version_id = copy.version_id; + + insert into apm_package_callbacks (version_id, type, proc) + select v_version_id, type, proc + from apm_package_callbacks + where version_id = copy.version_id; + + insert into apm_package_owners(version_id, owner_uri, owner_name, sort_key) + select v_version_id, owner_uri, owner_name, sort_key + from apm_package_owners + where version_id = copy.version_id; + + return v_version_id; + end copy; + + function edit ( + new_version_id in apm_package_versions.version_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + version_name in apm_package_versions.version_name%TYPE + default null, + version_uri in apm_package_versions.version_uri%TYPE, + summary in apm_package_versions.summary%TYPE, + description_format in apm_package_versions.description_format%TYPE, + description in apm_package_versions.description%TYPE, + release_date in apm_package_versions.release_date%TYPE, + vendor in apm_package_versions.vendor%TYPE, + vendor_uri in apm_package_versions.vendor_uri%TYPE, + auto_mount in apm_package_versions.auto_mount%TYPE, + installed_p in apm_package_versions.installed_p%TYPE + default 'f', + data_model_loaded_p in apm_package_versions.data_model_loaded_p%TYPE + default 'f' + ) return apm_package_versions.version_id%TYPE + is + v_version_id apm_package_versions.version_id%TYPE; + version_unchanged_p integer; + begin + -- Determine if version has changed. + select decode(count(*),0,0,1) into version_unchanged_p + from apm_package_versions + where version_id = edit.version_id + and version_name = edit.version_name; + if version_unchanged_p <> 1 then + v_version_id := copy( + version_id => edit.version_id, + new_version_id => edit.new_version_id, + new_version_name => edit.version_name, + new_version_uri => edit.version_uri + ); + else + v_version_id := edit.version_id; + end if; + + update apm_package_versions + set version_uri = edit.version_uri, + summary = edit.summary, + description_format = edit.description_format, + description = edit.description, + release_date = trunc(sysdate), + vendor = edit.vendor, + vendor_uri = edit.vendor_uri, + auto_mount = edit.auto_mount, + installed_p = edit.installed_p, + data_model_loaded_p = edit.data_model_loaded_p + where version_id = v_version_id; + return v_version_id; + end edit; + +-- Add an interface provided by this version. + function add_interface( + interface_id in apm_package_dependencies.dependency_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + interface_uri in apm_package_dependencies.service_uri%TYPE, + interface_version in apm_package_dependencies.service_version%TYPE + ) return apm_package_dependencies.dependency_id%TYPE + is + v_dep_id apm_package_dependencies.dependency_id%TYPE; + begin + if add_interface.interface_id is null then + select acs_object_id_seq.nextval into v_dep_id from dual; + else + v_dep_id := add_interface.interface_id; + end if; + + insert into apm_package_dependencies + (dependency_id, version_id, dependency_type, service_uri, service_version) + values + (v_dep_id, add_interface.version_id, 'provides', add_interface.interface_uri, + add_interface.interface_version); + return v_dep_id; + end add_interface; + + procedure remove_interface( + interface_id in apm_package_dependencies.dependency_id%TYPE + ) + is + begin + delete from apm_package_dependencies + where dependency_id = remove_interface.interface_id; + end remove_interface; + + procedure remove_interface( + interface_uri in apm_package_dependencies.service_uri%TYPE, + interface_version in apm_package_dependencies.service_version%TYPE, + version_id in apm_package_versions.version_id%TYPE + ) + is + v_dep_id apm_package_dependencies.dependency_id%TYPE; + begin + select dependency_id into v_dep_id from apm_package_dependencies + where service_uri = remove_interface.interface_uri + and interface_version = remove_interface.interface_version; + remove_interface(v_dep_id); + end remove_interface; + + -- Add a requirement for this version. A requirement is some interface that this + -- version depends on. + function add_dependency( + dependency_id in apm_package_dependencies.dependency_id%TYPE + default null, + version_id in apm_package_versions.version_id%TYPE, + dependency_uri in apm_package_dependencies.service_uri%TYPE, + dependency_version in apm_package_dependencies.service_version%TYPE + ) return apm_package_dependencies.dependency_id%TYPE + is + v_dep_id apm_package_dependencies.dependency_id%TYPE; + begin + if add_dependency.dependency_id is null then + select acs_object_id_seq.nextval into v_dep_id from dual; + else + v_dep_id := add_dependency.dependency_id; + end if; + + insert into apm_package_dependencies + (dependency_id, version_id, dependency_type, service_uri, service_version) + values + (v_dep_id, add_dependency.version_id, 'requires', add_dependency.dependency_uri, + add_dependency.dependency_version); + return v_dep_id; + end add_dependency; + + procedure remove_dependency( + dependency_id in apm_package_dependencies.dependency_id%TYPE + ) + is + begin + delete from apm_package_dependencies + where dependency_id = remove_dependency.dependency_id; + end remove_dependency; + + + procedure remove_dependency( + dependency_uri in apm_package_dependencies.service_uri%TYPE, + dependency_version in apm_package_dependencies.service_version%TYPE, + version_id in apm_package_versions.version_id%TYPE + ) + is + v_dep_id apm_package_dependencies.dependency_id%TYPE; + begin + select dependency_id into v_dep_id from apm_package_dependencies + where service_uri = remove_dependency.dependency_uri + and service_version = remove_dependency.dependency_version; + remove_dependency(v_dep_id); + end remove_dependency; + + function sortable_version_name ( + version_name in apm_package_versions.version_name%TYPE + ) return varchar2 + is + a_fields integer; + a_start integer; + a_end integer; + a_order varchar2(1000); + a_char char(1); + a_seen_letter char(1) := 'f'; + begin + a_fields := 0; + a_start := 1; + loop + a_end := a_start; + + -- keep incrementing a_end until we run into a non-number + while substr(version_name, a_end, 1) >= '0' and substr(version_name, a_end, 1) <= '9' loop + a_end := a_end + 1; + end loop; + if a_end = a_start then + return -1; + -- raise_application_error(-20000, 'Expected number at position ' || a_start); + end if; + if a_end - a_start > 4 then + return -1; + -- raise_application_error(-20000, 'Numbers within versions can only be up to 4 digits long'); + end if; + + -- zero-pad and append the number + a_order := a_order || substr('0000', 1, 4 - (a_end - a_start)) || + substr(version_name, a_start, a_end - a_start) || '.'; + a_fields := a_fields + 1; + if a_end > length(version_name) then + -- end of string - we're outta here + if a_seen_letter = 'f' then + -- append the "final" suffix if there haven't been any letters + -- so far (i.e., not development/alpha/beta) + a_order := a_order || lpad(' ',(7 - a_fields)*5,'0000.') || ' 3F.'; + end if; + return a_order; + end if; + + -- what's the next character? if a period, just skip it + a_char := substr(version_name, a_end, 1); + if a_char = '.' then + null; + else + -- if the next character was a letter, append the appropriate characters + if a_char = 'd' then + a_order := a_order || lpad(' ',(7 - a_fields)*5,'0000.') || ' 0D.'; + elsif a_char = 'a' then + a_order := a_order || lpad(' ',(7 - a_fields)*5,'0000.') || ' 1A.'; + elsif a_char = 'b' then + a_order := a_order || lpad(' ',(7 - a_fields)*5,'0000.') || ' 2B.'; + end if; + + -- can't have something like 3.3a1b2 - just one letter allowed! + if a_seen_letter = 't' then + return -1; + -- raise_application_error(-20000, 'Not allowed to have two letters in version name ''' + -- || version_name || ''''); + end if; + a_seen_letter := 't'; + + -- end of string - we're done! + if a_end = length(version_name) then + return a_order; + end if; + end if; + a_start := a_end + 1; + end loop; + end sortable_version_name; + + function version_name_greater( + version_name_one in apm_package_versions.version_name%TYPE, + version_name_two in apm_package_versions.version_name%TYPE + ) return integer is + a_order_a varchar2(1000); + a_order_b varchar2(1000); + begin + a_order_a := sortable_version_name(version_name_one); + a_order_b := sortable_version_name(version_name_two); + if a_order_a < a_order_b then + return -1; + elsif a_order_a > a_order_b then + return 1; + end if; + return 0; + end version_name_greater; + + function upgrade_p( + path in varchar2, + initial_version_name in apm_package_versions.version_name%TYPE, + final_version_name in apm_package_versions.version_name%TYPE + ) return integer + is + v_pos1 integer; + v_pos2 integer; + v_path varchar2(1500); + v_version_from apm_package_versions.version_name%TYPE; + v_version_to apm_package_versions.version_name%TYPE; + begin + + -- Set v_path to the tail of the path (the file name). + v_path := substr(upgrade_p.path, instr(upgrade_p.path, '/', -1) + 1); + + -- Remove the extension, if it's .sql. + v_pos1 := instr(v_path, '.', -1); + if v_pos1 > 0 and substr(v_path, v_pos1) = '.sql' then + v_path := substr(v_path, 1, v_pos1 - 1); + end if; + + -- Figure out the from/to version numbers for the individual file. + v_pos1 := instr(v_path, '-', -1, 2); + v_pos2 := instr(v_path, '-', -1); + if v_pos1 = 0 or v_pos2 = 0 then + -- There aren't two hyphens in the file name. Bail. + return 0; + end if; + + v_version_from := substr(v_path, v_pos1 + 1, v_pos2 - v_pos1 - 1); + v_version_to := substr(v_path, v_pos2 + 1); + + if version_name_greater(upgrade_p.initial_version_name, v_version_from) <= 0 and + version_name_greater(upgrade_p.final_version_name, v_version_to) >= 0 then + return 1; + end if; + + return 0; + exception when others then + -- Invalid version number. + return 0; + end upgrade_p; + + procedure upgrade( + version_id in apm_package_versions.version_id%TYPE + ) + is + begin + update apm_package_versions + set enabled_p = 'f', + installed_p = 'f' + where package_key = (select package_key from apm_package_versions + where version_id = upgrade.version_id); + update apm_package_versions + set enabled_p = 't', + installed_p = 't' + where version_id = upgrade.version_id; + + end upgrade; + +end apm_package_version; +/ +show errors + +create or replace package body apm_package_type +as + procedure create_type( + package_key in apm_package_types.package_key%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE, + pretty_plural in acs_object_types.pretty_plural%TYPE, + package_uri in apm_package_types.package_uri%TYPE, + package_type in apm_package_types.package_type%TYPE, + initial_install_p in apm_package_types.initial_install_p%TYPE, + singleton_p in apm_package_types.singleton_p%TYPE, + spec_file_path in apm_package_types.spec_file_path%TYPE default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE default null + ) + is + begin + insert into apm_package_types + (package_key, pretty_name, pretty_plural, package_uri, package_type, + spec_file_path, spec_file_mtime, initial_install_p, singleton_p) + values + (create_type.package_key, create_type.pretty_name, create_type.pretty_plural, + create_type.package_uri, create_type.package_type, create_type.spec_file_path, + create_type.spec_file_mtime, create_type.initial_install_p, create_type.singleton_p); + end create_type; + + function update_type( + package_key in apm_package_types.package_key%TYPE, + pretty_name in acs_object_types.pretty_name%TYPE + default null, + pretty_plural in acs_object_types.pretty_plural%TYPE + default null, + package_uri in apm_package_types.package_uri%TYPE + default null, + package_type in apm_package_types.package_type%TYPE + default null, + initial_install_p in apm_package_types.initial_install_p%TYPE + default null, + singleton_p in apm_package_types.singleton_p%TYPE + default null, + spec_file_path in apm_package_types.spec_file_path%TYPE + default null, + spec_file_mtime in apm_package_types.spec_file_mtime%TYPE + default null + ) return apm_package_types.package_type%TYPE + is + begin + UPDATE apm_package_types SET + pretty_name = nvl(update_type.pretty_name, pretty_name), + pretty_plural = nvl(update_type.pretty_plural, pretty_plural), + package_uri = nvl(update_type.package_uri, package_uri), + package_type = nvl(update_type.package_type, package_type), + spec_file_path = nvl(update_type.spec_file_path, spec_file_path), + spec_file_mtime = nvl(update_type.spec_file_mtime, spec_file_mtime), + initial_install_p = nvl(update_type.initial_install_p, initial_install_p), + singleton_p = nvl(update_type.singleton_p, singleton_p) + where package_key = update_type.package_key; + return update_type.package_key; + end update_type; + + procedure drop_type ( + package_key in apm_package_types.package_key%TYPE, + cascade_p in char default 'f' + ) + is + cursor all_package_ids is + select package_id + from apm_packages + where package_key = drop_type.package_key; + + cursor all_parameters is + select parameter_id from apm_parameters + where package_key = drop_type.package_key; + + cursor all_versions is + select version_id from apm_package_versions + where package_key = drop_type.package_key; + begin + if cascade_p = 't' then + for cur_val in all_package_ids + loop + apm_package.del( + package_id => cur_val.package_id + ); + end loop; + -- Unregister all parameters. + for cur_val in all_parameters + loop + apm.unregister_parameter(parameter_id => cur_val.parameter_id); + end loop; + + -- Unregister all versions + for cur_val in all_versions + loop + apm_package_version.del(version_id => cur_val.version_id); + end loop; + end if; + delete from apm_package_types + where package_key = drop_type.package_key; + end drop_type; + + function num_parameters ( + package_key in apm_package_types.package_key%TYPE + ) return integer + is + v_count integer; + begin + select count(*) into v_count + from apm_parameters + where package_key = num_parameters.package_key; + return v_count; + end num_parameters; + +end apm_package_type; + + +/ +show errors + +create or replace package body apm_parameter_value +as + function new ( + value_id in apm_parameter_values.value_id%TYPE default null, + package_id in apm_packages.package_id%TYPE, + parameter_id in apm_parameter_values.parameter_id%TYPE, + attr_value in apm_parameter_values.attr_value%TYPE + ) return apm_parameter_values.value_id%TYPE + is + v_value_id apm_parameter_values.value_id%TYPE; + begin + v_value_id := acs_object.new( + object_id => value_id, + object_type => 'apm_parameter_value' + ); + insert into apm_parameter_values + (value_id, package_id, parameter_id, attr_value) + values + (v_value_id, apm_parameter_value.new.package_id, + apm_parameter_value.new.parameter_id, + apm_parameter_value.new.attr_value); + return v_value_id; + end new; + + procedure del ( + value_id in apm_parameter_values.value_id%TYPE default null + ) + is + begin + delete from apm_parameter_values + where value_id = apm_parameter_value.del.value_id; + acs_object.del(value_id); + end del; + + end apm_parameter_value; +/ +show errors; + +create or replace package body apm_application +as + + function new ( + application_id in acs_objects.object_id%TYPE default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_package_types.package_key%TYPE, + object_type in acs_objects.object_type%TYPE + default 'apm_application', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_application_id integer; + begin + v_application_id := apm_package.new ( + package_id => application_id, + instance_name => instance_name, + package_key => package_key, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + return v_application_id; + end new; + + procedure del ( + application_id in acs_objects.object_id%TYPE + ) + is + begin + delete from apm_applications + where application_id = apm_application.del.application_id; + apm_package.del( + package_id => application_id); + end del; + +end; +/ +show errors + +create or replace package body apm_service +as + + function new ( + service_id in acs_objects.object_id%TYPE default null, + instance_name in apm_packages.instance_name%TYPE + default null, + package_key in apm_package_types.package_key%TYPE, + object_type in acs_objects.object_type%TYPE default 'apm_service', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_service_id integer; + begin + v_service_id := apm_package.new ( + package_id => service_id, + instance_name => instance_name, + package_key => package_key, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + return v_service_id; + end new; + + procedure del ( + service_id in acs_objects.object_id%TYPE + ) + is + begin + delete from apm_services + where service_id = apm_service.del.service_id; + apm_package.del( + package_id => service_id + ); + end del; + +end; +/ +show errors + +-- +-- acs-kernel/sql/community-core-create.sql +-- +-- Abstractions fundamental to any online community (or information +-- system, in general), derived in large part from the ACS 3.x +-- community-core data model by Philip Greenspun (philg@mit.edu), from +-- the ACS 3.x user-groups data model by Tracy Adams (teadams@mit.edu) +-- from Chapter 3 (The Enterprise and Its World) of David Hay's +-- book _Data_Model_Patterns_, and from Chapter 2 (Accountability) +-- of Martin Fowler's book _Analysis_Patterns_. +-- +-- @author Michael Yoon (michael@arsdigita.com) +-- @author Rafael Schloming (rhs@mit.edu) +-- @author Jon Salz (jsalz@mit.edu) +-- +-- @creation-date 2000-05-18 +-- +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +------------------- +-- PARTY PACKAGE -- +------------------- + +create or replace package party +as + + function new ( + party_id in parties.party_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'party', + 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, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) return parties.party_id%TYPE; + + procedure del ( + party_id in parties.party_id%TYPE + ); + + function name ( + party_id in parties.party_id%TYPE + ) return varchar2; + + function email ( + party_id in parties.party_id%TYPE + ) return varchar2; + +end party; +/ +show errors + + +create or replace package body party +as + + function new ( + party_id in parties.party_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'party', + 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, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) + return parties.party_id%TYPE + is + v_party_id parties.party_id%TYPE; + begin + v_party_id := + acs_object.new(party_id, object_type, + creation_date, creation_user, creation_ip, context_id); + + insert into parties + (party_id, email, url) + values + (v_party_id, lower(email), url); + + return v_party_id; + end new; + + procedure del ( + party_id in parties.party_id%TYPE + ) + is + begin + acs_object.del(party_id); + end del; + + function name ( + party_id in parties.party_id%TYPE + ) + return varchar2 + is + begin + if party_id = -1 then + return 'The Public'; + else + return null; + end if; + end name; + + function email ( + party_id in parties.party_id%TYPE + ) + return varchar2 + is + v_email parties.email%TYPE; + begin + select email + into v_email + from parties + where party_id = email.party_id; + + return v_email; + + end email; + +end party; +/ +show errors + + +-------------------- +-- PERSON PACKAGE -- +-------------------- + +create or replace package person +as + + function new ( + person_id in persons.person_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'person', + 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, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + first_names in persons.first_names%TYPE, + last_name in persons.last_name%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return persons.person_id%TYPE; + + procedure del ( + person_id in persons.person_id%TYPE + ); + + function name ( + person_id in persons.person_id%TYPE + ) return varchar2; + + function first_names ( + person_id in persons.person_id%TYPE + ) return varchar2; + + function last_name ( + person_id in persons.person_id%TYPE + ) return varchar2; + +end person; +/ +show errors + +create or replace package body person +as + + function new ( + person_id in persons.person_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'person', + 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, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + first_names in persons.first_names%TYPE, + last_name in persons.last_name%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) + return persons.person_id%TYPE + is + v_person_id persons.person_id%TYPE; + begin + v_person_id := + party.new(person_id, object_type, + creation_date, creation_user, creation_ip, + email, url, context_id); + + insert into persons + (person_id, first_names, last_name) + values + (v_person_id, first_names, last_name); + + return v_person_id; + end new; + + procedure del ( + person_id in persons.person_id%TYPE + ) + is + begin + delete from persons + where person_id = person.del.person_id; + + party.del(person_id); + end del; + + function name ( + person_id in persons.person_id%TYPE + ) + return varchar2 + is + person_name varchar2(200); + begin + select first_names || ' ' || last_name + into person_name + from persons + where person_id = name.person_id; + + return person_name; + end name; + + function first_names ( + person_id in persons.person_id%TYPE + ) + return varchar2 + is + person_first_names varchar2(200); + begin + select first_names + into person_first_names + from persons + where person_id = first_names.person_id; + + return person_first_names; + end first_names; + +function last_name ( + person_id in persons.person_id%TYPE + ) + return varchar2 + is + person_last_name varchar2(200); + begin + select last_name + into person_last_name + from persons + where person_id = last_name.person_id; + + return person_last_name; + end last_name; + +end person; +/ +show errors + + +---------------------- +-- ACS_USER PACKAGE -- +---------------------- + +create or replace package acs_user +as + + function new ( + user_id in users.user_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'user', + 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, + authority_id in auth_authorities.authority_id%TYPE default null, + username in users.username%TYPE, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + first_names in persons.first_names%TYPE, + last_name in persons.last_name%TYPE, + password in users.password%TYPE, + salt in users.salt%TYPE, + screen_name in users.screen_name%TYPE default null, + email_verified_p in users.email_verified_p%TYPE default 't', + context_id in acs_objects.context_id%TYPE default null + ) + return users.user_id%TYPE; + + function receives_alerts_p ( + user_id in users.user_id%TYPE + ) + return char; + + procedure approve_email ( + user_id in users.user_id%TYPE + ); + + procedure unapprove_email ( + user_id in users.user_id%TYPE + ); + + procedure del ( + user_id in users.user_id%TYPE + ); + +end acs_user; +/ +show errors + +create or replace package body acs_user +as + + function new ( + user_id in users.user_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'user', + 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, + authority_id in auth_authorities.authority_id%TYPE default null, + username in users.username%TYPE, + email in parties.email%TYPE, + url in parties.url%TYPE default null, + first_names in persons.first_names%TYPE, + last_name in persons.last_name%TYPE, + password in users.password%TYPE, + salt in users.salt%TYPE, + screen_name in users.screen_name%TYPE default null, + email_verified_p in users.email_verified_p%TYPE default 't', + context_id in acs_objects.context_id%TYPE default null + ) + return users.user_id%TYPE + is + v_authority_id auth_authorities.authority_id%TYPE; + v_user_id users.user_id%TYPE; + begin + v_user_id := + person.new(user_id, object_type, + creation_date, creation_user, creation_ip, + email, url, + first_names, last_name, context_id); + + -- default to local authority + if authority_id is null then + select authority_id + into v_authority_id + from auth_authorities + where short_name = 'local'; + else + v_authority_id := authority_id; + end if; + + insert into users + (user_id, authority_id, username, password, salt, screen_name, email_verified_p) + values + (v_user_id, v_authority_id, username, password, salt, screen_name, email_verified_p); + + insert into user_preferences + (user_id) + values + (v_user_id); + + return v_user_id; + end new; + + function receives_alerts_p ( + user_id in users.user_id%TYPE + ) + return char + is + counter char(1); + begin + select decode(count(*),0,'f','t') into counter + from users + where no_alerts_until >= sysdate + and user_id = acs_user.receives_alerts_p.user_id; + + return counter; + + end receives_alerts_p; + + procedure approve_email ( + user_id in users.user_id%TYPE + ) + is + begin + update users + set email_verified_p = 't' + where user_id = approve_email.user_id; + end approve_email; + + + procedure unapprove_email ( + user_id in users.user_id%TYPE + ) + is + begin + update users + set email_verified_p = 'f' + where user_id = unapprove_email.user_id; + end unapprove_email; + + procedure del ( + user_id in users.user_id%TYPE + ) + is + begin + delete from user_preferences + where user_id = acs_user.del.user_id; + + delete from users + where user_id = acs_user.del.user_id; + + person.del(user_id); + end del; + +end acs_user; +/ +show errors + +-- +-- packages/acs-kernel/sql/groups-body-create.sql +-- +-- @author rhs@mit.edu +-- @creation-date 2000-08-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + + +-------------------- +-- PACKAGE BODIES -- +-------------------- + +create or replace package body composition_rel +as + + function new ( + rel_id in composition_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'composition_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return composition_rels.rel_id%TYPE + is + v_rel_id integer; + begin + v_rel_id := acs_rel.new ( + rel_id => rel_id, + rel_type => rel_type, + object_id_one => object_id_one, + object_id_two => object_id_two, + context_id => object_id_one, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into composition_rels + (rel_id) + values + (v_rel_id); + + return v_rel_id; + end; + + procedure del ( + rel_id in composition_rels.rel_id%TYPE + ) + is + begin + acs_rel.del(rel_id); + end; + + function check_path_exists_p ( + component_id in groups.group_id%TYPE, + container_id in groups.group_id%TYPE + ) return char + is + begin + if component_id = container_id then + return 't'; + end if; + + for row in (select r.object_id_one as parent_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_two = component_id) loop + if check_path_exists_p(row.parent_id, container_id) = 't' then + return 't'; + end if; + end loop; + + return 'f'; + end; + + function check_index ( + component_id in groups.group_id%TYPE, + container_id in groups.group_id%TYPE + ) return char + is + result char(1); + n_rows integer; + begin + result := 't'; + + -- Loop through all the direct containers (DC) of COMPONENT_ID + -- that are also contained by CONTAINER_ID and verify that the + -- GROUP_COMPONENT_INDEX contains the (GROUP_ID, DC.REL_ID, + -- CONTAINER_ID) triple. + for dc in (select r.rel_id, r.object_id_one as container_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_two = component_id) loop + + if check_path_exists_p(dc.container_id, + check_index.container_id) = 't' then + select decode(count(*),0,0,1) into n_rows + from group_component_index + where group_id = check_index.container_id + and component_id = check_index.component_id + and rel_id = dc.rel_id; + + if n_rows = 0 then + result := 'f'; + acs_log.error('composition_rel.check_representation', + 'Row missing from group_component_index for (' || + 'group_id = ' || container_id || ', ' || + 'component_id = ' || component_id || ', ' || + 'rel_id = ' || dc.rel_id || ')'); + end if; + + end if; + + end loop; + + -- Loop through all the containers of CONTAINER_ID. + for r1 in (select r.object_id_one as container_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_two = check_index.container_id + union + select check_index.container_id + from dual) loop + -- Loop through all the components of COMPONENT_ID and make a + -- recursive call. + for r2 in (select r.object_id_two as component_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_one = check_index.component_id + union + select check_index.component_id + from dual) loop + if (r1.container_id != check_index.container_id or + r2.component_id != check_index.component_id) and + check_index(r2.component_id, r1.container_id) = 'f' then + result := 'f'; + end if; + end loop; + end loop; + + return result; + end; + + function check_representation ( + rel_id in composition_rels.rel_id%TYPE + ) return char + is + container_id groups.group_id%TYPE; + component_id groups.group_id%TYPE; + result char(1); + begin + result := 't'; + + if acs_object.check_representation(rel_id) = 'f' then + result := 'f'; + end if; + + select object_id_one, object_id_two + into container_id, component_id + from acs_rels + where rel_id = check_representation.rel_id; + + -- First let's check that the index has all the rows it should. + if check_index(component_id, container_id) = 'f' then + result := 'f'; + end if; + + -- Now let's check that the index doesn't have any extraneous rows + -- relating to this relation. + for row in (select * + from group_component_index + where rel_id = check_representation.rel_id) loop + if check_path_exists_p(row.component_id, row.group_id) = 'f' then + result := 'f'; + acs_log.error('composition_rel.check_representation', + 'Extraneous row in group_component_index: ' || + 'group_id = ' || row.group_id || ', ' || + 'component_id = ' || row.component_id || ', ' || + 'rel_id = ' || row.rel_id || ', ' || + 'container_id = ' || row.container_id || '.'); + end if; + end loop; + + return result; + end; + +end composition_rel; +/ +show errors + + + + +create or replace package body membership_rel +as + + function new ( + rel_id in membership_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'membership_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default 'approved', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return membership_rels.rel_id%TYPE + is + v_rel_id integer; + begin + v_rel_id := acs_rel.new ( + rel_id => rel_id, + rel_type => rel_type, + object_id_one => object_id_one, + object_id_two => object_id_two, + context_id => object_id_one, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into membership_rels + (rel_id, member_state) + values + (v_rel_id, new.member_state); + + return v_rel_id; + end; + + procedure ban ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + update membership_rels + set member_state = 'banned' + where rel_id = ban.rel_id; + end; + + procedure approve ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + update membership_rels + set member_state = 'approved' + where rel_id = approve.rel_id; + end; + + procedure reject ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + update membership_rels + set member_state = 'rejected' + where rel_id = reject.rel_id; + end; + + procedure unapprove ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + update membership_rels + set member_state = 'needs approval' + where rel_id = unapprove.rel_id; + end; + + procedure deleted ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + update membership_rels + set member_state = 'deleted' + where rel_id = deleted.rel_id; + end; + + procedure del ( + rel_id in membership_rels.rel_id%TYPE + ) + is + begin + acs_rel.del(rel_id); + end; + + function check_index ( + group_id in groups.group_id%TYPE, + member_id in parties.party_id%TYPE, + container_id in groups.group_id%TYPE + ) return char + is + result char(1); + n_rows integer; + begin + + select count(*) into n_rows + from group_member_index + where group_id = check_index.group_id + and member_id = check_index.member_id + and container_id = check_index.container_id; + + if n_rows = 0 then + result := 'f'; + acs_log.error('membership_rel.check_representation', + 'Row missing from group_member_index: ' || + 'group_id = ' || group_id || ', ' || + 'member_id = ' || member_id || ', ' || + 'container_id = ' || container_id || '.'); + end if; + + for row in (select r.object_id_one as container_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_two = group_id) loop + if check_index(row.container_id, member_id, container_id) = 'f' then + result := 'f'; + end if; + end loop; + + return result; + end; + + function check_representation ( + rel_id in membership_rels.rel_id%TYPE + ) return char + is + group_id groups.group_id%TYPE; + member_id parties.party_id%TYPE; + result char(1); + begin + result := 't'; + + if acs_object.check_representation(rel_id) = 'f' then + result := 'f'; + end if; + + select r.object_id_one, r.object_id_two + into group_id, member_id + from acs_rels r, membership_rels m + where r.rel_id = m.rel_id + and m.rel_id = check_representation.rel_id; + + if check_index(group_id, member_id, group_id) = 'f' then + result := 'f'; + end if; + + for row in (select * + from group_member_index + where rel_id = check_representation.rel_id) loop + if composition_rel.check_path_exists_p(row.container_id, + row.group_id) = 'f' then + result := 'f'; + acs_log.error('membership_rel.check_representation', + 'Extra row in group_member_index: ' || + 'group_id = ' || row.group_id || ', ' || + 'member_id = ' || row.member_id || ', ' || + 'container_id = ' || row.container_id || '.'); + end if; + end loop; + + return result; + end; + +end membership_rel; +/ +show errors + + + +create or replace package body admin_rel +as + + function new ( + rel_id in admin_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'admin_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default 'approved', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return admin_rels.rel_id%TYPE + is + v_rel_id integer; + begin + v_rel_id := membership_rel.new ( + rel_id => rel_id, + rel_type => rel_type, + object_id_one => object_id_one, + object_id_two => object_id_two, + member_state => member_state, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into admin_rels + (rel_id) + values + (v_rel_id); + + return v_rel_id; + end; + + procedure del ( + rel_id in admin_rels.rel_id%TYPE + ) + is + begin + membership_rel.del(rel_id); + end; + +end admin_rel; +/ +show errors + + + +create or replace package body acs_group +is + function new ( + group_id in groups.group_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'group', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + group_name in groups.group_name%TYPE, + join_policy in groups.join_policy%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) + return groups.group_id%TYPE + is + v_group_id groups.group_id%TYPE; + v_group_type_exists_p integer; + v_join_policy groups.join_policy%TYPE; + begin + v_group_id := + party.new(group_id, object_type, creation_date, creation_user, + creation_ip, email, url, context_id); + + v_join_policy := join_policy; + + -- if join policy wasn't specified, select the default based on group type + if v_join_policy is null then + select count(*) into v_group_type_exists_p + from group_types + where group_type = object_type; + + if v_group_type_exists_p = 1 then + select default_join_policy into v_join_policy + from group_types + where group_type = object_type; + else + v_join_policy := 'open'; + end if; + end if; + + insert into groups + (group_id, group_name, join_policy) + values + (v_group_id, group_name, v_join_policy); + + + -- setup the permissible relationship types for this group + insert into group_rels + (group_rel_id, group_id, rel_type) + select acs_object_id_seq.nextval, v_group_id, g.rel_type + from group_type_rels g + where g.group_type = new.object_type; + + return v_group_id; + end new; + + + procedure del ( + group_id in groups.group_id%TYPE + ) + is + begin + + -- Delete all segments defined for this group + for row in (select segment_id + from rel_segments + where group_id = acs_group.del.group_id) loop + + rel_segment.del(row.segment_id); + + end loop; + + -- Delete all the relations of any type to this group + for row in (select r.rel_id, t.package_name + from acs_rels r, acs_object_types t + where r.rel_type = t.object_type + and (r.object_id_one = acs_group.del.group_id + or r.object_id_two = acs_group.del.group_id)) loop + execute immediate 'begin ' || row.package_name || '.del(' || row.rel_id || '); end;'; + end loop; + + party.del(group_id); + end del; + + function name ( + group_id in groups.group_id%TYPE + ) + return varchar2 + is + group_name varchar2(200); + begin + select group_name + into group_name + from groups + where group_id = name.group_id; + + return group_name; + end name; + + function member_p ( + party_id in parties.party_id%TYPE, + group_id in groups.group_id%TYPE, + cascade_membership char + ) + return char + is + m_result integer; + begin + + if cascade_membership = 't' then + select count(*) + into m_result + from group_member_map + where group_id = member_p.group_id and + member_id = member_p.party_id; + + if m_result > 0 then + return 't'; + end if; + else + select count(*) + into m_result + from acs_rels rels, all_object_party_privilege_map perm + where perm.object_id = rels.rel_id + and perm.privilege = 'read' + and rels.rel_type = 'membership_rel' + and rels.object_id_one = member_p.group_id + and rels.object_id_two = member_p.party_id; + + if m_result > 0 then + return 't'; + end if; + end if; + + return 'f'; + end member_p; + + function check_representation ( + group_id in groups.group_id%TYPE + ) return char + is + result char(1); + begin + result := 't'; + acs_log.notice('acs_group.check_representation', + 'Running check_representation on group ' || group_id); + + if acs_object.check_representation(group_id) = 'f' then + result := 'f'; + end if; + + for c in (select c.rel_id + from acs_rels r, composition_rels c + where r.rel_id = c.rel_id + and r.object_id_one = group_id) loop + if composition_rel.check_representation(c.rel_id) = 'f' then + result := 'f'; + end if; + end loop; + + for m in (select m.rel_id + from acs_rels r, membership_rels m + where r.rel_id = m.rel_id + and r.object_id_one = group_id) loop + if membership_rel.check_representation(m.rel_id) = 'f' then + result := 'f'; + end if; + end loop; + + acs_log.notice('acs_group.check_representation', + 'Done running check_representation on group ' || group_id); + return result; + end; + +end acs_group; +/ +show errors + +-- +-- packages/acs-kernel/sql/groups-create.sql +-- +-- @author rhs@mit.edu +-- @creation-date 2000-08-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +-------------- +-- PACKAGES -- +-------------- + +create or replace package composition_rel +as + + function new ( + rel_id in composition_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'composition_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return composition_rels.rel_id%TYPE; + + procedure del ( + rel_id in composition_rels.rel_id%TYPE + ); + + function check_path_exists_p ( + component_id in groups.group_id%TYPE, + container_id in groups.group_id%TYPE + ) return char; + + function check_representation ( + rel_id in composition_rels.rel_id%TYPE + ) return char; + +end composition_rel; +/ +show errors + + +create or replace package membership_rel +as + + function new ( + rel_id in membership_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'membership_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default 'approved', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return membership_rels.rel_id%TYPE; + + procedure ban ( + rel_id in membership_rels.rel_id%TYPE + ); + + procedure approve ( + rel_id in membership_rels.rel_id%TYPE + ); + + procedure reject ( + rel_id in membership_rels.rel_id%TYPE + ); + + procedure unapprove ( + rel_id in membership_rels.rel_id%TYPE + ); + + procedure deleted ( + rel_id in membership_rels.rel_id%TYPE + ); + + procedure del ( + rel_id in membership_rels.rel_id%TYPE + ); + + function check_representation ( + rel_id in membership_rels.rel_id%TYPE + ) return char; + +end membership_rel; +/ +show errors + + +create or replace package admin_rel +as + + function new ( + rel_id in admin_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'admin_rel', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default 'approved', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return admin_rels.rel_id%TYPE; + + procedure del ( + rel_id in admin_rels.rel_id%TYPE + ); + +end admin_rel; +/ +show errors + + +create or replace package acs_group +is + function new ( + group_id in groups.group_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'group', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + group_name in groups.group_name%TYPE, + join_policy in groups.join_policy%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) return groups.group_id%TYPE; + + procedure del ( + group_id in groups.group_id%TYPE + ); + + function name ( + group_id in groups.group_id%TYPE + ) return varchar2; + + function member_p ( + party_id in parties.party_id%TYPE, + group_id in groups.group_id%TYPE, + cascade_membership char + ) return char; + + function check_representation ( + group_id in groups.group_id%TYPE + ) return char; + +end acs_group; +/ +show errors + +-- Data model to keep a journal of all actions on objects. +-- +-- +-- @author Lars Pind (lars@pinds.com) +-- @creation-date 2000-22-18 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- +-- Copyright (C) 1999-2000 ArsDigita Corporation +-- +-- This is free software distributed under the terms of the GNU Public +-- License. Full text of the license is available from the GNU Project: +-- http://www.fsf.org/copyleft/gpl.html + + + +create or replace package journal_entry +as + + function new ( + journal_id in journal_entries.journal_id%TYPE default null, + object_id in journal_entries.object_id%TYPE, + action in journal_entries.action%TYPE, + action_pretty in journal_entries.action_pretty%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, + msg in journal_entries.msg%TYPE default null + ) return journal_entries.journal_id%TYPE; + + procedure del ( + journal_id in journal_entries.journal_id%TYPE + ); + + procedure delete_for_object( + object_id in acs_objects.object_id%TYPE + ); + +end journal_entry; +/ +show errors; + +create or replace package body journal_entry +as + + function new ( + journal_id in journal_entries.journal_id%TYPE default null, + object_id in journal_entries.object_id%TYPE, + action in journal_entries.action%TYPE, + action_pretty in journal_entries.action_pretty%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, + msg in journal_entries.msg%TYPE default null + ) return journal_entries.journal_id%TYPE + is + v_journal_id journal_entries.journal_id%TYPE; + begin + v_journal_id := acs_object.new ( + object_id => journal_id, + object_type => 'journal_entry', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => object_id + ); + + insert into journal_entries ( + journal_id, object_id, action, action_pretty, msg + ) values ( + v_journal_id, object_id, action, action_pretty, msg + ); + + return v_journal_id; + end new; + + procedure del ( + journal_id in journal_entries.journal_id%TYPE + ) + is + begin + delete from journal_entries where journal_id = journal_entry.del.journal_id; + acs_object.del(journal_entry.del.journal_id); + end del; + + procedure delete_for_object( + object_id in acs_objects.object_id%TYPE + ) + is + cursor journal_cur is + select journal_id from journal_entries where object_id = delete_for_object.object_id; + begin + for journal_rec in journal_cur loop + journal_entry.del(journal_rec.journal_id); + end loop; + end delete_for_object; + +end journal_entry; +/ +show errors; + +-- +-- /packages/acs-kernel/sql/rel-constraints-create.sql +-- +-- Add support for relational constraints based on relational segmentation. +-- +-- @author Oumi Mehrotra (oumi@arsdigita.com) +-- @creation-date 2000-11-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +-- Copyright (C) 1999-2000 ArsDigita Corporation +-- This is free software distributed under the terms of the GNU Public +-- License. Full text of the license is available from the GNU Project: +-- http://www.fsf.org/copyleft/gpl.html + + +create or replace package body rel_constraint +as + + function new ( + constraint_id in rel_constraints.constraint_id%TYPE default null, + constraint_type in acs_objects.object_type%TYPE default 'rel_constraint', + constraint_name in rel_constraints.constraint_name%TYPE, + rel_segment in rel_constraints.rel_segment%TYPE, + rel_side in rel_constraints.rel_side%TYPE default 'two', + required_rel_segment in rel_constraints.required_rel_segment%TYPE, + context_id in acs_objects.context_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return rel_constraints.constraint_id%TYPE + is + v_constraint_id rel_constraints.constraint_id%TYPE; + begin + v_constraint_id := acs_object.new ( + object_id => constraint_id, + object_type => constraint_type, + context_id => context_id, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into rel_constraints + (constraint_id, constraint_name, + rel_segment, rel_side, required_rel_segment) + values + (v_constraint_id, new.constraint_name, + new.rel_segment, new.rel_side, new.required_rel_segment); + + return v_constraint_id; + end; + + procedure del ( + constraint_id in rel_constraints.constraint_id%TYPE + ) + is + begin + acs_object.del(constraint_id); + end; + + function get_constraint_id ( + rel_segment in rel_constraints.rel_segment%TYPE, + rel_side in rel_constraints.rel_side%TYPE default 'two', + required_rel_segment in rel_constraints.required_rel_segment%TYPE + ) return rel_constraints.constraint_id%TYPE + is + v_constraint_id rel_constraints.constraint_id%TYPE; + begin + select constraint_id into v_constraint_id + from rel_constraints + where rel_segment = get_constraint_id.rel_segment + and rel_side = get_constraint_id.rel_side + and required_rel_segment = get_constraint_id.required_rel_segment; + + return v_constraint_id; + + end; + + function violation ( + rel_id in acs_rels.rel_id%TYPE + ) return varchar + is + v_error varchar(4000); + begin + + v_error := null; + + for constraint_violated in + (select /*+ FIRST_ROWS*/ constraint_id, constraint_name + from rel_constraints_violated_one + where rel_id = rel_constraint.violation.rel_id + and rownum = 1) loop + + v_error := v_error || 'Relational Constraint Violation: ' || + constraint_violated.constraint_name || + ' (constraint_id=' || + constraint_violated.constraint_id || '). '; + + return v_error; + end loop; + + for constraint_violated in + (select /*+ FIRST_ROWS*/ constraint_id, constraint_name + from rel_constraints_violated_two + where rel_id = rel_constraint.violation.rel_id + and rownum = 1) loop + + v_error := v_error || 'Relational Constraint Violation: ' || + constraint_violated.constraint_name || + ' (constraint_id=' || + constraint_violated.constraint_id || '). '; + + return v_error; + end loop; + + return v_error; + + end violation; + + + function violation_if_removed ( + rel_id in acs_rels.rel_id%TYPE + ) return varchar + is + v_count integer; + v_error varchar(4000); + begin + v_error := null; + + select count(*) into v_count + from dual + where exists (select 1 from rc_violations_by_removing_rel r where r.rel_id = violation_if_removed.rel_id); + + if v_count > 0 then + -- some other relation depends on this one. Let's build up a string + -- of the constraints we are violating + for constraint_violated in (select constraint_id, constraint_name + from rc_violations_by_removing_rel r + where r.rel_id = violation_if_removed.rel_id) loop + + v_error := v_error || 'Relational Constraint Violation: ' || + constraint_violated.constraint_name || + ' (constraint_id=' || + constraint_violated.constraint_id || '). '; + + end loop; + + end if; + + return v_error; + + end; + + +end; +/ +show errors + +-- +-- /packages/acs-kernel/sql/rel-constraints-create.sql +-- +-- Add support for relational constraints based on relational segmentation. +-- +-- @author Oumi Mehrotra (oumi@arsdigita.com) +-- @creation-date 2000-11-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +-- Copyright (C) 1999-2000 ArsDigita Corporation +-- This is free software distributed under the terms of the GNU Public +-- License. Full text of the license is available from the GNU Project: +-- http://www.fsf.org/copyleft/gpl.html + +-------------- +-- PACKAGES -- +-------------- + +create or replace package rel_constraint +as + + function new ( + --/** Creates a new relational constraint + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + constraint_id in rel_constraints.constraint_id%TYPE default null, + constraint_type in acs_objects.object_type%TYPE default 'rel_constraint', + constraint_name in rel_constraints.constraint_name%TYPE, + rel_segment in rel_constraints.rel_segment%TYPE, + rel_side in rel_constraints.rel_side%TYPE default 'two', + required_rel_segment in rel_constraints.required_rel_segment%TYPE, + context_id in acs_objects.context_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return rel_constraints.constraint_id%TYPE; + + procedure del ( + constraint_id in rel_constraints.constraint_id%TYPE + ); + + function get_constraint_id ( + --/** Returns the constraint_id associated with the specified + -- rel_segment and required_rel_segment for the specified site. + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + rel_segment in rel_constraints.rel_segment%TYPE, + rel_side in rel_constraints.rel_side%TYPE default 'two', + required_rel_segment in rel_constraints.required_rel_segment%TYPE + ) return rel_constraints.constraint_id%TYPE; + + function violation ( + --/** Checks to see if there a relational constraint is violated + -- by the precense of the specified relation. If not, returns + -- null. If so, returns an appropriate error string. + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + -- @param rel_id The relation for which we want to find + -- any violations + --*/ + rel_id in acs_rels.rel_id%TYPE + ) return varchar; + + + function violation_if_removed ( + --/** Checks to see if removing the specified relation would violate + -- a relational constraint. If not, returns null. If so, returns + -- an appropriate error string. + -- + -- @author Michael Bryzek (mbryzek@arsdigita.com) + -- @creation-date 1/2001 + -- + -- @param rel_id The relation that we are planning to remove + --*/ + rel_id in acs_rels.rel_id%TYPE + ) return varchar; + +end; +/ +show errors +-- +-- packages/acs-kernel/sql/rel-segments-create.sql +-- +-- @author Oumi Mehrotra oumi@arsdigita.com +-- @creation-date 2000-11-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +-- Copyright (C) 1999-2000 ArsDigita Corporation +-- This is free software distributed under the terms of the GNU Public +-- License. Full text of the license is available from the GNU Project: +-- http://www.fsf.org/copyleft/gpl.html + +------------------ +-- PACKAGE BODY -- +------------------ + +create or replace package body rel_segment +is + function new ( + segment_id in rel_segments.segment_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'rel_segment', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + segment_name in rel_segments.segment_name%TYPE, + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return rel_segments.segment_id%TYPE + is + v_segment_id rel_segments.segment_id%TYPE; + begin + v_segment_id := + party.new(segment_id, object_type, creation_date, creation_user, + creation_ip, email, url, context_id); + + insert into rel_segments + (segment_id, segment_name, group_id, rel_type) + values + (v_segment_id, new.segment_name, new.group_id, new.rel_type); + + return v_segment_id; + end new; + + procedure del ( + segment_id in rel_segments.segment_id%TYPE + ) + is + begin + + -- remove all constraints on this segment + for row in (select constraint_id + from rel_constraints + where rel_segment = rel_segment.del.segment_id) loop + + rel_constraint.del(row.constraint_id); + + end loop; + + party.del(segment_id); + + end del; + + -- EXPERIMENTAL / UNSTABLE -- use at your own risk + -- + function get ( + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE + ) return rel_segments.segment_id%TYPE + is + v_segment_id rel_segments.segment_id%TYPE; + begin + select min(segment_id) into v_segment_id + from rel_segments + where group_id = get.group_id + and rel_type = get.rel_type; + + return v_segment_id; + end get; + + + -- EXPERIMENTAL / UNSTABLE -- use at your own risk + -- + -- This function simplifies the use of segments a little by letting + -- you not have to worry about creating and initializing segments. + -- If the segment you're interested in exists, this function + -- returns its segment_id. + -- If the segment you're interested in doesn't exist, this function + -- does a pretty minimal amount of initialization for the segment + -- and returns a new segment_id. + function get_or_new ( + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE, + segment_name in rel_segments.segment_name%TYPE + default null + ) return rel_segments.segment_id%TYPE + is + v_segment_id rel_segments.segment_id%TYPE; + v_segment_name rel_segments.segment_name%TYPE; + begin + + v_segment_id := get(group_id, rel_type); + + if v_segment_id is null then + + if segment_name is not null then + v_segment_name := segment_name; + else + select groups.group_name || ' - ' || acs_object_types.pretty_name || + ' segment' + into v_segment_name + from groups, acs_object_types + where groups.group_id = get_or_new.group_id + and acs_object_types.object_type = get_or_new.rel_type; + + end if; + + v_segment_id := rel_segment.new ( + object_type => 'rel_segment', + creation_user => null, + creation_ip => null, + email => null, + url => null, + segment_name => v_segment_name, + group_id => get_or_new.group_id, + rel_type => get_or_new.rel_type, + context_id => get_or_new.group_id + ); + + end if; + + return v_segment_id; + + end get_or_new; + + function name ( + segment_id in rel_segments.segment_id%TYPE + ) + return rel_segments.segment_name%TYPE + is + segment_name varchar(200); + begin + select segment_name + into segment_name + from rel_segments + where segment_id = name.segment_id; + + return segment_name; + end name; + +end rel_segment; +/ +show errors + +-- +-- packages/acs-kernel/sql/rel-segments-create.sql +-- +-- @author Oumi Mehrotra oumi@arsdigita.com +-- @creation-date 2000-11-22 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +-- Copyright (C) 1999-2000 ArsDigita Corporation +-- This is free software distributed under the terms of the GNU Public +-- License. Full text of the license is available from the GNU Project: +-- http://www.fsf.org/copyleft/gpl.html + +-- WARNING! +-- Relational segments is a new and experimental concept. The API may +-- change in the future, particularly the functions marked "EXPERIMENTAL". +-- + +-- create pl/sql package rel_segment + +create or replace package rel_segment +is + function new ( + --/** Creates a new relational segment + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + segment_id in rel_segments.segment_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'rel_segment', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + segment_name in rel_segments.segment_name%TYPE, + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return rel_segments.segment_id%TYPE; + + procedure del ( + --/** Deletes a relational segment + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + segment_id in rel_segments.segment_id%TYPE + ); + + function name ( + segment_id in rel_segments.segment_id%TYPE + ) return rel_segments.segment_name%TYPE; + + function get ( + --/** EXPERIMENTAL / UNSTABLE -- use at your own risk + -- Get the id of a segment given a group_id and rel_type. + -- This depends on the uniqueness of group_id,rel_type. We + -- might remove the unique constraint in the future, in which + -- case we would also probably remove this function. + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE + ) return rel_segments.segment_id%TYPE; + + function get_or_new ( + --/** EXPERIMENTAL / UNSTABLE -- use at your own risk + -- + -- This function simplifies the use of segments a little by letting + -- you not have to worry about creating and initializing segments. + -- If the segment you're interested in exists, this function + -- returns its segment_id. + -- If the segment you're interested in doesn't exist, this function + -- does a pretty minimal amount of initialization for the segment + -- and returns a new segment_id. + -- + -- @author Oumi Mehrotra (oumi@arsdigita.com) + -- @creation-date 12/2000 + -- + --*/ + group_id in rel_segments.group_id%TYPE, + rel_type in rel_segments.rel_type%TYPE, + segment_name in rel_segments.segment_name%TYPE + default null + ) return rel_segments.segment_id%TYPE; + +end rel_segment; +/ +show errors + + + + +create or replace package party_approved_member is + + procedure add_one( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE + ); + + procedure add( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE, + p_rel_type in acs_rels.rel_type%TYPE + ); + + procedure remove_one ( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE + ); + + procedure remove ( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE, + p_rel_type in acs_rels.rel_type%TYPE + ); + +end party_approved_member; +/ +show errors; + +create or replace package body party_approved_member is + + procedure add_one( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE + ) + is + begin + + insert into party_approved_member_map + (party_id, member_id, cnt) + values + (p_party_id, p_member_id, 1); + + exception when dup_val_on_index then + update party_approved_member_map + set cnt = cnt + 1 + where party_id = p_party_id + and member_id = p_member_id; + + end add_one; + + procedure add( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE, + p_rel_type in acs_rels.rel_type%TYPE + ) + is + begin + + add_one(p_party_id, p_member_id); + + -- if the relation type is mapped to a relational segment map that too + + for v_segments in (select segment_id + from rel_segments + where group_id = p_party_id + and rel_type in (select object_type + from acs_object_types + start with object_type = p_rel_type + connect by prior supertype = object_type)) + loop + add_one(v_segments.segment_id, p_member_id); + end loop; + + end add; + + procedure remove_one ( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE + ) + is + begin + + update party_approved_member_map + set cnt = cnt - 1 + where party_id = p_party_id + and member_id = p_member_id; + + delete from party_approved_member_map + where party_id = p_party_id + and member_id = p_member_id + and cnt = 0; + + end remove_one; + + procedure remove ( + p_party_id in parties.party_id%TYPE, + p_member_id in parties.party_id%TYPE, + p_rel_type in acs_rels.rel_type%TYPE + ) + is + begin + + remove_one(p_party_id, p_member_id); + + -- if the relation type is mapped to a relational segment unmap that too + + for v_segments in (select segment_id + from rel_segments + where group_id = p_party_id + and rel_type in (select object_type + from acs_object_types + start with object_type = p_rel_type + connect by prior supertype = object_type)) + loop + remove_one(v_segments.segment_id, p_member_id); + end loop; + + end remove; + +end party_approved_member; +/ +show errors; + + + +create or replace package site_node_object_map +as + + procedure new ( + object_id in site_node_object_mappings.object_id%TYPE, + node_id in site_node_object_mappings.node_id%TYPE + ); + + procedure del ( + object_id in site_node_object_mappings.object_id%TYPE + ); + +end site_node_object_map; +/ +show errors + +create or replace package body site_node_object_map +as + + procedure new ( + object_id in site_node_object_mappings.object_id%TYPE, + node_id in site_node_object_mappings.node_id%TYPE + ) is + begin + del(new.object_id); + + insert + into site_node_object_mappings + (object_id, node_id) + values + (new.object_id, new.node_id); + end new; + + procedure del ( + object_id in site_node_object_mappings.object_id%TYPE + ) is + begin + delete + from site_node_object_mappings + where object_id = del.object_id; + end del; + +end site_node_object_map; +/ +show errors + +-- +-- packages/acs-kernel/sql/site-nodes-create.sql +-- +-- @author rhs@mit.edu +-- @creation-date 2000-09-05 +-- @cvs-id $Id: upgrade-5.0d9-5.0d13.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + + +create or replace package site_node +as + + -- Create a new site node. If you set directory_p to be 'f' then you + -- cannot create nodes that have this node as their parent. + + function new ( + node_id in site_nodes.node_id%TYPE default null, + parent_id in site_nodes.node_id%TYPE default null, + name in site_nodes.name%TYPE, + object_id in site_nodes.object_id%TYPE default null, + directory_p in site_nodes.directory_p%TYPE, + pattern_p in site_nodes.pattern_p%TYPE default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return site_nodes.node_id%TYPE; + + -- Delete a site node. + + procedure del ( + node_id in site_nodes.node_id%TYPE + ); + + -- Return the node_id of a url. If the url begins with '/' then the + -- parent_id must be null. This will raise the no_data_found + -- exception if there is no mathing node in the site_nodes table. + -- This will match directories even if no trailing slash is included + -- in the url. + + function node_id ( + url in varchar2, + parent_id in site_nodes.node_id%TYPE default null + ) return site_nodes.node_id%TYPE; + + -- Return the url of a node_id. + + function url ( + node_id in site_nodes.node_id%TYPE + ) return varchar2; + +end; +/ +show errors + +create or replace package body site_node +as + + function new ( + node_id in site_nodes.node_id%TYPE default null, + parent_id in site_nodes.node_id%TYPE default null, + name in site_nodes.name%TYPE, + object_id in site_nodes.object_id%TYPE default null, + directory_p in site_nodes.directory_p%TYPE, + pattern_p in site_nodes.pattern_p%TYPE default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return site_nodes.node_id%TYPE + is + v_node_id site_nodes.node_id%TYPE; + v_directory_p site_nodes.directory_p%TYPE; + begin + if parent_id is not null then + select directory_p into v_directory_p + from site_nodes + where node_id = new.parent_id; + + if v_directory_p = 'f' then + raise_application_error ( + -20000, + 'Node ' || parent_id || ' is not a directory' + ); + end if; + end if; + + v_node_id := acs_object.new ( + object_id => node_id, + object_type => 'site_node', + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into site_nodes + (node_id, parent_id, name, object_id, directory_p, pattern_p) + values + (v_node_id, new.parent_id, new.name, new.object_id, + new.directory_p, new.pattern_p); + + return v_node_id; + end; + + procedure del ( + node_id in site_nodes.node_id%TYPE + ) + is + begin + delete from site_nodes + where node_id = site_node.del.node_id; + + acs_object.del(node_id); + end; + + function find_pattern ( + node_id in site_nodes.node_id%TYPE + ) return site_nodes.node_id%TYPE + is + v_pattern_p site_nodes.pattern_p%TYPE; + v_parent_id site_nodes.node_id%TYPE; + begin + if node_id is null then + raise no_data_found; + end if; + + select pattern_p, parent_id into v_pattern_p, v_parent_id + from site_nodes + where node_id = find_pattern.node_id; + + if v_pattern_p = 't' then + return node_id; + else + return find_pattern(v_parent_id); + end if; + end; + + function node_id ( + url in varchar2, + parent_id in site_nodes.node_id%TYPE default null + ) return site_nodes.node_id%TYPE + is + v_pos integer; + v_first site_nodes.name%TYPE; + v_rest varchar2(4000); + v_node_id integer; + v_pattern_p site_nodes.pattern_p%TYPE; + v_url varchar2(4000); + v_directory_p site_nodes.directory_p%TYPE; + v_trailing_slash_p char(1); + begin + v_url := url; + + if substr(v_url, length(v_url), 1) = '/' then + -- It ends with a / so it must be a directory. + v_trailing_slash_p := 't'; + v_url := substr(v_url, 1, length(v_url) - 1); + end if; + + v_pos := 1; + + while v_pos <= length(v_url) and substr(v_url, v_pos, 1) != '/' loop + v_pos := v_pos + 1; + end loop; + + if v_pos = length(v_url) then + v_first := v_url; + v_rest := null; + else + v_first := substr(v_url, 1, v_pos - 1); + v_rest := substr(v_url, v_pos + 1); + end if; + + begin + -- Is there a better way to do these freaking null compares? + select node_id, directory_p into v_node_id, v_directory_p + from site_nodes + where nvl(parent_id, 3.14) = nvl(site_node.node_id.parent_id, 3.14) + and nvl(name, chr(10)) = nvl(v_first, chr(10)); + exception + when no_data_found then + return find_pattern(parent_id); + end; + + if v_rest is null then + if v_trailing_slash_p = 't' and v_directory_p = 'f' then + return find_pattern(parent_id); + else + return v_node_id; + end if; + else + return node_id(v_rest, v_node_id); + end if; + end; + + function url ( + node_id in site_nodes.node_id%TYPE + ) return varchar2 + is + v_parent_id site_nodes.node_id%TYPE; + v_name site_nodes.name%TYPE; + v_directory_p site_nodes.directory_p%TYPE; + begin + if node_id is null then + return ''; + end if; + + select parent_id, name, directory_p into + v_parent_id, v_name, v_directory_p + from site_nodes + where node_id = url.node_id; + + if v_directory_p = 't' then + return url(v_parent_id) || v_name || '/'; + else + return url(v_parent_id) || v_name; + end if; + end; + +end; +/ +show errors + + + +-- +-- +-- +-- +-- +----------- +-- VIEWS -- +----------- + +-- View rel_constraints_violated_one +-- +-- pseudo sql: +-- +-- select all the side 'one' constraints +-- from the constraints and the associated relations of rel_segment +-- where the relation's container_id (i.e., object_id_one) is not in the +-- relational segment required_rel_segment. + +create or replace view rel_constraints_violated_one as +select constrained_rels.constraint_id, constrained_rels.constraint_name, + constrained_rels.rel_id, constrained_rels.container_id, + constrained_rels.party_id, constrained_rels.rel_type, + constrained_rels.rel_segment,constrained_rels.rel_side, + constrained_rels.required_rel_segment +from (select rel_constraints.constraint_id, rel_constraints.constraint_name, + r.rel_id, r.container_id, r.party_id, r.rel_type, + rel_constraints.rel_segment, + rel_constraints.rel_side, + rel_constraints.required_rel_segment + from rel_constraints, rel_segment_party_map r + where rel_constraints.rel_side = 'one' + and rel_constraints.rel_segment = r.segment_id + ) constrained_rels, + rel_segment_party_map rspm +where rspm.segment_id(+) = constrained_rels.required_rel_segment + and constrained_rels.container_id is null + and rspm.party_id is null; + +-- View rel_constraints_violated_two +-- +-- pseudo sql: +-- +-- select all the side 'two' constraints +-- from the constraints and the associated relations of rel_segment +-- where the relation's party_id (i.e., object_id_two) is not in the +-- relational segment required_rel_segment. + +create or replace view rel_constraints_violated_two as +select constrained_rels.constraint_id, constrained_rels.constraint_name, + constrained_rels.rel_id, constrained_rels.container_id, + constrained_rels.party_id, constrained_rels.rel_type, + constrained_rels.rel_segment,constrained_rels.rel_side, + constrained_rels.required_rel_segment +from (select rel_constraints.constraint_id, rel_constraints.constraint_name, + r.rel_id, r.container_id, r.party_id, r.rel_type, + rel_constraints.rel_segment, + rel_constraints.rel_side, + rel_constraints.required_rel_segment + from rel_constraints, rel_segment_party_map r + where rel_constraints.rel_side = 'two' + and rel_constraints.rel_segment = r.segment_id + ) constrained_rels, + rel_segment_party_map rspm +where rspm.segment_id(+) = constrained_rels.required_rel_segment + and constrained_rels.party_id is null + and rspm.party_id is null; + + +-- View: rc_all_constraints +-- +-- Question: Given group :group_id and rel_type :rel_type . . . +-- +-- What segments must a party be in +-- if the party were to be on side :rel_side of a relation of +-- type :rel_type to group :group_id ? +-- +-- Answer: select required_rel_segment +-- from rc_all_constraints +-- where group_id = :group_id +-- and rel_type = :rel_type +-- and rel_side = :rel_side +-- +-- Notes: we take special care not to get identity rows, where group_id and +-- rel_type are equivalent to segment_id. This can happen if there are some +-- funky constraints in the system, such as membership to Arsdigita requires +-- user_profile to Arsdigita. Then you could get rows from the +-- rc_all_constraints view saying that: +-- user_profile to Arsdigita +-- requires being in the segment of Arsdigita Users. +-- +-- This happens because user_profile is a type of memebrship, and there's a +-- constraint saying that membership to Arsdigita requires being in the +-- Arsdigita Users segment. We eliminate such rows from the rc_all_constraints +-- view with the "not (...)" clause below. +-- +create or replace view rc_all_constraints as +select group_rel_types.group_id, + group_rel_types.rel_type, + rel_constraints.rel_segment, + rel_constraints.rel_side, + required_rel_segment + from rel_constraints, + rel_segment_group_rel_type_map group_rel_types, + rel_segments req_seg + where rel_constraints.rel_segment = group_rel_types.segment_id + and rel_constraints.required_rel_segment = req_seg.segment_id + and not (req_seg.group_id = group_rel_types.group_id and + req_seg.rel_type = group_rel_types.rel_type); + +create or replace view rc_all_distinct_constraints as +select distinct + group_id, rel_type, rel_segment, rel_side, required_rel_segment +from rc_all_constraints; + + +-- THIS VIEW IS FOR COMPATIBILITY WITH EXISTING CODE +-- New code should use rc_all_constraints instead! +-- +-- View: rc_required_rel_segments +-- +-- Question: Given group :group_id and rel_type :rel_type . . . +-- +-- What segments must a party be in +-- if the party were to be belong to group :group_id +-- through a relation of type :rel_type ? +-- +-- Answer: select required_rel_segment +-- from rc_required_rel_segments +-- where group_id = :group_id +-- and rel_type = :rel_type +-- + +create or replace view rc_required_rel_segments as +select distinct group_id, rel_type, required_rel_segment +from rc_all_constraints +where rel_side = 'two'; + + +-- View: rc_parties_in_required_segs +-- +-- Question: Given group :group_id and rel_type :rel_type . . . +-- +-- What parties are "allowed" to be in group :group_id +-- through a relation of type :rel_type ? By "allowed", +-- we mean that no relational constraints would be violated. +-- +-- Answer: select party_id, acs_object.name(party_id) +-- from parties_in_rc_required_rel_segments +-- where group_id = :group_id +-- and rel_type = :rel_type +-- +create or replace view rc_parties_in_required_segs as +select parties_in_required_segs.group_id, + parties_in_required_segs.rel_type, + parties_in_required_segs.party_id +from + (select required_segs.group_id, + required_segs.rel_type, + seg_parties.party_id, + count(*) as num_matching_segs + from rc_required_rel_segments required_segs, + rel_segment_party_map seg_parties + where required_segs.required_rel_segment = seg_parties.segment_id + group by required_segs.group_id, + required_segs.rel_type, + seg_parties.party_id) parties_in_required_segs, + (select group_id, rel_type, count(*) as total + from rc_required_rel_segments + group by group_id, rel_type) total_num_required_segs +where + parties_in_required_segs.group_id = total_num_required_segs.group_id + and parties_in_required_segs.rel_type = total_num_required_segs.rel_type + and parties_in_required_segs.num_matching_segs = total_num_required_segs.total +UNION ALL +select group_rel_type_combos.group_id, + group_rel_type_combos.rel_type, + parties.party_id +from rc_required_rel_segments, + (select groups.group_id, comp_or_member_rel_types.rel_type + from groups, + (select object_type as rel_type from acs_object_types + start with object_type = 'membership_rel' + or object_type = 'composition_rel' + connect by supertype = prior object_type) comp_or_member_rel_types + ) group_rel_type_combos, + parties +where rc_required_rel_segments.group_id(+) = group_rel_type_combos.group_id + and rc_required_rel_segments.rel_type(+) = group_rel_type_combos.rel_type + and rc_required_rel_segments.group_id is null; + + +-- View: rc_valid_rel_types +-- +-- Question: What types of membership or composition are "valid" +-- for group :group_id ? A membership or composition +-- type R is "valid" when no relational constraints would +-- be violated if a party were to belong to group :group_id +-- through a rel of type R. +-- +-- Answer: select rel_type +-- from rc_valid_rel_types +-- where group_id = :group_id +-- +-- +create or replace view rc_valid_rel_types as +select side_one_constraints.group_id, + side_one_constraints.rel_type + from (select required_segs.group_id, + required_segs.rel_type, + count(*) as num_satisfied + from rc_all_constraints required_segs, + rel_segment_party_map map + where required_segs.rel_side = 'one' + and required_segs.required_rel_segment = map.segment_id + and required_segs.group_id = map.party_id + group by required_segs.group_id, + required_segs.rel_type) side_one_constraints, + (select group_id, rel_type, count(*) as total + from rc_all_constraints + where rel_side = 'one' + group by group_id, rel_type) total_side_one_constraints + where side_one_constraints.group_id = total_side_one_constraints.group_id + and side_one_constraints.rel_type = total_side_one_constraints.rel_type + and side_one_constraints.num_satisfied = total_side_one_constraints.total +UNION ALL +select group_rel_type_combos.group_id, + group_rel_type_combos.rel_type +from (select * from rc_all_constraints where rel_side='one') rc_all_constraints, + (select groups.group_id, comp_or_member_rel_types.rel_type + from groups, + (select object_type as rel_type from acs_object_types + start with object_type = 'membership_rel' + or object_type = 'composition_rel' + connect by supertype = prior object_type) comp_or_member_rel_types + ) group_rel_type_combos +where rc_all_constraints.group_id(+) = group_rel_type_combos.group_id + and rc_all_constraints.rel_type(+) = group_rel_type_combos.rel_type + and rc_all_constraints.group_id is null; + + +-- View: rc_violations_by_removing_rel +-- +-- Question: Given relation :rel_id +-- +-- If we were to remove the relation specified by rel_id, +-- what constraints would be violated and by what parties? +-- +-- Answer: select r.rel_id, r.constraint_id, r.constraint_name +-- acs_object_type.pretty_name(r.rel_type) as rel_type_pretty_name, +-- acs_object.name(r.object_id_one) as object_id_one_name, +-- acs_object.name(r.object_id_two) as object_id_two_name +-- from rc_violations_by_removing_rel r +-- where r.rel_id = :rel_id +-- + +create or replace view rc_violations_by_removing_rel as +select r.rel_type as viol_rel_type, r.rel_id as viol_rel_id, + r.object_id_one as viol_object_id_one, r.object_id_two as viol_object_id_two, + s.rel_id, + cons.constraint_id, cons.constraint_name, + map.segment_id, map.party_id, map.group_id, map.container_id, map.ancestor_rel_type + from acs_rels r, rel_segment_party_map map, rel_constraints cons, + (select s.segment_id, r.rel_id, r.object_id_two + from rel_segments s, acs_rels r + where r.object_id_one = s.group_id + and r.rel_type = s.rel_type) s + where map.party_id = r.object_id_two + and map.rel_id = r.rel_id + and r.object_id_two = s.object_id_two + and cons.rel_segment = map.segment_id + and cons.required_rel_segment = s.segment_id; + + +-- View: rc_segment_required_seg_map +-- +-- Question: Given a relational segment :rel_segment . . . +-- +-- What are all the segments in the system that a party has to +-- be in if the party were to be on side :rel_side of a relation +-- in segement :rel_segment? +-- +-- We want not only the direct required_segments (which we could +-- get from the rel_constraints table directly), but also the +-- indirect ones (i.e., the segments that are required by the +-- required segments, and so on). +-- +-- Answer: select required_rel_segment +-- from rc_segment_required_seg_map +-- where rel_segment = :rel_segment +-- and rel_side = :rel_side +-- +-- +create or replace view rc_segment_required_seg_map as +select rc.rel_segment, rc.rel_side, rc_required.required_rel_segment +from rel_constraints rc, rel_constraints rc_required +where rc.rel_segment in ( + select rel_segment + from rel_constraints + start with rel_segment = rc_required.rel_segment + connect by required_rel_segment = prior rel_segment + and prior rel_side = 'two' + ); + +-- View: rc_segment_dependency_levels +-- +-- This view is designed to determine what order of segments is safe +-- to use when adding a party to multiple segments. +-- +-- Question: Given a table or view called segments_I_want_to_be_in, +-- which segments can I add a party to first, without violating +-- any relational constraints? +-- +-- Answer: select segment_id +-- from segments_I_want_to_be_in s, +-- rc_segment_dependency_levels dl +-- where s.segment_id = dl.segment_id(+) +-- order by nvl(dl.dependency_level, 0) +-- +-- Note: dependency_level = 1 is the minimum dependency level. +-- dependency_level = N means that you cannot add a party to the +-- segment until you first add the party to some +-- segment of dependency_level N-1 (this view doesn't +-- tell you which segment -- you can get that info +-- from rel_constraints table or other views. +-- +-- Another Note: not all segemnts in rel_segemnts are returned by this view. +-- This view only returns segments S that have at least one rel_constraints row +-- where rel_segment = S. Segments that have no constraints defined on them +-- can be said to have dependency_level=0, hence the outer join and nvl in the +-- example query above (see "Answer:"). I could have embeded that logic into +-- this view, but that would unnecessarily degrade performance. +-- +create or replace view rc_segment_dependency_levels as + select rel_segment as segment_id, + max(tree_level) as dependency_level + from (select rel_segment, level as tree_level + from rel_constraints + connect by required_rel_segment = prior rel_segment + and prior rel_side = 'two') + group by rel_segment +; + + Index: openacs-4/packages/acs-mail/sql/oracle/upgrade/upgrade-4.6.2-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-mail/sql/oracle/upgrade/upgrade-4.6.2-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-mail/sql/oracle/upgrade/upgrade-4.6.2-5.0d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,537 @@ +-- +-- packages/acs-mail/sql/acs-mail-queue-create.sql +-- +-- @author John Prevost +-- @creation-date 2001-01-08 +-- @cvs-id $Id: upgrade-4.6.2-5.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +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 + + +-- +-- packages/acs-mail/sql/acs-mail-create-packages.sql +-- +-- @author John Prevost +-- @creation-date 2001-01-08 +-- @cvs-id $Id: upgrade-4.6.2-5.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +-- Package Interfaces -------------------------------------------------- + +create or replace package acs_mail_gc_object +as + + function new ( + gc_object_id in acs_objects.object_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'acs_mail_gc_object', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + gc_object_id in acs_mail_gc_objects.gc_object_id%TYPE + ); + +end; +/ +show errors + +create or replace package acs_mail_body +as + + function new ( + body_id in acs_mail_bodies.body_id%TYPE default null, + body_reply_to in acs_mail_bodies.body_reply_to%TYPE default null, + body_from in acs_mail_bodies.body_from%TYPE default null, + body_date in acs_mail_bodies.body_date%TYPE default null, + header_message_id in acs_mail_bodies.header_message_id%TYPE default null, + header_reply_to in acs_mail_bodies.header_reply_to%TYPE default null, + header_subject in acs_mail_bodies.header_subject%TYPE default null, + header_from in acs_mail_bodies.header_from%TYPE default null, + header_to in acs_mail_bodies.header_to%TYPE default null, + content_item_id in acs_mail_bodies.content_item_id%TYPE default null, + + object_type in acs_objects.object_type%TYPE default 'acs_mail_body', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + body_id in acs_mail_bodies.body_id%TYPE + ); + + function body_p ( + object_id in acs_objects.object_id%TYPE + ) return char; + + -- duplicate a mail body to make changes safely + + function clone ( + old_body_id in acs_mail_bodies.body_id%TYPE, + body_id in acs_mail_bodies.body_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'acs_mail_body', + 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_user%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + -- set the main content object of a mail body + + procedure set_content_object ( + body_id in acs_mail_bodies.body_id%TYPE, + content_item_id in acs_mail_bodies.content_item_id%TYPE + ); + +end; +/ +show errors + +create or replace package acs_mail_multipart +as + + function new ( + multipart_id in acs_mail_multiparts.multipart_id%TYPE default null, + multipart_kind in acs_mail_multiparts.multipart_kind%TYPE, + + object_type in acs_objects.object_type%TYPE + default 'acs_mail_multipart', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + multipart_id in acs_mail_multiparts.multipart_id%TYPE + ); + + function multipart_p ( + object_id in acs_objects.object_id%TYPE + ) return char; + + -- Add content at a specific index. If the sequence number is null, + -- below one, or higher than the highest item already available, + -- adds at the end. Otherwise, inserts and renumbers others. + + function add_content ( + multipart_id in acs_mail_multipart_parts.multipart_id%TYPE, + content_item_id in acs_mail_multipart_parts.content_item_id%TYPE + ) return integer; + +end acs_mail_multipart; +/ +show errors + +create or replace package acs_mail_link +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 ( + mail_link_id in acs_mail_links.mail_link_id%TYPE + ); + + function link_p ( + object_id in acs_objects.object_id%TYPE + ) return char; + +end acs_mail_link; +/ +show errors + +-- Package Implementations --------------------------------------------- + +create or replace package body acs_mail_gc_object +as + function new ( + gc_object_id in acs_objects.object_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'acs_mail_gc_object', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_object_id acs_objects.object_id%TYPE; + begin + v_object_id := acs_object.new ( + object_id => gc_object_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into acs_mail_gc_objects values ( v_object_id ); + return v_object_id; + end new; + + procedure del ( + gc_object_id in acs_mail_gc_objects.gc_object_id%TYPE + ) + is + begin + delete from acs_mail_gc_objects + where gc_object_id = acs_mail_gc_object.del.gc_object_id; + acs_object.del(gc_object_id); + end del; + +end acs_mail_gc_object; +/ +show errors + +create or replace package body acs_mail_body +as + + function new ( + body_id in acs_mail_bodies.body_id%TYPE default null, + body_reply_to in acs_mail_bodies.body_reply_to%TYPE default null, + body_from in acs_mail_bodies.body_from%TYPE default null, + body_date in acs_mail_bodies.body_date%TYPE default null, + header_message_id in acs_mail_bodies.header_message_id%TYPE default null, + header_reply_to in acs_mail_bodies.header_reply_to%TYPE default null, + header_subject in acs_mail_bodies.header_subject%TYPE default null, + header_from in acs_mail_bodies.header_from%TYPE default null, + header_to in acs_mail_bodies.header_to%TYPE default null, + content_item_id in acs_mail_bodies.content_item_id%TYPE default null, + + object_type in acs_objects.object_type%TYPE default 'acs_mail_body', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_object_id acs_objects.object_id%TYPE; + v_header_message_id acs_mail_bodies.header_message_id%TYPE; + begin + v_object_id := acs_mail_gc_object.new ( + gc_object_id => body_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + v_header_message_id := + nvl(header_message_id, + sysdate || '.' || v_object_id || '@' || + utl_inaddr.get_host_name || '.sddd'); + insert into acs_mail_bodies + (body_id, body_reply_to, body_from, body_date, header_message_id, + header_reply_to, header_subject, header_from, header_to, + content_item_id) + values + (v_object_id, body_reply_to, body_from, body_date, + v_header_message_id, header_reply_to, header_subject, header_from, + header_to, content_item_id); + return v_object_id; + end new; + + procedure del ( + body_id in acs_mail_bodies.body_id%TYPE + ) + is + begin + acs_mail_gc_object.del(body_id); + end del; + + function body_p ( + object_id in acs_objects.object_id%TYPE + ) return char + is + v_check_body_id integer; + begin + select decode(count(body_id),0,0,1) into v_check_body_id + from acs_mail_bodies + where body_id = object_id; + if v_check_body_id <> 0 then + return 't'; + else + return 'f'; + end if; + end body_p; + + function clone ( + old_body_id in acs_mail_bodies.body_id%TYPE, + body_id in acs_mail_bodies.body_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'acs_mail_body', + 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_user%TYPE default null, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_object_id acs_objects.object_id%TYPE; + body_reply_to acs_mail_bodies.body_reply_to%TYPE; + body_from acs_mail_bodies.body_from%TYPE; + body_date acs_mail_bodies.body_date%TYPE; + header_message_id acs_mail_bodies.header_message_id%TYPE; + header_reply_to acs_mail_bodies.header_reply_to%TYPE; + header_subject acs_mail_bodies.header_subject%TYPE; + header_from acs_mail_bodies.header_from%TYPE; + header_to acs_mail_bodies.header_to%TYPE; + content_item_id acs_mail_bodies.content_item_id%TYPE; + begin + select body_reply_to, body_from, body_date, + header_reply_to, header_subject, header_from, header_to, + content_item_id + into body_reply_to, body_from, body_date, + header_reply_to, header_subject, header_from, header_to, + content_item_id + from acs_mail_bodies + where body_id = old_body_id; + v_object_id := acs_mail_body.new ( + body_id => body_id, + body_reply_to => body_reply_to, + body_from => body_from, + body_date => body_date, + header_reply_to => header_reply_to, + header_subject => header_subject, + header_from => header_from, + header_to => header_to, + content_item_id => content_item_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + return v_object_id; + end clone; + + procedure set_content_object ( + body_id in acs_mail_bodies.body_id%TYPE, + content_item_id in acs_mail_bodies.content_item_id%TYPE + ) + is + begin + update acs_mail_bodies + set content_item_id = set_content_object.content_item_id + where body_id = set_content_object.body_id; + end set_content_object; + +end acs_mail_body; +/ +show errors + +create or replace package body acs_mail_multipart +as + + function new ( + multipart_id in acs_mail_multiparts.multipart_id%TYPE default null, + multipart_kind in acs_mail_multiparts.multipart_kind%TYPE, + + object_type in acs_objects.object_type%TYPE + default 'acs_mail_multipart', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_object_id acs_objects.object_id%TYPE; + begin + v_object_id := acs_mail_gc_object.new ( + gc_object_id => multipart_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into acs_mail_multiparts (multipart_id, multipart_kind) + values (v_object_id, multipart_kind); + return v_object_id; + end new; + + procedure del ( + multipart_id in acs_mail_multiparts.multipart_id%TYPE + ) + is + begin + acs_mail_gc_object.del(multipart_id); + end del; + + function multipart_p ( + object_id in acs_objects.object_id%TYPE + ) return char + is + v_check_multipart_id integer; + begin + select decode(count(multipart_id),0,0,1) into v_check_multipart_id + from acs_mail_multiparts + where multipart_id = object_id; + if v_check_multipart_id <> 0 then + return 't'; + else + return 'f'; + end if; + end multipart_p; + + -- Add content at a specific index. If the sequence number is null, + -- below one, or higher than the highest item already available, + -- adds at the end. Otherwise, inserts and renumbers others. + + function add_content ( + multipart_id in acs_mail_multipart_parts.multipart_id%TYPE, + content_item_id in acs_mail_multipart_parts.content_item_id%TYPE + ) return integer + is + v_multipart_id acs_mail_multiparts.multipart_id%TYPE; + v_max_num integer; + begin + -- get a row lock on the multipart item + select multipart_id into v_multipart_id from acs_mail_multiparts + where multipart_id = add_content.multipart_id for update; + select nvl(max(sequence_number),0) into v_max_num + from acs_mail_multipart_parts + where multipart_id = add_content.multipart_id; + insert into acs_mail_multipart_parts + (multipart_id, sequence_number, content_item_id) + values + (multipart_id, v_max_num + 1, content_item_id); + + return v_max_num + 1; + end add_content; + +end acs_mail_multipart; +/ +show errors + +create or replace package body acs_mail_link +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_object.new ( + object_id => mail_link_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_links ( mail_link_id, body_id ) + values ( v_object_id, body_id ); + return v_object_id; + end; + + procedure del ( + mail_link_id in acs_mail_links.mail_link_id%TYPE + ) + is + begin + delete from acs_mail_links + where mail_link_id = acs_mail_link.del.mail_link_id; + acs_object.del(mail_link_id); + end; + + function link_p ( + object_id in acs_objects.object_id%TYPE + ) return char + is + v_check_link_id integer; + begin + select decode(count(mail_link_id),0,0,1) into v_check_link_id + from acs_mail_links + where mail_link_id = object_id; + if v_check_link_id <> 0 then + return 't'; + else + return 'f'; + end if; + end link_p; + +end acs_mail_link; +/ +show errors Index: openacs-4/packages/acs-messaging/sql/oracle/upgrade/upgrade-4.5-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-messaging/sql/oracle/upgrade/upgrade-4.5-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-messaging/sql/oracle/upgrade/upgrade-4.5-5.0d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,643 @@ +-- +-- packages/acs-messaging/sql/acs-messaging-packages.sql +-- +-- @author John Prevost +-- @author Phong Nguyen +-- @creation-date 2000-08-27 +-- @cvs-id $Id: upgrade-4.5-5.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +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, + description in cr_revisions.description%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, + parent_id in cr_items.parent_id%TYPE default 0, + 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', + is_live in char default 't' + ) return acs_objects.object_id%TYPE; + + function edit ( + message_id in acs_messages.message_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%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, + 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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE; + + procedure del ( + 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 + ); + + procedure send ( + message_id in acs_messages.message_id%TYPE, + to_address in varchar2, + grouping_id in integer default null, + wait_until in date default sysdate + ); + + function first_ancestor ( + message_id in acs_messages.message_id%TYPE + ) return acs_messages.message_id%TYPE; + + -- ACHTUNG! WARNING! ACHTUNG! WARNING! ACHTUNG! WARNING! -- + + -- Developers: Please don't depend on the following functionality + -- to remain in the same place. Chances are very good these + -- functions will migrate to another PL/SQL package or be replaced + -- by direct calls to CR code in the near future. + + function new_file ( + message_id in acs_messages.message_id%TYPE, + file_id in cr_items.item_id%TYPE default null, + file_name in cr_items.name%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%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, + is_live in char default 't', + storage_type in cr_items.storage_type%TYPE default 'file' + ) return acs_objects.object_id%TYPE; + + function edit_file ( + file_id in cr_items.item_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE; + + procedure delete_file ( + file_id in cr_items.item_id%TYPE + ); + + function new_image ( + message_id in acs_messages.message_id%TYPE, + image_id in cr_items.item_id%TYPE default null, + file_name in cr_items.name%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%TYPE default null, + width in images.width%TYPE default null, + height in images.height%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, + is_live in char default 't', + storage_type in cr_items.storage_type%TYPE default 'file' + ) return acs_objects.object_id%TYPE; + + function edit_image ( + image_id in cr_items.item_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%TYPE default null, + width in images.width%TYPE default null, + height in images.height%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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE; + + procedure delete_image ( + image_id in cr_items.item_id%TYPE + ); + + function new_extlink ( + name in cr_items.name%TYPE default null, + extlink_id in cr_extlinks.extlink_id%TYPE default null, + url in cr_extlinks.url%TYPE, + label in cr_extlinks.label%TYPE default null, + description in cr_extlinks.description%TYPE default null, + parent_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 + ) return cr_extlinks.extlink_id%TYPE; + + function edit_extlink ( + extlink_id in cr_extlinks.extlink_id%TYPE, + url in cr_extlinks.url%TYPE, + label in cr_extlinks.label%TYPE default null, + description in cr_extlinks.description%TYPE default null + ) return cr_extlinks.extlink_id%TYPE; + + procedure delete_extlink ( + extlink_id in cr_extlinks.extlink_id%TYPE + ); + + function name ( + message_id in acs_objects.object_id%TYPE + ) return varchar2; + +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, + description in cr_revisions.description%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, + parent_id in cr_items.parent_id%TYPE default 0, + 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', + is_live in char default 't' + ) return acs_objects.object_id%TYPE + is + v_message_id acs_messages.message_id%TYPE; + v_rfc822_id acs_messages.rfc822_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 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; + + -- this needs to be fixed up, but Oracle doesn't give us a way + -- to get the FQDN + 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_message_id := content_item.new ( + name => v_rfc822_id, + parent_id => parent_id, + content_type => 'acs_message_revision', + item_id => message_id, + context_id => context_id, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_subtype => object_type + ); + + 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); + + -- create an initial revision for the new message + v_revision_id := acs_message.edit ( + message_id => v_message_id, + title => title, + description => description, + mime_type => mime_type, + text => text, + data => data, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + is_live => is_live + ); + + return v_message_id; + end new; + + function edit ( + message_id in acs_messages.message_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%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, + 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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE + is + v_revision_id cr_revisions.revision_id%TYPE; + begin + + -- create a new revision using whichever call is appropriate + if edit.data is not null then + v_revision_id := content_revision.new ( + item_id => message_id, + title => title, + description => description, + data => data, + mime_type => mime_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + elsif title is not null or text is not null then + v_revision_id := content_revision.new ( + item_id => message_id, + title => title, + description => description, + text => text, + mime_type => mime_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + end if; + + -- test for auto approval of revision + if edit.is_live = 't' then + content_item.set_live_revision(v_revision_id); + end if; + + return v_revision_id; + + end edit; + + procedure del ( + message_id in acs_messages.message_id%TYPE + ) + is + begin + delete from acs_messages + where message_id = acs_message.del.message_id; + content_item.del(message_id); + end del; + + function message_p ( + message_id in acs_messages.message_id%TYPE + ) return char + is + v_check_message_id integer; + begin + select decode(count(message_id),0,0,1) into v_check_message_id + from acs_messages + where message_id = message_p.message_id; + if v_check_message_id <> 0 then + return 't'; + else + return 'f'; + end if; + end message_p; + + procedure send ( + message_id in acs_messages.message_id%TYPE, + to_address in varchar2, + 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, to_address, grouping_id, wait_until) + values + (message_id, to_address, grouping_id, v_wait_until); + end send; + + 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, to_address, grouping_id, wait_until) + select send.message_id, p.email, send.grouping_id, v_wait_until + from parties p + where p.party_id = send.recipient_id; + end send; + + function first_ancestor ( + message_id in acs_messages.message_id%TYPE + ) return acs_messages.message_id%TYPE + is + v_message_id acs_messages.message_id%TYPE; + begin + select message_id into v_message_id + from (select message_id, reply_to + from acs_messages + connect by message_id = prior reply_to + start with message_id = first_ancestor.message_id) ancestors + where reply_to is null; + return v_message_id; + end first_ancestor; + + -- ACHTUNG! WARNING! ACHTUNG! WARNING! ACHTUNG! WARNING! -- + + -- Developers: Please don't depend on the following functionality + -- to remain in the same place. Chances are very good these + -- functions will migrate to another PL/SQL package or be replaced + -- by direct calls to CR code in the near future. + + function new_file ( + message_id in acs_messages.message_id%TYPE, + file_id in cr_items.item_id%TYPE default null, + file_name in cr_items.name%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%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, + is_live in char default 't', + storage_type in cr_items.storage_type%TYPE default 'file' + ) return acs_objects.object_id%TYPE + is + v_file_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + begin + + v_file_id := content_item.new ( + name => file_name, + parent_id => message_id, + item_id => file_id, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + storage_type => storage_type + ); + + -- create an initial revision for the new attachment + v_revision_id := edit_file ( + file_id => v_file_id, + title => title, + description => description, + mime_type => mime_type, + content => content, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + is_live => is_live + ); + + return v_file_id; + end new_file; + + function edit_file ( + file_id in cr_items.item_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE + is + v_revision_id cr_revisions.revision_id%TYPE; + begin + + v_revision_id := content_revision.new ( + title => title, + mime_type => mime_type, + data => content, + item_id => file_id, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + -- test for auto approval of revision + if is_live = 't' then + content_item.set_live_revision(v_revision_id); + end if; + + return v_revision_id; + end edit_file; + + procedure delete_file ( + file_id in cr_items.item_id%TYPE + ) + is + begin + content_item.del(delete_file.file_id); + end delete_file; + + function new_image ( + message_id in acs_messages.message_id%TYPE, + image_id in cr_items.item_id%TYPE default null, + file_name in cr_items.name%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%TYPE default null, + width in images.width%TYPE default null, + height in images.height%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, + is_live in char default 't', + storage_type in cr_items.storage_type%TYPE default 'file' + ) return acs_objects.object_id%TYPE + is + v_image_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + begin + + v_image_id := content_item.new ( + name => file_name, + parent_id => message_id, + item_id => image_id, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + storage_type => storage_type + ); + + -- create an initial revision for the new attachment + v_revision_id := edit_image ( + image_id => v_image_id, + title => title, + description => description, + mime_type => mime_type, + content => content, + width => width, + height => height, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + is_live => is_live + ); + + return v_image_id; + end new_image; + + function edit_image ( + image_id in cr_items.item_id%TYPE, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + content in cr_revisions.content%TYPE default null, + width in images.width%TYPE default null, + height in images.height%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, + is_live in char default 't' + ) return acs_objects.object_id%TYPE + is + v_revision_id cr_revisions.revision_id%TYPE; + begin + + v_revision_id := content_revision.new ( + title => edit_image.title, + mime_type => edit_image.mime_type, + data => edit_image.content, + item_id => edit_image.image_id, + creation_date => edit_image.creation_date, + creation_user => edit_image.creation_user, + creation_ip => edit_image.creation_ip + ); + + -- insert new width and height values + -- XXX fix after image.new exists + insert into images + (image_id, width, height) + values + (v_revision_id, width, height); + + -- test for auto approval of revision + if edit_image.is_live = 't' then + content_item.set_live_revision(v_revision_id); + end if; + + return v_revision_id; + end edit_image; + + procedure delete_image ( + image_id in cr_items.item_id%TYPE + ) + is + begin + -- XXX fix after image.delete exists + delete from images + where image_id = delete_image.image_id; + content_item.del(image_id); + end delete_image; + + -- XXX should just call content_extlink.new + function new_extlink ( + name in cr_items.name%TYPE default null, + extlink_id in cr_extlinks.extlink_id%TYPE default null, + url in cr_extlinks.url%TYPE, + label in cr_extlinks.label%TYPE default null, + description in cr_extlinks.description%TYPE default null, + parent_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 + ) return cr_extlinks.extlink_id%TYPE + is + v_extlink_id cr_extlinks.extlink_id%TYPE; + begin + v_extlink_id := content_extlink.new ( + name => new_extlink.name, + url => new_extlink.url, + label => new_extlink.label, + description => new_extlink.description, + parent_id => new_extlink.parent_id, + extlink_id => new_extlink.extlink_id, + creation_date => new_extlink.creation_date, + creation_user => new_extlink.creation_user, + creation_ip => new_extlink.creation_ip + ); + end new_extlink; + + -- XXX should just edit extlink + function edit_extlink ( + extlink_id in cr_extlinks.extlink_id%TYPE, + url in cr_extlinks.url%TYPE, + label in cr_extlinks.label%TYPE default null, + description in cr_extlinks.description%TYPE default null + ) return cr_extlinks.extlink_id%TYPE + is + v_is_extlink char; + begin + v_is_extlink := content_extlink.is_extlink(edit_extlink.extlink_id); + if v_is_extlink = 't' then + update cr_extlinks + set url = edit_extlink.url, + label = edit_extlink.label, + description = edit_extlink.description + where extlink_id = edit_extlink.extlink_id; + end if; + return v_is_extlink; + end edit_extlink; + + procedure delete_extlink ( + extlink_id in cr_extlinks.extlink_id%TYPE + ) is + begin + content_extlink.del(extlink_id => delete_extlink.extlink_id); + end delete_extlink; + + function name ( + message_id in acs_objects.object_id%TYPE + ) return varchar2 + is + v_message_name acs_messages_all.title%TYPE; + begin + select title into v_message_name + from acs_messages_all + where message_id = name.message_id; + return v_message_name; + end name; + +end acs_message; +/ +show errors Index: openacs-4/packages/acs-service-contract/sql/oracle/upgrade/upgrade-4.7d3-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-service-contract/sql/oracle/upgrade/upgrade-4.7d3-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-service-contract/sql/oracle/upgrade/upgrade-4.7d3-5.0d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,924 @@ +-- $Id: upgrade-4.7d3-5.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + + +create or replace package acs_sc_msg_type +as + + function new ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + msg_type_spec in varchar2 + ) return acs_sc_msg_types.msg_type_id%TYPE; + + procedure del ( + msg_type_id in acs_sc_msg_types.msg_type_id%TYPE default null, + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE default null + ); + + function get_id ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE + ) return acs_sc_msg_types.msg_type_id%TYPE; + + + function get_name ( + msg_type_id in acs_sc_msg_types.msg_type_id%TYPE + ) return acs_sc_msg_types.msg_type_name%TYPE; + + -- ask nd about name + function parse_spec ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + msg_type_spec in varchar2 + ) return integer; + + function new_element ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + element_name in acs_sc_msg_type_elements.element_name%TYPE, + element_msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + element_msg_type_isset_p in acs_sc_msg_type_elements.element_msg_type_isset_p%TYPE, + element_pos in acs_sc_msg_type_elements.element_pos%TYPE + ) return acs_sc_msg_types.msg_type_id%TYPE; + +end acs_sc_msg_type; +/ +show errors + + +create or replace package body acs_sc_msg_type +as + + function new ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + msg_type_spec in varchar2 + ) return acs_sc_msg_types.msg_type_id%TYPE + is + v_msg_type_id integer; + v_spec_parse_level integer; + begin + v_msg_type_id := acs_object.new( + object_type => 'acs_sc_msg_type' + ); + + insert into acs_sc_msg_types ( + msg_type_id, + msg_type_name + ) values ( + v_msg_type_id, + msg_type_name + ); + + v_spec_parse_level := acs_sc_msg_type.parse_spec( + msg_type_name, + msg_type_spec); + + return v_msg_type_id; + + end new; + + procedure del ( + msg_type_id in acs_sc_msg_types.msg_type_id%TYPE default null, + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE default null + ) + is + v_msg_type_id acs_sc_msg_types.msg_type_id%TYPE; + begin + + if msg_type_name is not NULL + then + v_msg_type_id := acs_sc_msg_type.get_id(msg_type_name); + + elsif msg_type_id is not NULL + then + v_msg_type_id := msg_type_id; + + else + raise_application_error(-20000, 'no args supplied to sc_msg_type.delete'); + + end if; + + delete from acs_sc_msg_types + where msg_type_id = v_msg_type_id; + + end del; + + function get_id ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE + ) return acs_sc_msg_types.msg_type_id%TYPE + + is + v_msg_type_id acs_sc_msg_types.msg_type_id%TYPE; + begin + + select msg_type_id into v_msg_type_id + from acs_sc_msg_types + where msg_type_name = get_id.msg_type_name; + + return v_msg_type_id; + + end get_id; + + + function get_name ( + msg_type_id in acs_sc_msg_types.msg_type_id%TYPE + ) return acs_sc_msg_types.msg_type_name%TYPE + is + v_msg_type_name acs_sc_msg_types.msg_type_name%TYPE; + begin + + select msg_type_name into v_msg_type_name + from acs_sc_msg_types + where msg_type_id = get_name.msg_type_id; + + return v_msg_type_name; + end get_name; + + + + -- string processing in pl/sql is so much fun + -- i'm sure there is a better way to go about this + function parse_spec ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + msg_type_spec in varchar2 + ) return integer + is + v_element_pos integer; + v_str_s_idx integer; -- spec str pointers + v_str_e_idx integer; + v_elem_idx integer; -- element str pointer + v_str_len integer; + v_element varchar(200); + v_element_type varchar(200); + v_element_name varchar(200); + v_element_msg_type_name varchar(200); + v_element_msg_type_isset_p char(1); + v_junk_msg_type_id integer; + begin + + -- oracle treats empty strings as nulls + if msg_type_spec is null + then + return 0; + end if; + + + v_element_pos := 1; + v_str_e_idx := 1; + + while TRUE + loop + -- string start check + if v_element_pos = 1 + then + v_str_s_idx := 1; + else + v_str_s_idx := instr(msg_type_spec, ',', v_str_e_idx); + + if v_str_s_idx > 0 then + v_str_s_idx := v_str_s_idx + 1; + end if; + + end if; + + v_str_e_idx := instr(msg_type_spec, ',', v_str_s_idx+1)-1; + + -- end of string check + if v_str_s_idx > 0 and v_str_e_idx <= 0 + then + v_str_e_idx := length(msg_type_spec); + end if; + + -- dbms_output.put_line(v_str_s_idx || ' '|| v_str_e_idx || ' ' || v_element_pos); + -- dbms_output.new_line(); + + if v_str_s_idx > 0 + then + + v_element := substr(msg_type_spec, + v_str_s_idx, + v_str_e_idx+1 - v_str_s_idx); + + v_elem_idx := instr(v_element, ':'); + + if v_elem_idx > 0 + then + v_element_name := trim( substr(v_element, 1, v_elem_idx-1)); + v_element_type := trim( substr(v_element, v_elem_idx+1)); + + if (instr(v_element_type, '[',1,1) = length(v_element_type)-1) and + (instr(v_element_type, ']',1,1) = length(v_element_type)) + then + v_element_msg_type_isset_p := 't'; + v_element_msg_type_name := trim(substr( + v_element_type, + 1, + length(v_element_type)-2)); + + if v_element_msg_type_name = '' + then + raise_application_error (-20001, + 'Wrong Format: Message Type Specification'); + end if; + else + v_element_msg_type_isset_p := 'f'; + v_element_msg_type_name := v_element_type; + + end if; + + v_junk_msg_type_id := acs_sc_msg_type.new_element ( + msg_type_name =>parse_spec.msg_type_name, + element_name => v_element_name, + element_msg_type_name => v_element_msg_type_name, + element_msg_type_isset_p => v_element_msg_type_isset_p, + element_pos => v_element_pos + ); + + else + raise_application_error(-20001,'Wrong Format: Message Type Specification'); + end if; + else + -- yippee we're done + exit; + end if; + + v_element_pos := v_element_pos + 1; + + end loop; + + return v_element_pos - 1; + end parse_spec; + + function new_element ( + msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + element_name in acs_sc_msg_type_elements.element_name%TYPE, + element_msg_type_name in acs_sc_msg_types.msg_type_name%TYPE, + element_msg_type_isset_p in acs_sc_msg_type_elements.element_msg_type_isset_p%TYPE, + element_pos in acs_sc_msg_type_elements.element_pos%TYPE + ) return acs_sc_msg_types.msg_type_id%TYPE + is + v_msg_type_id integer; + v_element_msg_type_id integer; + begin + + v_msg_type_id := acs_sc_msg_type.get_id(msg_type_name); + + if v_msg_type_id is null + then + raise_application_error (-20001, 'Unknown Message Type: ' || msg_type_name); + end if; + + v_element_msg_type_id := acs_sc_msg_type.get_id(element_msg_type_name); + + if v_element_msg_type_id is null + then + raise_application_error (-20001, 'Unknown Message Type: ' || element_msg_type_name); + end if; + + insert into acs_sc_msg_type_elements ( + msg_type_id, + element_name, + element_msg_type_id, + element_msg_type_isset_p, + element_pos + ) values ( + v_msg_type_id, + element_name, + v_element_msg_type_id, + element_msg_type_isset_p, + element_pos + ); + + return v_msg_type_id; + + end new_element; + +end acs_sc_msg_type; +/ +show errors + + + +create or replace package acs_sc_contract +as + + function new ( + contract_name in acs_sc_contracts.contract_name%TYPE, + contract_desc in acs_sc_contracts.contract_desc%TYPE + ) return acs_sc_contracts.contract_id%TYPE; + + function get_id ( + contract_name in acs_sc_contracts.contract_name%TYPE + ) return acs_sc_contracts.contract_id%TYPE; + + function get_name ( + contract_id in acs_sc_contracts.contract_id%TYPE + ) return acs_sc_contracts.contract_name%TYPE; + + procedure del ( + contract_name in acs_sc_contracts.contract_name%TYPE default null, + contract_id in acs_sc_contracts.contract_id%TYPE default null + ); +end acs_sc_contract; +/ +show errors + +create or replace package acs_sc_operation +as + + function new ( + contract_name in acs_sc_contracts.contract_name%TYPE, + operation_name in acs_sc_operations.operation_name%TYPE, + operation_desc in acs_sc_operations.operation_desc%TYPE, + operation_iscachable_p in acs_sc_operations.operation_iscachable_p%TYPE, + operation_nargs in acs_sc_operations.operation_nargs%TYPE, + operation_inputtype in acs_sc_msg_types.msg_type_name%TYPE, + operation_outputtype in acs_sc_msg_types.msg_type_name%TYPE + ) return acs_sc_operations.operation_id%TYPE; + + function get_id ( + contract_name acs_sc_contracts.contract_name%TYPE, + operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_operations.operation_id%TYPE; + + + procedure del ( + operation_id acs_sc_operations.operation_id%TYPE default null, + operation_name acs_sc_operations.operation_name%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null + ); + +end acs_sc_operation; +/ +show errors + +create or replace package acs_sc_impl +as + + function new ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_pretty_name acs_sc_impls.impl_pretty_name%TYPE default null, + impl_owner_name acs_sc_impls.impl_owner_name%TYPE + ) return acs_sc_impls.impl_id%TYPE; + + function get_id ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ) return acs_sc_impls.impl_id%TYPE; + + function get_name ( + impl_id acs_sc_impls.impl_id%TYPE + ) return acs_sc_impls.impl_name%TYPE; + + procedure del ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ); + + /* Next 2 functions are deprecated but left here for backwards compatability */ + + function new_alias ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE, + impl_alias acs_sc_impl_aliases.impl_alias%TYPE, + impl_pl acs_sc_impl_aliases.impl_pl%TYPE + ) return acs_sc_impl_aliases.impl_id%TYPE; + + -- fix by Ben from delete_aliases to delete_alias + function delete_alias ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_impls.impl_id%TYPE; + +end acs_sc_impl; +/ +show error + +create or replace package acs_sc_impl_alias +as + function new ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE, + impl_alias acs_sc_impl_aliases.impl_alias%TYPE, + impl_pl acs_sc_impl_aliases.impl_pl%TYPE + ) return acs_sc_impl_aliases.impl_id%TYPE; + + function del ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_impls.impl_id%TYPE; + +end acs_sc_impl_alias; +/ +show error + +create or replace package acs_sc_binding +as + procedure new ( + contract_id acs_sc_operations.contract_id%TYPE default null, + impl_id acs_sc_bindings.impl_id%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null, + impl_name acs_sc_impls.impl_name%TYPE default null + ); + + procedure del ( + contract_id acs_sc_contracts.contract_id%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null, + impl_id acs_sc_impls.impl_id%TYPE default null, + impl_name acs_sc_impls.impl_name%TYPE default null + ); + + function exists_p ( + contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ) return integer; + +end acs_sc_binding; +/ +show errors + +create or replace package body acs_sc_contract +as + function new ( + contract_name in acs_sc_contracts.contract_name%TYPE, + contract_desc in acs_sc_contracts.contract_desc%TYPE + ) return acs_sc_contracts.contract_id%TYPE + is + v_contract_id acs_sc_contracts.contract_id%TYPE; + begin + v_contract_id := acs_object.new( object_type=>'acs_sc_contract'); + + insert into acs_sc_contracts ( + contract_id, + contract_name, + contract_desc + ) values ( + v_contract_id, + contract_name, + contract_desc + ); + + return v_contract_id; + + end new; + + function get_id ( + contract_name in acs_sc_contracts.contract_name%TYPE + ) return acs_sc_contracts.contract_id%TYPE + is + v_contract_id acs_sc_contracts.contract_id%TYPE; + begin + + select contract_id into v_contract_id + from acs_sc_contracts + where contract_name = get_id.contract_name; + + return v_contract_id; + + end get_id; + + function get_name ( + contract_id in acs_sc_contracts.contract_id%TYPE + ) return acs_sc_contracts.contract_name%TYPE + is + v_contract_name acs_sc_contracts.contract_name%TYPE; + begin + + select contract_name into v_contract_name + from acs_sc_contracts + where contract_id = get_name.contract_id; + + return v_contract_name; + + end get_name; + + procedure del ( + contract_name in acs_sc_contracts.contract_name%TYPE default null, + contract_id in acs_sc_contracts.contract_id%TYPE default null + ) + is + v_contract_id acs_sc_contracts.contract_id%TYPE; + begin + + if contract_name is not NULL + then + v_contract_id := acs_sc_contract.get_id(contract_name); + + elsif contract_id is not NULL + then + v_contract_id := contract_id; + + else + raise_application_error(-20001, 'Service Contracts: no valid args supplied to delete'); + end if; + + + delete from acs_sc_contracts + where contract_id = v_contract_id; + acs_object.del(v_contract_id); + + end del; + +end acs_sc_contract; +/ +show errors + + +create or replace package body acs_sc_operation +as + + function new ( + contract_name in acs_sc_contracts.contract_name%TYPE, + operation_name in acs_sc_operations.operation_name%TYPE, + operation_desc in acs_sc_operations.operation_desc%TYPE, + operation_iscachable_p in acs_sc_operations.operation_iscachable_p%TYPE, + operation_nargs in acs_sc_operations.operation_nargs%TYPE, + operation_inputtype in acs_sc_msg_types.msg_type_name%TYPE, + operation_outputtype in acs_sc_msg_types.msg_type_name%TYPE + ) return acs_sc_operations.operation_id%TYPE + is + v_contract_id acs_sc_contracts.contract_id%TYPE; + v_operation_id acs_sc_operations.operation_id%TYPE; + v_operation_inputtype_id acs_sc_operations.operation_inputtype_id%TYPE; + v_operation_outputtype_id acs_sc_operations.operation_outputtype_id%TYPE; + begin + + v_contract_id := acs_sc_contract.get_id(contract_name); + v_operation_id := acs_object.new (object_type=>'acs_sc_operation'); + v_operation_inputtype_id := acs_sc_msg_type.get_id(operation_inputtype); + v_operation_outputtype_id := acs_sc_msg_type.get_id(operation_outputtype); + + insert into acs_sc_operations ( + contract_id, + operation_id, + contract_name, + operation_name, + operation_desc, + operation_iscachable_p, + operation_nargs, + operation_inputtype_id, + operation_outputtype_id + ) values ( + v_contract_id, + v_operation_id, + contract_name, + operation_name, + operation_desc, + operation_iscachable_p, + operation_nargs, + v_operation_inputtype_id, + v_operation_outputtype_id + ); + + return v_operation_id; + + end new; + + + function get_id ( + contract_name acs_sc_contracts.contract_name%TYPE, + operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_operations.operation_id%TYPE + as + v_operation_id acs_sc_operations.operation_id%TYPE; + begin + select operation_id into v_operation_id + from acs_sc_operations + where contract_name = get_id.contract_name + and operation_name = get_id.operation_name; + + return v_operation_id; + end get_id; + + + procedure del ( + operation_id acs_sc_operations.operation_id%TYPE default null, + operation_name acs_sc_operations.operation_name%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null + ) + is + v_operation_id acs_sc_operations.operation_id%TYPE; + begin + + if (operation_id is NULL and operation_name is not NULL and contract_name is not NULL) + then + v_operation_id := get_id(contract_name, operation_name); + + elsif operation_id is not NULL + then + v_operation_id := operation_id; + + else + raise_application_error(-20001, 'ACS Contracts: Invalid args to operation delete'); + end if; + + delete from acs_sc_operations + where operation_id = v_operation_id; + + end del; + + +end acs_sc_operation; +/ +show errors + + +create or replace package body acs_sc_impl +as + + function new ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_pretty_name acs_sc_impls.impl_pretty_name%TYPE default null, + impl_owner_name acs_sc_impls.impl_owner_name%TYPE + ) return acs_sc_impls.impl_id%TYPE + is + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + v_impl_id := acs_object.new (object_type => 'acs_sc_implementation'); + + insert into acs_sc_impls ( + impl_id, + impl_name, + impl_pretty_name, + impl_owner_name, + impl_contract_name + ) values ( + v_impl_id, + impl_name, + impl_pretty_name, + impl_owner_name, + impl_contract_name + ); + + return v_impl_id; + end new; + + function get_id ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ) return acs_sc_impls.impl_id%TYPE + as + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + + select impl_id into v_impl_id + from acs_sc_impls + where impl_name = get_id.impl_name + and impl_contract_name = get_id.impl_contract_name; + + return v_impl_id; + + end get_id; + + + function get_name ( + impl_id acs_sc_impls.impl_id%TYPE + ) return acs_sc_impls.impl_name%TYPE + as + v_impl_name acs_sc_impls.impl_name%TYPE; + begin + + select impl_name into v_impl_name + from acs_sc_impls + where impl_id = get_name.impl_id; + + return v_impl_name; + + end get_name; + + procedure del ( + impl_contract_name acs_sc_impls.impl_contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ) + as + begin + delete from acs_sc_impls + where impl_contract_name = acs_sc_impl.del.impl_contract_name + and impl_name = acs_sc_impl.del.impl_name; + end del; + + + /* next 2 functions are deprecated. */ + + function new_alias ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE, + impl_alias acs_sc_impl_aliases.impl_alias%TYPE, + impl_pl acs_sc_impl_aliases.impl_pl%TYPE + ) return acs_sc_impl_aliases.impl_id%TYPE + is + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + -- FUNCTION DEPRECATED. USE acs_sc_impl_alias.new + dbms_output.put_line('acs_sc_impl.new_alias DEPRECATED. Use acs_sc_impl_alias.new'); + + v_impl_id := acs_sc_impl_alias.new( + impl_contract_name, + impl_name, + impl_operation_name, + impl_alias, + impl_pl + ); + + return v_impl_id; + + end new_alias; + + function delete_alias ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_impls.impl_id%TYPE + is + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + -- FUNCTION DEPRECATED. USE acs_sc_impl_alias.delete + dbms_output.put_line('acs_sc_impl.delete_alias DEPRECATED. Use acs_sc_impl_alias.delete'); + + v_impl_id := acs_sc_impl_alias.del( + impl_contract_name, + impl_name, + impl_operation_name + ); + + return v_impl_id; + + end delete_alias; + +end acs_sc_impl; +/ +show errors + +create or replace package body acs_sc_impl_alias +as + + function new ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE, + impl_alias acs_sc_impl_aliases.impl_alias%TYPE, + impl_pl acs_sc_impl_aliases.impl_pl%TYPE + ) return acs_sc_impl_aliases.impl_id%TYPE + is + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + + v_impl_id := acs_sc_impl.get_id(impl_contract_name,impl_name); + + insert into acs_sc_impl_aliases ( + impl_id, + impl_name, + impl_contract_name, + impl_operation_name, + impl_alias, + impl_pl + ) values ( + v_impl_id, + impl_name, + impl_contract_name, + impl_operation_name, + impl_alias, + impl_pl + ); + + return v_impl_id; + + end new; + + function del ( + impl_contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE, + impl_operation_name acs_sc_operations.operation_name%TYPE + ) return acs_sc_impls.impl_id%TYPE + is + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + v_impl_id := acs_sc_impl.get_id(impl_contract_name,impl_name); + + delete from acs_sc_impl_aliases + where impl_contract_name = acs_sc_impl_alias.del.impl_contract_name + and impl_name = acs_sc_impl_alias.del.impl_name + and impl_operation_name = acs_sc_impl_alias.del.impl_operation_name; + + return v_impl_id; + + end del; + +end acs_sc_impl_alias; +/ +show errors + +create or replace package body acs_sc_binding +as + -- you can pick a pair of args, either ids or names to pass in. + procedure new ( + contract_id acs_sc_operations.contract_id%TYPE default null, + impl_id acs_sc_bindings.impl_id%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null, + impl_name acs_sc_impls.impl_name%TYPE default null + ) + is + v_contract_name acs_sc_contracts.contract_name%TYPE; + v_contract_id acs_sc_contracts.contract_id%TYPE; + v_impl_name acs_sc_impls.impl_name%TYPE; + v_impl_id acs_sc_impls.impl_id%TYPE; + v_count integer; + begin + + if impl_id is not null and contract_id is not null + then + + v_contract_name := acs_sc_contract.get_name(contract_id); + v_impl_name := acs_sc_impl.get_name(impl_id); + v_contract_id := contract_id; + v_impl_id := impl_id; + + elsif contract_name is not null and impl_name is not null + then + v_contract_id := acs_sc_contract.get_id(contract_name); + v_impl_id := acs_sc_impl.get_id(contract_name,impl_name); + v_impl_name := impl_name; + v_contract_name := contract_name; + + else + raise_application_error(-20001, 'Service Contracts:Invalid args to binding new'); + end if; + + + select count(*) into v_count + from acs_sc_operations + where contract_id = new.contract_id + and operation_name not in (select impl_operation_name + from acs_sc_impl_aliases + where impl_contract_name = v_contract_name + and impl_id = v_impl_id); + + if v_count > 0 + then + raise_application_error(-20001, 'Binding of ' || + v_contract_name || + ' to ' || + v_impl_name || + ' failed since certain operations are not implemented.'); + end if; + + insert into acs_sc_bindings ( + contract_id, + impl_id + ) values ( + v_contract_id, + v_impl_id + ); + + end new; + + procedure del ( + contract_id acs_sc_contracts.contract_id%TYPE default null, + contract_name acs_sc_contracts.contract_name%TYPE default null, + impl_id acs_sc_impls.impl_id%TYPE default null, + impl_name acs_sc_impls.impl_name%TYPE default null + ) + is + v_contract_id acs_sc_contracts.contract_id%TYPE; + v_impl_id acs_sc_impls.impl_id%TYPE; + begin + + if impl_id is not null and contract_id is not null + then + v_impl_id := impl_id; + v_contract_id := contract_id; + + elsif impl_name is not null and contract_name is not null + then + v_impl_id := acs_sc_impl.get_id(contract_name,impl_name); + v_contract_id := acs_sc_contract.get_id(contract_name); + else + raise_application_error(-20001, 'Service contract binding delete invalid args'); + end if; + + delete from acs_sc_bindings + where contract_id = v_contract_id + and impl_id = v_impl_id; + end del; + + function exists_p ( + contract_name acs_sc_contracts.contract_name%TYPE, + impl_name acs_sc_impls.impl_name%TYPE + ) return integer + is + v_exists_p integer; + begin + select decode(count(*),0, 0, 1) into v_exists_p + from acs_sc_bindings + where contract_id = acs_sc_contract.get_id(contract_name) + and impl_id = acs_sc_impl.get_id(contract_name,impl_name); + + return v_exists_p; + end exists_p; + +end acs_sc_binding; +/ +show errors Index: openacs-4/packages/acs-subsite/sql/oracle/upgrade/upgrade-5.0d4-5.0d5.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/acs-subsite/sql/oracle/upgrade/upgrade-5.0d4-5.0d5.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/acs-subsite/sql/oracle/upgrade/upgrade-5.0d4-5.0d5.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,297 @@ +-- +-- packages/acs-subsite/sql/application_groups-create.sql +-- +-- @author oumi@arsdigita.com +-- @creation-date 2000-02-02 +-- @cvs-id $Id: upgrade-5.0d4-5.0d5.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + + +create or replace package application_group +is + + function new ( + group_id in application_groups.group_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'application_group', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + group_name in groups.group_name%TYPE, + package_id in application_groups.package_id%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return application_groups.group_id%TYPE; + + procedure del ( + group_id in application_groups.group_id%TYPE + ); + + function group_id_from_package_id ( + package_id in application_groups.group_id%TYPE, + no_complain_p in char default 'f' + ) return char; + +end application_group; +/ +show errors + + +create or replace package body application_group +is + + function new ( + group_id in application_groups.group_id%TYPE default null, + object_type in acs_objects.object_type%TYPE + default 'application_group', + 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, + email in parties.email%TYPE default null, + url in parties.url%TYPE default null, + group_name in groups.group_name%TYPE, + package_id in application_groups.package_id%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) + return application_groups.group_id%TYPE + is + v_group_id application_groups.group_id%TYPE; + begin + v_group_id := acs_group.new ( + group_id => group_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + email => email, + url => url, + group_name => group_name, + context_id => context_id + ); + + insert into application_groups (group_id, package_id) + values (v_group_id, package_id); + + return v_group_id; + end new; + + + procedure del ( + group_id in application_groups.group_id%TYPE + ) + is + begin + + acs_group.del(group_id); + + end del; + + function group_id_from_package_id ( + package_id in application_groups.group_id%TYPE, + no_complain_p in char default 'f' + ) return char + is + v_group_id application_groups.group_id%TYPE; + begin + + select group_id + into v_group_id + from application_groups + where package_id = group_id_from_package_id.package_id; + + return v_group_id; + + exception when no_data_found then + + if no_complain_p != 't' then + raise_application_error(-20000, 'No group_id found for package ' || + package_id || ' (' || acs_object.name(package_id) || ').' ); + end if; + + return null; + + end group_id_from_package_id; + +end application_group; +/ +show errors + + +create or replace package subsite_callback as + + function new ( + --/** Registers a new callback. If the same callback exists as + -- defined in the unique constraint on the table, does + -- nothing but returns the existing callback_id. + -- + -- @author Michael Bryzek (mbryzek@arsdigita.com) + -- @creation-date 2001-02-20 + -- + --*/ + callback_id IN subsite_callbacks.callback_id%TYPE default null, + event_type IN subsite_callbacks.event_type%TYPE, + object_type IN subsite_callbacks.object_type%TYPE, + callback IN subsite_callbacks.callback%TYPE, + callback_type IN subsite_callbacks.callback_type%TYPE, + sort_order IN subsite_callbacks.sort_order%TYPE default null + ) return subsite_callbacks.callback_id%TYPE; + + procedure del ( + --/** Deletes the specified callback + -- + -- @author Michael Bryzek (mbryzek@arsdigita.com) + -- @creation-date 2001-02-20 + -- + --*/ + + callback_id IN subsite_callbacks.callback_id%TYPE + ); + +end subsite_callback; +/ +show errors; + + + +create or replace package body subsite_callback as + + function new ( + callback_id IN subsite_callbacks.callback_id%TYPE default null, + event_type IN subsite_callbacks.event_type%TYPE, + object_type IN subsite_callbacks.object_type%TYPE, + callback IN subsite_callbacks.callback%TYPE, + callback_type IN subsite_callbacks.callback_type%TYPE, + sort_order IN subsite_callbacks.sort_order%TYPE default null + ) return subsite_callbacks.callback_id%TYPE + IS + v_callback_id subsite_callbacks.callback_id%TYPE; + v_sort_order subsite_callbacks.sort_order%TYPE; + BEGIN + + if new.callback_id is null then + select acs_object_id_seq.nextval into v_callback_id from dual; + else + v_callback_id := new.callback_id; + end if; + + if new.sort_order is null then + -- Make this the next event for this object_type/event_type combination + select nvl(max(sort_order),0) + 1 into v_sort_order + from subsite_callbacks + where object_type = new.object_type + and event_type = new.event_type; + else + v_sort_order := new.sort_order; + end if; + + begin + insert into subsite_callbacks + (callback_id, event_type, object_type, callback, callback_type, sort_order) + values + (v_callback_id, new.event_type, new.object_type, new.callback, new.callback_type, v_sort_order); + exception when dup_val_on_index then + select callback_id into v_callback_id + from subsite_callbacks + where event_type = new.event_type + and object_type = new.object_type + and callback_type = new.callback_type + and callback = new.callback; + end; + return v_callback_id; + + END new; + + + procedure del ( + callback_id IN subsite_callbacks.callback_id%TYPE + ) + is + begin + delete from subsite_callbacks where callback_id=subsite_callback.del.callback_id; + end del; + +end subsite_callback; +/ +show errors; + +-- +-- packages/acs-subsite/sql/user-profiles-create.sql +-- +-- @author oumi@arsdigita.com +-- @creation-date 2000-02-02 +-- @cvs-id $Id: upgrade-5.0d4-5.0d5.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +create or replace package user_profile +as + + function new ( + profile_id in user_profiles.profile_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'user_profile', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return user_profiles.profile_id%TYPE; + + procedure del ( + profile_id in user_profiles.profile_id%TYPE + ); + +end user_profile; +/ +show errors + + +create or replace package body user_profile +as + + function new ( + profile_id in user_profiles.profile_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'user_profile', + object_id_one in acs_rels.object_id_one%TYPE, + object_id_two in acs_rels.object_id_two%TYPE, + member_state in membership_rels.member_state%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return user_profiles.profile_id%TYPE + is + v_profile_id integer; + begin + + v_profile_id := membership_rel.new ( + rel_id => profile_id, + rel_type => rel_type, + object_id_one => object_id_one, + object_id_two => object_id_two, + member_state => member_state, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into user_profiles (profile_id) values (v_profile_id); + + return v_profile_id; + end new; + + procedure del ( + profile_id in user_profiles.profile_id%TYPE + ) + is + begin + + membership_rel.del(profile_id); + + end delete; + +end user_profile; +/ +show errors + + Index: openacs-4/packages/bug-tracker/sql/oracle/upgrade/upgrade-1.3d1-1.3d2.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/bug-tracker/sql/oracle/upgrade/upgrade-1.3d1-1.3d2.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/bug-tracker/sql/oracle/upgrade/upgrade-1.3d1-1.3d2.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,608 @@ +-- +-- Bug tracker Oracle data model +-- + + +create or replace package bt_project +as + procedure new ( + package_id in integer + ); + procedure del ( + project_id in integer + ); + procedure keywords_delete ( + project_id in integer, + delete_root_p in varchar2 default 'f' + ); + +end bt_project; +/ +show errors + +create or replace package bt_version +as + procedure set_active ( + active_version_id in integer + ); + +end bt_version; +/ +show errors + +create or replace package bt_bug +as + function new ( + bug_id in integer default null, + bug_number in integer default null, + package_id in integer, + component_id in integer, + found_in_version in integer, + summary in varchar2, + user_agent in varchar2 default null, + comment_content in varchar2, + comment_format in varchar2, + creation_date in date default sysdate(), + creation_user in integer, + creation_ip in varchar2 default null, + item_subtype in varchar2 default 'bt_bug', + content_type in varchar2 default 'bt_bug_revision' + ) return integer; + + procedure del ( + bug_id in integer + ); + + function name ( + bug_id in integer + ) return varchar2; + +end bt_bug; +/ +show errors + +create or replace package bt_bug_revision +as + function new( + bug_revision_id in integer default null, + bug_id in integer, + component_id in integer, + found_in_version in integer, + fix_for_version in integer, + fixed_in_version in integer, + resolution in varchar2, + user_agent in varchar2 default null, + summary in varchar2, + creation_date in date default sysdate(), + creation_user in integer, + creation_ip in varchar default null + ) return integer; + +end bt_bug_revision; +/ +show errors + +create or replace package bt_patch +as + function new ( + patch_id in integer default null, + project_id in integer, + component_id in integer, + summary in varchar2, + description in varchar2, + description_format in varchar2, + content in varchar2, + generated_from_version in integer, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in varchar2 + ) return integer; + + procedure del ( + patch_id in integer + ); + + function name ( + patch_id in integer + ) return varchar2; + +end bt_patch; +/ +show errors + +create or replace package body bt_project +as + procedure new ( + package_id in integer + ) + is + v_count integer; + v_instance_name varchar(300); + v_creation_user integer; + v_creation_ip varchar(50); + v_folder_id integer; + v_root_folder_id integer; + v_keyword_id integer; + begin + select count (*) + into v_count + from bt_projects + where project_id = new.package_id; + + if v_count > 0 then + return; + end if; + + -- get instance name for the content folder + select p.instance_name, o.creation_user, o.creation_ip + into v_instance_name, v_creation_user, v_creation_ip + from apm_packages p, + acs_objects o + where p.package_id = bt_project.new.package_id + and p.package_id = o.object_id; + + select content_item.get_root_folder + into v_root_folder_id + from dual; + + -- create a root CR folder + v_folder_id := content_folder.new( + name => 'bug_tracker_' || bt_project.new.package_id, + label => v_instance_name, + description => null, + parent_id => v_root_folder_id, + context_id => bt_project.new.package_id, + creation_user => v_creation_user, + creation_ip => v_creation_ip + ); + + -- Set package_id column. Oddly enoguh, there is no API to set it + update cr_folders set package_id = bt_project.new.package_id where folder_id = v_folder_id; + + -- register our content type + content_folder.register_content_type ( + folder_id => v_folder_id, + content_type => 'bt_bug_revision', + include_subtypes => 't' + ); + + -- create the instance root keyword + v_keyword_id := content_keyword.new( + heading => v_instance_name, + description => null, + parent_id => null, + keyword_id => null, + creation_date => sysdate(), + creation_user => v_creation_user, + creation_ip => v_creation_ip, + object_type => 'content_keyword' + ); + + -- insert the row into bt_projects + insert into bt_projects + (project_id, folder_id, root_keyword_id) + values + (bt_project.new.package_id, v_folder_id, v_keyword_id); + + -- Create a General component to start with + insert into bt_components + (component_id, project_id, component_name) + values + (acs_object_id_seq.nextval, bt_project.new.package_id, 'General'); + + return; + end new; + + procedure del ( + project_id in integer + ) + is + v_folder_id integer; + v_root_keyword_id integer; + begin + + -- get the content folder for this instance + select folder_id, root_keyword_id + into v_folder_id, v_root_keyword_id + from bt_projects + where project_id = bt_project.del.project_id; + + -- This get''s done in tcl before we are called ... for now + -- Delete the bugs + -- for rec in select item_id from cr_items where parent_id = v_folder_id + -- loop + -- bt_bug.del(rec.item_id); + -- end loop; + + -- Delete the patches + for rec in (select patch_id from bt_patches where project_id = bt_project.del.project_id) + loop + bt_patch.del(rec.patch_id); + end loop; + + -- delete the content folder + content_folder.del(v_folder_id); + + -- delete the projects keywords + bt_project.keywords_delete( + project_id => project_id, + delete_root_p => 't' + ); + + -- These tables should really be set up to cascade + delete from bt_versions where project_id = bt_project.del.project_id; + delete from bt_components where project_id = bt_project.del.project_id; + delete from bt_user_prefs where project_id = bt_project.del.project_id; + + delete from bt_projects where project_id = bt_project.del.project_id; + end del; + + procedure keywords_delete ( + project_id in integer, + delete_root_p in varchar2 default 'f' + ) + is + v_root_keyword_id integer; + v_changed_p char(1); + begin + -- get the content folder for this instance + select root_keyword_id + into v_root_keyword_id + from bt_projects + where project_id = keywords_delete.project_id; + + -- if we are deleting the root, remove it from the project as well + if delete_root_p = 't' then + update bt_projects + set root_keyword_id = null + where project_id = keywords_delete.project_id; + end if; + + -- delete the projects keywords + + -- Keep looping over all project keywords, deleting all + -- leaf nodes, until everything has been deleted + loop + v_changed_p := 'f'; + for rec in + (select keyword_id + from (select keyword_id + from cr_keywords + start with keyword_id = v_root_keyword_id + connect by prior keyword_id = parent_id) q + where content_keyword.is_leaf(keyword_id) = 't') + loop + if (delete_root_p = 't') or (rec.keyword_id != v_root_keyword_id) then + content_keyword.del(rec.keyword_id); + v_changed_p := 't'; + end if; + end loop; + + exit when v_changed_p = 'f'; + end loop; + + end keywords_delete; + +end bt_project; +/ +show errors + +create or replace package body bt_version +as + procedure set_active ( + active_version_id in integer + ) + is + v_project_id integer; + begin + select project_id + into v_project_id + from bt_versions + where version_id = active_version_id; + + if v_project_id is not null then + update bt_versions set active_version_p='f' where project_id = v_project_id; + end if; + + update bt_versions set active_version_p='t' where version_id = active_version_id; + + return; + end; +end bt_version; +/ +show errors + +create or replace package body bt_bug +as + function new ( + bug_id in integer default null, + bug_number in integer default null, + package_id in integer, + component_id in integer, + found_in_version in integer, + summary in varchar2, + user_agent in varchar2 default null, + comment_content in varchar2, + comment_format in varchar2, + creation_date in date default sysdate(), + creation_user in integer, + creation_ip in varchar2 default null, + item_subtype in varchar2 default 'bt_bug', + content_type in varchar2 default 'bt_bug_revision' + ) return integer + is + v_bug_id integer; + v_revision_id integer; + v_bug_number integer; + v_folder_id integer; + begin + -- get the content folder for this instance + select folder_id + into v_folder_id + from bt_projects + where project_id = bt_bug.new.package_id; + + -- get bug_number + if bug_number is null then + select nvl(max(bug_number),0) + 1 + into v_bug_number + from bt_bugs + where parent_id = v_folder_id; + else + v_bug_number := bug_number; + end if; + + -- create the content item + v_bug_id := content_item.new( + name => v_bug_number, + parent_id => v_folder_id, + item_id => bt_bug.new.bug_id, + locale => null, + creation_date => bt_bug.new.creation_date, + creation_user => bt_bug.new.creation_user, + context_id => v_folder_id, + creation_ip => bt_bug.new.creation_ip, + item_subtype => bt_bug.new.item_subtype, + content_type => bt_bug.new.content_type, + title => null, + description => null, + nls_language => null, + mime_type => null, + data => null + ); + + -- create the item type row + insert into bt_bugs + (bug_id, + bug_number, + comment_content, + comment_format, + parent_id, + project_id, + creation_date, + creation_user) + values + (v_bug_id, + v_bug_number, + bt_bug.new.comment_content, + bt_bug.new.comment_format, + v_folder_id, + bt_bug.new.package_id, + bt_bug.new.creation_date, + bt_bug.new.creation_user); + + -- create the initial revision + v_revision_id := bt_bug_revision.new( + bug_revision_id => null, + bug_id => v_bug_id, + component_id => bt_bug.new.component_id, + found_in_version => bt_bug.new.found_in_version, + fix_for_version => null, + fixed_in_version => null, + resolution => null, + user_agent => bt_bug.new.user_agent, + summary => bt_bug.new.summary, + creation_date => bt_bug.new.creation_date, + creation_user => bt_bug.new.creation_user, + creation_ip => bt_bug.new.creation_ip + ); + + return v_bug_id; + end new; + + procedure del ( + bug_id in integer + ) + is + v_case_id integer; + foo integer; + begin + -- Every bug is associated with a workflow case + select case_id into v_case_id + from workflow_cases + where object_id = bt_bug.del.bug_id; + + foo := workflow_case_pkg.del(v_case_id); + + -- Every bug may have notifications attached to it + -- and there is one column in the notificaitons datamodel that doesn't + -- cascade + for rec in (select notification_id from notifications where response_id = bt_bug.del.bug_id) + loop + notification.del (rec.notification_id); + end loop; + + acs_object.del(bug_id); + + return; + end del; + + function name ( + bug_id in integer + ) return varchar2 + is + v_name bt_bugs.summary%TYPE; + begin + select summary + into v_name + from bt_bugs + where bug_id = name.bug_id; + + return v_name; + end name; + +end bt_bug; +/ +show errors + +create or replace package body bt_bug_revision +as + function new( + bug_revision_id in integer default null, + bug_id in integer, + component_id in integer, + found_in_version in integer, + fix_for_version in integer, + fixed_in_version in integer, + resolution in varchar2, + user_agent in varchar2 default null, + summary in varchar2, + creation_date in date default sysdate(), + creation_user in integer, + creation_ip in varchar default null + ) return integer + is + + v_revision_id integer; + begin + -- create the initial revision + v_revision_id := content_revision.new( + title => summary, -- title + description => null, -- description + publish_date => sysdate(), -- publish_date + mime_type => null, -- mime_type + nls_language => null, -- nls_language + text => null, -- new_data + item_id => bug_id, -- item_id + revision_id => bug_revision_id, -- revision_id + creation_date => creation_date, -- creation_date + creation_user => creation_user, -- creation_user + creation_ip => creation_ip -- creation_ip + ); + + -- insert into the bug-specific revision table + insert into bt_bug_revisions + (bug_revision_id, component_id, resolution, user_agent, found_in_version, fix_for_version, fixed_in_version) + values + (v_revision_id, bt_bug_revision.new.component_id, bt_bug_revision.new.resolution, bt_bug_revision.new.user_agent, bt_bug_revision.new.found_in_version, bt_bug_revision.new.fix_for_version, bt_bug_revision.new.fixed_in_version); + + -- make this revision live + content_item.set_live_revision(v_revision_id); + + -- update the cache + update bt_bugs + set live_revision_id = v_revision_id, + summary = bt_bug_revision.new.summary, + component_id = bt_bug_revision.new.component_id, + resolution = bt_bug_revision.new.resolution, + user_agent = bt_bug_revision.new.user_agent, + found_in_version = bt_bug_revision.new.found_in_version, + fix_for_version = bt_bug_revision.new.fix_for_version, + fixed_in_version = bt_bug_revision.new.fixed_in_version + where bug_id = bt_bug_revision.new.bug_id; + + return v_revision_id; + end new; + +end bt_bug_revision; +/ +show errors + + +create or replace package body bt_patch +as + function new ( + patch_id in integer default null, + project_id in integer, + component_id in integer, + summary in varchar2, + description in varchar2, + description_format in varchar2, + content in varchar2, + generated_from_version in integer, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in varchar2 + ) return integer + is + v_patch_id integer; + v_patch_number integer; + v_action_id integer; + begin + v_patch_id := acs_object.new( + object_id => patch_id, + object_type => 'bt_patch', + context_id => project_id, + creation_ip => creation_ip, + creation_user => creation_user + ); + + select nvl(max(patch_number),0) +1 + into v_patch_number + from bt_patches + where project_id = new.project_id; + + insert into bt_patches + (patch_id, + project_id, + component_id, + summary, + content, + generated_from_version, + patch_number) + values + (v_patch_id, + project_id, + component_id, + summary, + content, + generated_from_version, + v_patch_number); + + select acs_object_id_seq.nextval into v_action_id from dual; + + insert into bt_patch_actions + (action_id, patch_id, action, actor, comment_text, comment_format) + values + (v_action_id, v_patch_id, 'open', creation_user, description, description_format); + + return v_patch_id; + end new; + + function name ( + patch_id in integer + ) return varchar2 + is + v_name bt_patches.summary%TYPE; + begin + select summary + into v_name + from bt_patches + where patch_id = name.patch_id; + + return v_name; + end name; + + + procedure del ( + patch_id in integer + ) + is + begin + acs_object.del( patch_id ); + + return; + end del; + +end bt_patch; +/ +show errors + Index: openacs-4/packages/bulk-mail/sql/oracle/upgrade/upgrade-0.4-0.5.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/bulk-mail/sql/oracle/upgrade/upgrade-0.4-0.5.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/bulk-mail/sql/oracle/upgrade/upgrade-0.4-0.5.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,110 @@ +-- +-- bulk_mail logic +-- +-- @author yon@openforce.net +-- @version $Id: upgrade-0.4-0.5.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +create or replace package bulk_mail +as + + function new ( + bulk_mail_id in bulk_mail_messages.bulk_mail_id%TYPE default null, + package_id in bulk_mail_messages.package_id%TYPE, + send_date in varchar default null, + date_format in varchar default 'YYYY MM DD HH24 MI SS', + status in bulk_mail_messages.status%TYPE default 'pending', + from_addr in bulk_mail_messages.from_addr%TYPE, + subject in bulk_mail_messages.subject%TYPE default null, + reply_to in bulk_mail_messages.reply_to%TYPE default null, + extra_headers in bulk_mail_messages.extra_headers%TYPE default null, + message in varchar, + query in bulk_mail_messages.query%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, + context_id in acs_objects.context_id%TYPE default null + ) return bulk_mail_messages.bulk_mail_id%TYPE; + + procedure del ( + bulk_mail_id in bulk_mail_messages.bulk_mail_id%TYPE + ); + +end bulk_mail; +/ +show errors + +create or replace package body bulk_mail +as + + function new ( + bulk_mail_id in bulk_mail_messages.bulk_mail_id%TYPE default null, + package_id in bulk_mail_messages.package_id%TYPE, + send_date in varchar default null, + date_format in varchar default 'YYYY MM DD HH24 MI SS', + status in bulk_mail_messages.status%TYPE default 'pending', + from_addr in bulk_mail_messages.from_addr%TYPE, + subject in bulk_mail_messages.subject%TYPE default null, + reply_to in bulk_mail_messages.reply_to%TYPE default null, + extra_headers in bulk_mail_messages.extra_headers%TYPE default null, + message in varchar, + query in bulk_mail_messages.query%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, + context_id in acs_objects.context_id%TYPE default null + ) return bulk_mail_messages.bulk_mail_id%TYPE + is + v_bulk_mail_id bulk_mail_messages.bulk_mail_id%TYPE; + v_send_date varchar(4000); + begin + + v_bulk_mail_id := acs_object.new( + object_id => bulk_mail.new.bulk_mail_id, + object_type => 'bulk_mail_message', + creation_date => bulk_mail.new.creation_date, + creation_user => bulk_mail.new.creation_user, + creation_ip => bulk_mail.new.creation_ip, + context_id => bulk_mail.new.context_id + ); + + v_send_date := bulk_mail.new.send_date; + if v_send_date is null then + select to_char(sysdate, bulk_mail.new.date_format) + into v_send_date + from dual; + end if; + + insert + into bulk_mail_messages + (bulk_mail_id, package_id, + send_date, status, + from_addr, subject, reply_to, + extra_headers, message, query) + values + (v_bulk_mail_id, bulk_mail.new.package_id, + to_date(bulk_mail.new.send_date, bulk_mail.new.date_format), bulk_mail.new.status, + bulk_mail.new.from_addr, bulk_mail.new.subject, bulk_mail.new.reply_to, + bulk_mail.new.extra_headers, bulk_mail.new.message, bulk_mail.new.query); + + return v_bulk_mail_id; + + end new; + + procedure del ( + bulk_mail_id in bulk_mail_messages.bulk_mail_id%TYPE + ) + is + begin + + delete + from bulk_mail_messages + where bulk_mail_messages.bulk_mail_id = bulk_mail.del.bulk_mail_id; + + acs_object.del(bulk_mail.del.bulk_mail_id); + + end del; + +end bulk_mail; +/ +show errors Index: openacs-4/packages/calendar/sql/oracle/upgrade/upgrade-1.0-2.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/calendar/sql/oracle/upgrade/upgrade-1.0-2.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/calendar/sql/oracle/upgrade/upgrade-1.0-2.0d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,586 @@ +-- Create the cal_item object +-- +-- @author Gary Jin (gjin@arsdigita.com) +-- @creation-date Nov 17, 2000 +-- @cvs-id $Id: upgrade-1.0-2.0d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +create or replace package cal_item +as + function new ( + cal_item_id in cal_items.cal_item_id%TYPE default null, + on_which_calendar in calendars.calendar_id%TYPE , + name in acs_activities.name%TYPE default null, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default 'f', + status_summary in acs_activities.status_summary%TYPE default null, + timespan_id in acs_events.timespan_id%TYPE default null, + activity_id in acs_events.activity_id%TYPE default null, + recurrence_id in acs_events.recurrence_id%TYPE default null, + item_type_id in cal_items.item_type_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cal_item', + 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 + ) return cal_items.cal_item_id%TYPE; + + -- delete cal_item + procedure del ( + cal_item_id in cal_items.cal_item_id%TYPE + ); + + procedure delete_all ( + recurrence_id in acs_events.recurrence_id%TYPE + ); + + -- functions to return the name of the cal_item + function name ( + cal_item_id in cal_items.cal_item_id%TYPE + ) return acs_activities.name%TYPE; + + -- functions to return the calendar that owns the cal_item + function on_which_calendar ( + cal_item_id in cal_items.cal_item_id%TYPE + ) return calendars.calendar_id%TYPE; + +end cal_item; +/ +show errors; + + + +create or replace package body cal_item +as + function new ( + cal_item_id in cal_items.cal_item_id%TYPE default null, + on_which_calendar in calendars.calendar_id%TYPE , + name in acs_activities.name%TYPE default null, + description in acs_activities.description%TYPE default null, + html_p in acs_activities.html_p%TYPE default 'f', + status_summary in acs_activities.status_summary%TYPE default null, + timespan_id in acs_events.timespan_id%TYPE default null, + activity_id in acs_events.activity_id%TYPE default null, + recurrence_id in acs_events.recurrence_id%TYPE default null, + item_type_id in cal_items.item_type_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cal_item', + 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 + ) return cal_items.cal_item_id%TYPE + + is + v_cal_item_id cal_items.cal_item_id%TYPE; + v_grantee_id acs_permissions.grantee_id%TYPE; + v_privilege acs_permissions.privilege%TYPE; + + begin + v_cal_item_id := acs_event.new ( + event_id => cal_item_id, + name => name, + description => description, + html_p => html_p, + status_summary => status_summary, + timespan_id => timespan_id, + activity_id => activity_id, + recurrence_id => recurrence_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into cal_items + (cal_item_id, on_which_calendar, item_type_id) + values (v_cal_item_id, on_which_calendar, item_type_id); + + -- assign the default permission to the cal_item + -- by default, cal_item are going to inherit the + -- calendar permission that it belongs too. + + -- first find out the permissions. + --select grantee_id into v_grantee_id + --from acs_permissions + --where object_id = cal_item.new.on_which_calendar; + + --select privilege into v_privilege + --from acs_permissions + --where object_id = cal_item.new.on_which_calendar; + + -- now we grant the permissions + --acs_permission.grant_permission ( + -- object_id => v_cal_item_id, + -- grantee_id => v_grantee_id, + -- privilege => v_privilege + + --); + + return v_cal_item_id; + + end new; + + procedure del ( + cal_item_id in cal_items.cal_item_id%TYPE + ) + is + + begin + -- Erase the cal_item assoicated with the id + delete from cal_items + where cal_item_id = cal_item.del.cal_item_id; + + -- Erase all the privileges + delete from acs_permissions + where object_id = cal_item.del.cal_item_id; + + acs_event.del(cal_item_id); + end del; + + procedure delete_all ( + recurrence_id in acs_events.recurrence_id%TYPE + ) is + v_event_id acs_events%ROWTYPE; + begin + FOR v_event_id in + (select * from acs_events + where recurrence_id = delete_all.recurrence_id) + LOOP + cal_item.del(v_event_id.event_id); + end LOOP; + + recurrence.del(recurrence_id); + end delete_all; + + -- functions to return the name of the cal_item + function name ( + cal_item_id in cal_items.cal_item_id%TYPE + ) + return acs_activities.name%TYPE + + is + v_name acs_activities.name%TYPE; + begin + select name + into v_name + from acs_activities + where activity_id = + ( + select activity_id + from acs_events + where event_id = cal_item.name.cal_item_id + ); + + return v_name; + end name; + + + -- functions to return the calendar that owns the cal_item + function on_which_calendar ( + cal_item_id in cal_items.cal_item_id%TYPE + ) + return calendars.calendar_id%TYPE + + is + v_calendar_id calendars.calendar_id%TYPE; + begin + select on_which_calendar + into v_calendar_id + from cal_items + where cal_item_id = cal_item.on_which_calendar.cal_item_id; + + return v_calendar_id; + end on_which_calendar; + +end cal_item; +/ +show errors; + + +------------------------------------------------------------- +-- create package calendar +------------------------------------------------------------- + +create or replace package calendar +as + function new ( + calendar_id in acs_objects.object_id%TYPE default null, + calendar_name in calendars.calendar_name%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'calendar', + owner_id in calendars.owner_id%TYPE , + private_p in calendars.private_p%TYPE default 'f', + package_id in calendars.package_id%TYPE default null, + 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 + + ) return calendars.calendar_id%TYPE; + + procedure del ( + calendar_id in calendars.calendar_id%TYPE + ); + + -- figures out the name of the calendar + function name ( + calendar_id in calendars.calendar_id%TYPE + ) return calendars.calendar_name%TYPE; + + -- returns 't' if calendar is private and 'f' if its not + function private_p ( + calendar_id in calendars.calendar_id%TYPE + ) return char; + + + -- returns 't' if calendar is viewable by the given party + -- this implies that the party has calendar_read permission + -- on this calendar + function readable_p ( + calendar_id in calendars.calendar_id%TYPE, + party_id in parties.party_id%TYPE + ) return char; + + -- returns 't' if party wants to be able to select + -- this calendar, and return 'f' otherwise. + function show_p ( + calendar_id in calendars.calendar_id%TYPE, + party_id in parties.party_id%TYPE + ) return char; + + + ---------------------------------------------------------------- + -- Helper functions for calendar generations: + -- + -- These functions are used for assist in calendar + -- generation. Putting them in the PL/SQL level ensures that + -- the date date will be the same, and allowing adoptation + -- to a different language much easier and faster. + -- + -- current month name + function month_name ( + current_date date + ) return char; + + -- next month + function next_month ( + current_date date + ) return date; + + -- prev month + function prev_month ( + current_date date + ) return date; + + -- number of days in the month + function num_day_in_month ( + current_date date + ) return integer; + + -- first day to be displayed in a month. + function first_displayed_date ( + current_date date + ) return date; + + -- last day to be displayed in a month. + function last_displayed_date ( + current_date date + ) return date; + +end calendar; +/ +show errors; + + +create or replace package body calendar +as + + function new ( + calendar_id in acs_objects.object_id%TYPE default null, + calendar_name in calendars.calendar_name%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'calendar', + owner_id in calendars.owner_id%TYPE , + private_p in calendars.private_p%TYPE default 'f', + package_id in calendars.package_id%TYPE default null, + 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 + + ) + return calendars.calendar_id%TYPE + + is + v_calendar_id calendars.calendar_id%TYPE; + + begin + v_calendar_id := acs_object.new ( + object_id => calendar_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into calendars + (calendar_id, calendar_name, owner_id, package_id, private_p) + values (v_calendar_id, calendar_name, owner_id, package_id, private_p); + + + -- each calendar has three default conditions + -- 1. all items are public + -- 2. all items are private + -- 3. no default conditions + -- + -- calendar being public implies granting permission + -- calendar_read to the group 'the_public' and 'registered users' + -- + -- calendar being private implies granting permission + -- calendar_read to the owner party/group of the party + -- + -- by default, we grant "calendar_admin" to + -- the owner of the calendar + acs_permission.grant_permission ( + object_id => v_calendar_id, + grantee_id => owner_id, + privilege => 'calendar_admin' + ); + + + return v_calendar_id; + end new; + + + + -- body for procedure delete + procedure del ( + calendar_id in calendars.calendar_id%TYPE + ) + is + + begin + -- First erase all the item relate to this calendar. + delete from calendars + where calendar_id = calendar.del.calendar_id; + + -- Delete all privileges associate with this calendar + delete from acs_permissions + where object_id = calendar.del.calendar_id; + + -- Delete all privilges of the cal_items that's associated + -- with this calendar + delete from acs_permissions + where object_id in ( + select cal_item_id + from cal_items + where on_which_calendar = calendar.del.calendar_id + ); + + + acs_object.del(calendar_id); + end del; + + + + -- figures out the name of the calendar + function name ( + calendar_id in calendars.calendar_id%TYPE + ) + return calendars.calendar_name%TYPE + + is + v_calendar_name calendars.calendar_name%TYPE; + begin + select calendar_name + into v_calendar_name + from calendars + where calendar_id = calendar.name.calendar_id; + + return v_calendar_name; + end name; + + + + -- returns 't' if calendar is private and 'f' if its not + function private_p ( + calendar_id in calendars.calendar_id%TYPE + ) + return char + + is + v_private_p char(1) := 't'; + begin + select private_p + into v_private_p + from calendars + where calendar_id = calendar.private_p.calendar_id; + + return v_private_p; + end private_p; + + + + -- returns 't' if calendar is viewable by the given party + -- this implies that the party has calendar_read permission + -- on this calendar + function readable_p ( + calendar_id in calendars.calendar_id%TYPE, + party_id in parties.party_id%TYPE + ) + return char + + is + v_readable_p char(1) := 't'; + begin + select decode(count(*), 1, 't', 'f') + into v_readable_p + from acs_object_party_privilege_map + where party_id = calendar.readable_p.party_id + and object_id = calendar.readable_p.calendar_id + and privilege = 'calendar_read'; + + return v_readable_p; + + end readable_p; + + -- returns 't' if party wants to be able to select (calendar_show granted) + -- this calendar, and .return 'f' otherwise. + -- + -- this seems to be a problem with the problem that when + -- revoking the permissions using acs_permissions.revoke + -- data is not removed from table acs_object_party_privilege_map. + function show_p ( + calendar_id in calendars.calendar_id%TYPE, + party_id in parties.party_id%TYPE + ) + return char + + is + v_show_p char(1) := 't'; + begin + select decode(count(*), 1, 't', 'f') + into v_show_p + from acs_permissions + where grantee_id = calendar.show_p.party_id + and object_id = calendar.show_p.calendar_id + and privilege = 'calendar_show'; + + return v_show_p; + + end show_p; + + + -- Helper functions for calendar generations: + -- + -- These functions are used for assist in calendar + -- generation. Putting them in the PL/SQL level ensures that + -- the date date will be the same, and allowing adoptation + -- to a different language much easier and faster. + -- + -- current month name + function month_name ( + current_date date + ) return char + + is + name char; + begin + select to_char(to_date(calendar.month_name.current_date), 'fmMonth') + into name + from dual; + + return name; + end month_name; + + + -- next month + function next_month ( + current_date date + ) return date + + is + v_date date; + begin + select trunc(add_months(to_date(sysdate), -1)) + into v_date + from dual; + + return v_date; + end next_month; + + + -- prev month + function prev_month ( + current_date date + ) return date + + is + v_date date; + begin + select trunc(add_months(to_date(sysdate), -1)) + into v_date + from dual; + + return v_date; + end prev_month; + + -- number of days in the month + function num_day_in_month ( + current_date date + ) return integer + + is + v_num integer; + begin + select to_char(last_day(to_date(sysdate)), 'DD') + into v_num + from dual; + + return v_num; + end num_day_in_month; + + -- first day to be displayed in a month. + function first_displayed_date ( + current_date date + ) return date + + is + v_date date; + begin + select next_day(trunc(to_date(sysdate), 'Month') - 7, 'SUNDAY') + into v_date + from dual; + + return v_date; + end first_displayed_date; + + -- last day to be displayed in a month. + function last_displayed_date ( + current_date date + ) return date + + is + v_date date; + begin + select next_day(last_day(to_date(sysdate)), 'SATURDAY') + into v_date + from dual; + + return v_date; + end last_displayed_date; + +end calendar; +/ +show errors + + + + + + + + + + + Index: openacs-4/packages/curriculum/sql/oracle/upgrade/upgrade-0.4d-0.5d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/curriculum/sql/oracle/upgrade/upgrade-0.4d-0.5d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/curriculum/sql/oracle/upgrade/upgrade-0.4d-0.5d1.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,258 @@ +-- packages/curriculum/sql/oracle/curriculum-curriculum-package-create.sql +-- +-- @author Ola Hansson (ola@polyxena.net) +-- @creation-date 2003-05-23 +-- @cvs-id $Id: upgrade-0.4d-0.5d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +create or replace package cu_curriculum +as + + function new ( + curriculum_id in cu_curriculums.curriculum_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cu_curriculum', + name in cu_curriculums.name%TYPE, +-- The description column is of type clob rather than varchar +-- in order to allow a maximum of 32K as opposed to varchar's 4K. +-- However, clob doesn't support the %TYPE syntax and clob isn't +-- a valid type in PLSQL. But since a varchar in PLSQL can be up +-- to 32K that is the explicit type we use here. + description in varchar default null, + desc_format in cu_curriculums.desc_format%TYPE, + owner_id in cu_curriculums.owner_id%TYPE, + package_id in cu_curriculums.package_id%TYPE, + sort_key in cu_curriculums.sort_key%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return cu_curriculums.curriculum_id%TYPE; + + function name ( + curriculum_id in cu_curriculums.curriculum_id%TYPE + ) return cu_curriculums.name%TYPE; + + procedure del ( + curriculum_id in cu_curriculums.curriculum_id%TYPE + ); + +end cu_curriculum; +/ +show errors + + +create or replace package body cu_curriculum +as + + function new ( + curriculum_id in cu_curriculums.curriculum_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cu_curriculum', + name in cu_curriculums.name%TYPE, + description in varchar default null, + desc_format in cu_curriculums.desc_format%TYPE, + owner_id in cu_curriculums.owner_id%TYPE, + package_id in cu_curriculums.package_id%TYPE, + sort_key in cu_curriculums.sort_key%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return cu_curriculums.curriculum_id%TYPE + is + v_curriculum_id cu_curriculums.curriculum_id%TYPE; + v_sort_key cu_curriculums.sort_key%TYPE; + begin + v_curriculum_id := acs_object.new( + object_id => curriculum_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => nvl(context_id, package_id) + ); + + if new.sort_key is null then + select nvl(max(sort_key)+1, 1) + into v_sort_key + from cu_curriculums + where package_id = new.package_id; + else + v_sort_key := new.sort_key; + end if; + + insert into cu_curriculums + (curriculum_id, name, description, desc_format, owner_id, package_id, sort_key) + values + (v_curriculum_id, name, description, desc_format, owner_id, package_id, v_sort_key); + + return v_curriculum_id; + end new; + + function name ( + curriculum_id in cu_curriculums.curriculum_id%TYPE + ) return cu_curriculums.name%TYPE + is + v_name cu_curriculums.name%TYPE; + begin + select name + into v_name + from cu_curriculums + where curriculum_id = cu_curriculum.name.curriculum_id; + + return v_name; + end name; + + procedure del ( + curriculum_id in cu_curriculums.curriculum_id%TYPE + ) + is + cursor c_element_cur is + select element_id + from cu_elements + where curriculum_id = cu_curriculum.del.curriculum_id; + begin + delete from acs_permissions + where object_id = cu_curriculum.del.curriculum_id; + + -- Delete all elements in the curriculum. + for v_element_val in c_element_cur loop + cu_element.del(v_element_val.element_id); + end loop; + + delete from cu_curriculums + where curriculum_id = cu_curriculum.del.curriculum_id; + + acs_object.del(cu_curriculum.del.curriculum_id); + end del; + +end cu_curriculum; +/ +show errors + +-- packages/curriculum/sql/oracle/curriculum-element-package-create.sql +-- +-- @author Ola Hansson (ola@polyxena.net) +-- @creation-date 2003-05-23 +-- @cvs-id $Id: upgrade-0.4d-0.5d1.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ + +create or replace package cu_element +as + + function new ( + element_id in cu_elements.element_id%TYPE default null, + curriculum_id in cu_elements.curriculum_id%TYPE, + name in cu_elements.name%TYPE, +-- The description column is of type clob rather than varchar +-- in order to allow a maximum of 32K as opposed to varchar's 4K. +-- However, clob doesn't support the %TYPE syntax and clob isn't +-- a valid type in PLSQL. But since a varchar in PLSQL can be up +-- to 32K that is the explicit type we use here. + description in varchar default null, + desc_format in cu_elements.desc_format%TYPE, + url in cu_elements.url%TYPE, + external_p in cu_elements.external_p%TYPE default 'f', + enabled_p in cu_elements.enabled_p%TYPE default 't', + sort_key in cu_elements.sort_key%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cu_element', + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return cu_elements.element_id%TYPE; + + function name ( + element_id in cu_elements.element_id%TYPE + ) return cu_elements.name%TYPE; + + procedure del ( + element_id in cu_elements.element_id%TYPE + ); + +end cu_element; +/ +show errors + + +create or replace package body cu_element +as + + function new ( + element_id in cu_elements.element_id%TYPE default null, + curriculum_id in cu_elements.curriculum_id%TYPE, + name in cu_elements.name%TYPE, +-- The 'description' column is of type clob rather than varchar +-- in order to allow a maximum of 32K as opposed to varchar's 4K. +-- However, clob doesn't support the %TYPE syntax and clob isn't +-- a valid type in PLSQL. But since a varchar in PLSQL can be up +-- to 32K that is the explicit type we use here. + description in varchar default null, + desc_format in cu_elements.desc_format%TYPE, + url in cu_elements.url%TYPE, + external_p in cu_elements.external_p%TYPE default 'f', + enabled_p in cu_elements.enabled_p%TYPE default 't', + sort_key in cu_elements.sort_key%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'cu_element', + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return cu_elements.element_id%TYPE + is + v_element_id cu_elements.element_id%TYPE; + v_sort_key cu_elements.sort_key%TYPE; + begin + v_element_id := acs_object.new ( + object_id => element_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => nvl(context_id, curriculum_id) + ); + + if new.sort_key is null then + select nvl(max(sort_key)+1, 1) + into v_sort_key + from cu_elements + where curriculum_id = new.curriculum_id; + else + v_sort_key := new.sort_key; + end if; + + insert into cu_elements + (element_id, curriculum_id, name, description, desc_format, url, external_p, enabled_p, sort_key) + values + (v_element_id, curriculum_id, name, description, desc_format, url, external_p, enabled_p, v_sort_key); + + return v_element_id; + end new; + + function name ( + element_id in cu_elements.element_id%TYPE + ) return cu_elements.name%TYPE + is + v_name cu_elements.name%TYPE; + begin + select name into v_name + from cu_elements + where element_id = name.element_id; + + return v_name; + end name; + + procedure del ( + element_id in cu_elements.element_id%TYPE + ) + is + begin + delete from acs_permissions + where object_id = cu_element.del.element_id; + + delete from cu_elements + where element_id = cu_element.del.element_id; + + acs_object.del(element_id); + end del; + +end cu_element; +/ +show errors Index: openacs-4/packages/forums/sql/oracle/upgrade/upgrade-1.0d3-1.0d4.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/forums/sql/oracle/upgrade/upgrade-1.0d3-1.0d4.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/forums/sql/oracle/upgrade/upgrade-1.0d3-1.0d4.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,364 @@ + +-- +-- The Forums Package +-- +-- @author gwong@orchardlabs.com,ben@openforce.biz +-- @creation-date 2002-05-16 +-- +-- The Package +-- +-- This code is newly concocted by Ben, but with heavy concepts and heavy code +-- chunks lifted from Gilbert. Thanks Orchard Labs! +-- + +create or replace package forums_forum +as + + function new ( + forum_id in forums_forums.forum_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'forums_forum', + name in forums_forums.name%TYPE, + charter in forums_forums.charter%TYPE default null, + presentation_type in forums_forums.presentation_type%TYPE, + posting_policy in forums_forums.posting_policy%TYPE, + package_id in forums_forums.package_id%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return forums_forums.forum_id%TYPE; + + function name ( + forum_id in forums_forums.forum_id%TYPE + ) return varchar; + + procedure del ( + forum_id in forums_forums.forum_id%TYPE + ); + +end forums_forum; +/ +show errors + +create or replace package body forums_forum +as + + function new ( + forum_id in forums_forums.forum_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'forums_forum', + name in forums_forums.name%TYPE, + charter in forums_forums.charter%TYPE default null, + presentation_type in forums_forums.presentation_type%TYPE, + posting_policy in forums_forums.posting_policy%TYPE, + package_id in forums_forums.package_id%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return forums_forums.forum_id%TYPE + is + v_forum_id forums_forums.forum_id%TYPE; + begin + v_forum_id := acs_object.new( + object_id => forum_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => nvl(context_id, package_id) + ); + + insert into forums_forums + (forum_id, name, charter, presentation_type, posting_policy, package_id) + values + (v_forum_id, name, charter, presentation_type, posting_policy, package_id); + + return v_forum_id; + end new; + + function name ( + forum_id in forums_forums.forum_id%TYPE + ) return varchar + is + v_name forums_forums.name%TYPE; + begin + select name + into v_name + from forums_forums + where forum_id = name.forum_id; + + return v_name; + end name; + + procedure del ( + forum_id in forums_forums.forum_id%TYPE + ) + is + begin + acs_object.del(forum_id); + end del; + +end forums_forum; +/ +show errors + +-- +-- The Forums Package +-- +-- @author gwong@orchardlabs.com,ben@openforce.biz +-- @creation-date 2002-05-16 +-- +-- The Package for Messages +-- +-- This code is newly concocted by Ben, but with heavy concepts and heavy code +-- chunks lifted from Gilbert. Thanks Orchard Labs! +-- + +create or replace package forums_message +as + + function new ( + message_id in forums_messages.message_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'forums_message', + forum_id in forums_messages.forum_id%TYPE, + subject in forums_messages.subject%TYPE, + content in varchar, + html_p in forums_messages.html_p%TYPE default 'f', + user_id in forums_messages.user_id%TYPE, + posting_date in forums_messages.posting_date%TYPE default sysdate, + state in forums_messages.state%TYPE default null, + parent_id in forums_messages.parent_id%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return forums_messages.message_id%TYPE; + + function root_message_id ( + message_id in forums_messages.message_id%TYPE + ) return forums_messages.message_id%TYPE; + + procedure thread_open ( + message_id in forums_messages.message_id%TYPE + ); + + procedure thread_close ( + message_id in forums_messages.message_id%TYPE + ); + + procedure del ( + message_id in forums_messages.message_id%TYPE + ); + + procedure delete_thread ( + message_id in forums_messages.message_id%TYPE + ); + + function name ( + message_id in forums_messages.message_id%TYPE + ) return varchar; + +end forums_message; +/ +show errors + +create or replace package body forums_message +as + + function new ( + message_id in forums_messages.message_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'forums_message', + forum_id in forums_messages.forum_id%TYPE, + subject in forums_messages.subject%TYPE, + content in varchar, + html_p in forums_messages.html_p%TYPE default 'f', + user_id in forums_messages.user_id%TYPE, + posting_date in forums_messages.posting_date%TYPE default sysdate, + state in forums_messages.state%TYPE default null, + parent_id in forums_messages.parent_id%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return forums_messages.message_id%TYPE + is + v_message_id acs_objects.object_id%TYPE; + v_sortkey forums_messages.tree_sortkey%TYPE; + v_forum_policy forums_forums.posting_policy%TYPE; + v_state forums_messages.state%TYPE; + begin + + v_message_id := acs_object.new( + object_id => message_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => nvl(context_id, forum_id) + ); + + if state is null + then + select posting_policy + into v_forum_policy + from forums_forums + where forum_id= new.forum_id; + + if v_forum_policy = 'moderated' then + v_state := 'pending'; + else + v_state := 'approved'; + end if; + else + v_state := state; + end if; + + insert into forums_messages + (message_id, forum_id, subject, content, html_p, user_id, posting_date, parent_id, state) + values + (v_message_id, forum_id, subject, content, html_p, user_id, posting_date, parent_id, v_state); + + -- DRB: Can't use root_message_id() here because it triggers a "mutating table" error + + select tree_sortkey into v_sortkey + from forums_messages + where message_id = v_message_id; + + update forums_forums + set last_post = posting_date + where forum_id = forums_message.new.forum_id; + + update forums_messages + set last_child_post = posting_date + where forum_id = forums_message.new.forum_id + and tree_sortkey = tree.ancestor_key(v_sortkey, 1); + + return v_message_id; + end new; + + function root_message_id ( + message_id in forums_messages.message_id%TYPE + ) return forums_messages.message_id%TYPE + is + v_message_id forums_messages.message_id%TYPE; + v_forum_id forums_messages.forum_id%TYPE; + v_sortkey forums_messages.tree_sortkey%TYPE; + begin + select forum_id, tree_sortkey + into v_forum_id, v_sortkey + from forums_messages + where message_id = root_message_id.message_id; + + select message_id + into v_message_id + from forums_messages + where forum_id = v_forum_id + and tree_sortkey = tree.ancestor_key(v_sortkey, 1); + + return v_message_id; + end root_message_id; + + procedure thread_open ( + message_id in forums_messages.message_id%TYPE + ) + is + v_forum_id forums_messages.forum_id%TYPE; + v_sortkey forums_messages.tree_sortkey%TYPE; + begin + select forum_id, tree_sortkey + into v_forum_id, v_sortkey + from forums_messages + where message_id = thread_open.message_id; + + update forums_messages + set open_p = 't' + where tree_sortkey between tree.left(v_sortkey) and tree.right(v_sortkey) + and forum_id = v_forum_id; + + update forums_messages + set open_p = 't' + where message_id = thread_open.message_id; + end thread_open; + + procedure thread_close ( + message_id in forums_messages.message_id%TYPE + ) + is + v_forum_id forums_messages.forum_id%TYPE; + v_sortkey forums_messages.tree_sortkey%TYPE; + begin + select forum_id, tree_sortkey + into v_forum_id, v_sortkey + from forums_messages + where message_id = thread_close.message_id; + + update forums_messages + set open_p = 'f' + where tree_sortkey between tree.left(v_sortkey) and tree.right(v_sortkey) + and forum_id = v_forum_id; + + update forums_messages + set open_p = 'f' + where message_id = thread_close.message_id; + end thread_close; + + procedure del ( + message_id in forums_messages.message_id%TYPE + ) + is + begin + acs_object.del(message_id); + end del; + + procedure delete_thread ( + message_id in forums_messages.message_id%TYPE + ) + is + v_forum_id forums_messages.forum_id%TYPE; + v_sortkey forums_messages.tree_sortkey%TYPE; + v_message forums_messages%ROWTYPE; + begin + select forum_id, tree_sortkey + into v_forum_id, v_sortkey + from forums_messages + where message_id = delete_thread.message_id; + + -- if it's already deleted + if SQL%NOTFOUND then + return; + end if; + + -- delete all children + -- order by tree_sortkey desc to guarantee + -- that we never delete a parent before its child + -- sortkeys are beautiful + for v_message in (select * + from forums_messages + where forum_id = v_forum_id + and tree_sortkey between tree.left(v_sortkey) and tree.right(v_sortkey) + order by tree_sortkey desc) + loop + forums_message.del(v_message.message_id); + end loop; + + -- delete the message itself + forums_message.del(delete_thread.message_id); + end delete_thread; + + function name ( + message_id in forums_messages.message_id%TYPE + ) return varchar + is + v_name forums_messages.subject%TYPE; + begin + select subject + into v_name + from forums_messages + where message_id = forums_message.name.message_id; + + return v_name; + end name; + +end forums_message; +/ +show errors Index: openacs-4/packages/lars-blogger/sql/oracle/upgrade/upgrade-1.0d1-1.0d2.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/lars-blogger/sql/oracle/upgrade/upgrade-1.0d1-1.0d2.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/lars-blogger/sql/oracle/upgrade/upgrade-1.0d1-1.0d2.sql 8 Oct 2003 16:59:22 -0000 1.1 @@ -0,0 +1,204 @@ +-- +-- lars-blogger-package-create.sql +-- +-- @author Lars Pind +-- @author Yon (Yon@milliped.com) Oracle Port +-- +-- @cvs-id $Id: upgrade-1.0d1-1.0d2.sql,v 1.1 2003/10/08 16:59:22 mohanp Exp $ +-- + +create or replace package pinds_blog_entry +as + + function new ( + entry_id in pinds_blog_entries.entry_id%TYPE default null, + package_id in pinds_blog_entries.package_id%TYPE, + title in pinds_blog_entries.title%TYPE default null, + title_url in pinds_blog_entries.title_url%TYPE default null, + content in varchar default null, + content_format in varchar default 'text/html', + entry_date in pinds_blog_entries.entry_date%TYPE default null, + draft_p in pinds_blog_entries.draft_p%TYPE default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return pinds_blog_entries.entry_id%TYPE; + + procedure del ( + entry_id in pinds_blog_entries.entry_id%TYPE + ); + + function title ( + entry_id in pinds_blog_entries.entry_id%TYPE + ) return pinds_blog_entries.title%TYPE; + +end pinds_blog_entry; +/ +show errors + +create or replace package body pinds_blog_entry +as + + function new ( + entry_id in pinds_blog_entries.entry_id%TYPE default null, + package_id in pinds_blog_entries.package_id%TYPE, + title in pinds_blog_entries.title%TYPE default null, + title_url in pinds_blog_entries.title_url%TYPE default null, + content in varchar default null, + content_format in varchar default 'text/html', + entry_date in pinds_blog_entries.entry_date%TYPE default null, + draft_p in pinds_blog_entries.draft_p%TYPE default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return pinds_blog_entries.entry_id%TYPE + is + v_entry_id pinds_blog_entries.entry_id%TYPE; + begin + + v_entry_id := acs_object.new( + object_id => pinds_blog_entry.new.entry_id, + object_type => 'pinds_blog_entry', + creation_date => sysdate, + creation_user => pinds_blog_entry.new.creation_user, + creation_ip => pinds_blog_entry.new.creation_ip, + context_id => pinds_blog_entry.new.package_id + ); + + insert into pinds_blog_entries ( + entry_id, + package_id, + title, + title_url, + content, + content_format, + entry_date, + posted_date, + draft_p, + deleted_p + ) values ( + v_entry_id, + pinds_blog_entry.new.package_id, + pinds_blog_entry.new.title, + pinds_blog_entry.new.title_url, + pinds_blog_entry.new.content, + pinds_blog_entry.new.content_format, + pinds_blog_entry.new.entry_date, + sysdate, + pinds_blog_entry.new.draft_p, + 'f' + ); + + return v_entry_id; + + end new; + + procedure del ( + entry_id in pinds_blog_entries.entry_id%TYPE + ) + is + begin + + delete + from pinds_blog_entries + where entry_id = pinds_blog_entry.del.entry_id; + + acs_object.del(pinds_blog_entry.del.entry_id); + + end del; + + function title ( + entry_id in pinds_blog_entries.entry_id%TYPE + ) return pinds_blog_entries.title%TYPE + is + v_title pinds_blog_entries.title%TYPE; + begin + + select title + into v_title + from pinds_blog_entries + where entry_id = pinds_blog_entry.title.entry_id; + + return v_title; + + exception when no_data_found then + return ''; + + end title; + +end pinds_blog_entry; +/ +show errors + +create or replace package weblogger_channel +as + + function new ( + channel_id in weblogger_channels.channel_id%TYPE default null, + package_id in weblogger_channels.package_id%TYPE, + user_id in weblogger_channels.user_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return weblogger_channels.channel_id%TYPE; + + procedure del ( + channel_id in weblogger_channels.channel_id%TYPE + ); + +end weblogger_channel; +/ +show errors + + +create or replace package body weblogger_channel +as + + function new ( + channel_id in weblogger_channels.channel_id%TYPE default null, + package_id in weblogger_channels.package_id%TYPE, + user_id in weblogger_channels.user_id%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return weblogger_channels.channel_id%TYPE + is + v_channel_id weblogger_channels.channel_id%TYPE; + begin + + v_channel_id := acs_object.new( + object_id => weblogger_channel.new.channel_id, + object_type => 'weblogger_channel', + creation_date => sysdate, + creation_user => weblogger_channel.new.creation_user, + creation_ip => weblogger_channel.new.creation_ip, + context_id => weblogger_channel.new.package_id + ); + + insert into weblogger_channels ( + channel_id, + package_id, + user_id + ) values ( + v_channel_id, + weblogger_channel.new.package_id, + weblogger_channel.new.user_id + ); + + return v_channel_id; + + end new; + + procedure del ( + channel_id in weblogger_channels.channel_id%TYPE + ) + is + begin + + delete + from weblogger_channels + where channel_id = weblogger_channel.del.channel_id; + + acs_object.del(weblogger_channel.del.channel_id); + + end del; + +end weblogger_channel; +/ +show errors Index: openacs-4/packages/logger/sql/oracle/upgrade/upgrade-1.0b1-1.0b2.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/logger/sql/oracle/upgrade/upgrade-1.0b1-1.0b2.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/logger/sql/oracle/upgrade/upgrade-1.0b1-1.0b2.sql 8 Oct 2003 17:00:30 -0000 1.1 @@ -0,0 +1,291 @@ +-- +-- Oracle PL/SQL packages for the Logger application +-- +-- @author Lars Pind (lars@collaboraid.biz) +-- @author Peter Marklund (peter@collaboraid.biz) +-- @creation-date 2003-04-03 + +------------------------------------ +-- Package definititions +------------------------------------ + +create or replace package logger_project +as + function new ( + project_id in integer default null, + name in logger_projects.name%TYPE, + description in logger_projects.description%TYPE default null, + project_lead in integer, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null, + package_id in apm_packages.package_id%TYPE + ) return integer; + + procedure del ( + project_id in integer + ); + + function name ( + project_id in integer + ) return varchar2; + +end logger_project; +/ +show errors; + +create or replace package logger_variable +as + function new ( + variable_id in integer default null, + name in logger_variables.name%TYPE, + unit in logger_variables.unit%TYPE, + type in logger_variables.type%TYPE, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null, + package_id in apm_packages.package_id%TYPE + ) return integer; + + procedure del ( + variable_id in integer + ); + + function name ( + variable_id in integer + ) return varchar2; + +end logger_variable; +/ +show errors; + +create or replace package logger_entry +as + function new ( + entry_id in logger_entries.entry_id%TYPE default null, + project_id in logger_entries.project_id%TYPE, + variable_id in logger_entries.variable_id%TYPE, + value in logger_entries.value%TYPE, + time_stamp in logger_entries.time_stamp%TYPE, + description in logger_entries.description%TYPE default null, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return integer; + + procedure del ( + entry_id in integer + ); + + function name ( + entry_id in integer + ) return varchar2; + +end logger_entry; +/ +show errors; + +------------------------------------ +-- Package body implementations +------------------------------------ + +create or replace package body logger_project +as + function new ( + project_id in integer default null, + name in logger_projects.name%TYPE, + description in logger_projects.description%TYPE default null, + project_lead in integer, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null, + package_id in apm_packages.package_id%TYPE + ) return integer + is + v_project_id integer; + begin + v_project_id := acs_object.new( + object_id => project_id, + object_type => 'logger_project', + context_id => package_id, + creation_ip => creation_ip, + creation_user => creation_user + ); + + insert into logger_projects (project_id, name, description, project_lead) + values (v_project_id, name, description, project_lead); + + insert into logger_project_pkg_map (project_id, package_id) + values (v_project_id, logger_project.new.package_id); + + return v_project_id; + end new; + + procedure del ( + project_id in integer + ) + is + begin + -- Delete all entries in the project + for rec in (select entry_id + from logger_entries + where project_id = logger_project.del.project_id + ) + loop + logger_entry.del(rec.entry_id); + end loop; + + -- Delete all variables only mapped to this project. + for rec in (select variable_id + from logger_variables + where exists (select 1 + from logger_project_pkg_map + where project_id = logger_project.del.project_id + ) + and not exists (select 1 + from logger_project_pkg_map + where project_id <> logger_project.del.project_id + ) + ) + loop + logger_variable.del(rec.variable_id); + end loop; + + -- Delete the project acs object. This will cascade the row in the logger_projects table + -- as well as all projections in the project + -- acs_object.delete should delete permissions for us but this change is not on cvs head yet + delete from acs_permissions where object_id = project_id; + acs_object.del(project_id); + + end del; + + function name ( + project_id in integer + ) return varchar2 + is + v_name logger_projects.name%TYPE; + begin + select name + into v_name + from logger_projects + where project_id = name.project_id; + + return v_name; + end name; + +end logger_project; +/ +show errors; + +create or replace package body logger_variable +as + function new ( + variable_id in integer default null, + name in logger_variables.name%TYPE, + unit in logger_variables.unit%TYPE, + type in logger_variables.type%TYPE, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null, + package_id in apm_packages.package_id%TYPE + ) return integer + is + v_variable_id integer; + begin + v_variable_id := acs_object.new( + object_id => variable_id, + object_type => 'logger_variable', + context_id => package_id, + creation_ip => creation_ip, + creation_user => creation_user + ); + + insert into logger_variables (variable_id, name, unit, type, package_id) + values (v_variable_id, name, unit, type, package_id); + + return v_variable_id; + end new; + + procedure del ( + variable_id in integer + ) + is + begin + -- Everything should be set up to cascade + -- acs_object.delete should delete permissions for us but this change is not on cvs head yet + delete from acs_permissions where object_id = variable_id; + acs_object.del(variable_id); + end del; + + function name ( + variable_id in integer + ) return varchar2 + is + v_name logger_projects.name%TYPE; + begin + select name + into v_name + from logger_variables + where variable_id = name.variable_id; + + return v_name; + end name; + +end logger_variable; +/ +show errors; + +create or replace package body logger_entry +as + function new ( + entry_id in logger_entries.entry_id%TYPE default null, + project_id in logger_entries.project_id%TYPE, + variable_id in logger_entries.variable_id%TYPE, + value in logger_entries.value%TYPE, + time_stamp in logger_entries.time_stamp%TYPE, + description in logger_entries.description%TYPE default null, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return integer + is + v_entry_id integer; + begin + v_entry_id := acs_object.new( + object_id => entry_id, + object_type => 'logger_entry', + context_id => project_id, + creation_ip => creation_ip, + creation_user => creation_user + ); + + insert into logger_entries (entry_id, project_id, variable_id, value, + time_stamp, description) + values (v_entry_id, project_id, variable_id, value, time_stamp, description); + + return v_entry_id; + + end new; + + procedure del ( + entry_id in integer + ) + is + begin + -- The row in the entries table will cascade + -- acs_object.delete should delete permissions for us but this change is not on cvs head yet + delete from acs_permissions where object_id = entry_id; + acs_object.del(entry_id); + end del; + + function name ( + entry_id in integer + ) return varchar2 + is + v_name logger_projects.name%TYPE; + begin + -- TODO: Should we only return the say 20 first characters here? + select description into v_name + from logger_entries + where entry_id = logger_entry.name.entry_id; + + return v_name; + end name; + +end logger_entry; +/ +show errors; Index: openacs-4/packages/news/sql/oracle/upgrade/upgrade-5.0d1-5.0d2.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/news/sql/oracle/upgrade/upgrade-5.0d1-5.0d2.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/news/sql/oracle/upgrade/upgrade-5.0d1-5.0d2.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,588 @@ +-- /packages/news/sql/news-create.sql +-- +-- @author stefan@arsdigita.com +-- @created 2000-12-13 +-- @cvs-id $Id: upgrade-5.0d1-5.0d2.sql,v 1.1 2003/10/08 16:59:23 mohanp Exp $ + + +-- *** PACKAGE NEWS, plsql to create content_item *** +create or replace package news +as + function new ( + item_id in cr_items.item_id%TYPE default null, + -- + locale in cr_items.locale%TYPE default null, + -- + publish_date in cr_revisions.publish_date%TYPE default null, + text in varchar2 default null, + nls_language in cr_revisions.nls_language%TYPE default null, + title in cr_revisions.title%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + -- + package_id in cr_news.package_id%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default null, + approval_ip in cr_news.approval_ip%TYPE default null, + -- + relation_tag in cr_child_rels.relation_tag%TYPE + default null, + -- + item_subtype in acs_object_types.object_type%TYPE + default 'content_revision', + content_type in acs_object_types.object_type%TYPE + default 'news', + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_ip in acs_objects.creation_ip%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + -- + is_live_p in varchar2 default 'f' + ) return cr_news.news_id%TYPE; + + procedure del ( + item_id in cr_items.item_id%TYPE + ); + + procedure archive ( + item_id in cr_items.item_id%TYPE, + archive_date in cr_news.archive_date%TYPE default sysdate + ); + + procedure make_permanent ( + item_id in cr_items.item_id%TYPE + ); + + + procedure set_approve ( + revision_id in cr_revisions.revision_id%TYPE, + approve_p in varchar2 default 't', + publish_date in cr_revisions.publish_date%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default sysdate, + approval_ip in cr_news.approval_ip%TYPE default null, + live_revision_p in varchar2 default 't' + ); + + + + function status ( + news_id in cr_news.news_id%TYPE + ) return varchar2; + + + function name ( + news_id in cr_news.news_id%TYPE + ) return varchar2; + + + -- + -- API for revisions: e.g. when the news admin wants to revise a news item + -- + function revision_new ( + item_id in cr_items.item_id%TYPE, + -- + publish_date in cr_revisions.publish_date%TYPE default null, + text in varchar2 default null, + title in cr_revisions.title%TYPE, + -- + -- here goes the revision log + description in cr_revisions.description%TYPE, + -- + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + package_id in cr_news.package_id%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default null, + approval_ip in cr_news.approval_ip%TYPE default null, + -- + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_ip in acs_objects.creation_ip%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + -- + make_active_revision_p in varchar2 default 'f' + ) return cr_revisions.revision_id%TYPE; + + + procedure revision_delete ( + revision_id in cr_revisions.revision_id%TYPE + ); + + + procedure revision_set_active ( + revision_id in cr_revisions.revision_id%TYPE + ); + + procedure clone ( + new_package_id in cr_news.package_id%TYPE default null, + old_package_id in cr_news.package_id%TYPE default null + ); + +end news; +/ +show errors + + + +create or replace package body news + as + function new ( + item_id in cr_items.item_id%TYPE default null, + -- + locale in cr_items.locale%TYPE default null, + -- + publish_date in cr_revisions.publish_date%TYPE default null, + text in varchar2 default null, + nls_language in cr_revisions.nls_language%TYPE default null, + title in cr_revisions.title%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default + 'text/plain', + -- + package_id in cr_news.package_id%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default null, + approval_ip in cr_news.approval_ip%TYPE default null, + -- + relation_tag in cr_child_rels.relation_tag%TYPE default null, + -- + item_subtype in acs_object_types.object_type%TYPE default + 'content_revision', + content_type in acs_object_types.object_type%TYPE default 'news', + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_ip in acs_objects.creation_ip%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + -- + is_live_p in varchar2 default 'f' + ) return cr_news.news_id%TYPE + is + v_news_id integer; + v_item_id integer; + v_id integer; + v_revision_id integer; + v_parent_id integer; + v_name varchar2(200); + v_log_string varchar2(400); + begin + select content_item.get_id('news') + into v_parent_id + from dual; + -- + -- this will be used for 2xClick protection + if item_id is null then + select acs_object_id_seq.nextval + into v_id + from dual; + else + v_id := item_id; + end if; + -- + select 'news' || to_char(sysdate,'YYYYMMDD') || v_id + into v_name + from dual; + -- + v_log_string := 'initial submission'; + -- + v_item_id := content_item.new( + item_id => v_id, + name => v_name, + parent_id => v_parent_id, + context_id => package_id, + locale => locale, + item_subtype => item_subtype, + content_type => content_type, + mime_type => mime_type, + nls_language => nls_language, + relation_tag => relation_tag, + creation_date => creation_date, + creation_ip => creation_ip, + creation_user => creation_user + ); + v_revision_id := content_revision.new( + title => title, + description => v_log_string, + publish_date => publish_date, + mime_type => mime_type, + nls_language => nls_language, + text => text, + item_id => v_item_id, + creation_date => creation_date, + creation_ip => creation_ip, + creation_user => creation_user + ); + insert into cr_news + (news_id, + package_id, + archive_date, + approval_user, + approval_date, + approval_ip) + values + (v_revision_id, + package_id, + archive_date, + approval_user, + approval_date, + approval_ip); + -- make this revision live when immediately approved + if is_live_p = 't' then + update + cr_items + set + live_revision = v_revision_id, + publish_status = 'ready' + where + item_id = v_item_id; + end if; + v_news_id := v_revision_id; + return v_news_id; + end new; + + + -- deletes a news item along with all its revisions and possibnle attachements + procedure del ( + item_id in cr_items.item_id%TYPE + ) is + v_item_id cr_items.item_id%TYPE; + + cursor comment_cursor IS + select message_id + from acs_messages am, acs_objects ao + where am.message_id = ao.object_id + and ao.context_id = v_item_id; + + begin + v_item_id := news.del.item_id; + dbms_output.put_line('Deleting associated comments...'); + -- delete acs_messages, images, comments to news item + for v_cm in comment_cursor loop + -- images + delete from images + where image_id in (select latest_revision + from cr_items + where parent_id = v_cm.message_id); + acs_message.del(v_cm.message_id); + delete from general_comments + where comment_id = v_cm.message_id; + end loop; + delete from cr_news + where news_id in (select revision_id + from cr_revisions + where item_id = v_item_id); + content_item.del(v_item_id); + end del; + + + -- (re)-publish a news item out of the archive by nulling the archive_date + -- this only applies to the currently active revision + procedure make_permanent ( + item_id in cr_items.item_id%TYPE + ) + is + begin + update cr_news + set archive_date = null + where news_id = content_item.get_live_revision(news.make_permanent.item_id); + end make_permanent; + + + -- archive a news item + -- this only applies to the currently active revision + procedure archive ( + item_id in cr_items.item_id%TYPE, + archive_date in cr_news.archive_date%TYPE default sysdate + ) + is + begin + update cr_news + set archive_date = news.archive.archive_date + where news_id = content_item.get_live_revision(news.archive.item_id); + end archive; + + + -- approve/unapprove a specific revision + -- approving a revision makes it also the active revision + procedure set_approve( + revision_id in cr_revisions.revision_id%TYPE, + approve_p in varchar2 default 't', + publish_date in cr_revisions.publish_date%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default sysdate, + approval_ip in cr_news.approval_ip%TYPE default null, + live_revision_p in varchar2 default 't' + ) + is + v_item_id cr_items.item_id%TYPE; + begin + select item_id into v_item_id + from cr_revisions + where revision_id = news.set_approve.revision_id; + -- unapprove an revision (does not mean to knock out active revision) + if news.set_approve.approve_p = 'f' then + update cr_news + set approval_date = null, + approval_user = null, + approval_ip = null, + archive_date = null + where news_id = news.set_approve.revision_id; + -- + update cr_revisions + set publish_date = null + where revision_id = news.set_approve.revision_id; + else + -- approve a revision + update cr_revisions + set publish_date = news.set_approve.publish_date + where revision_id = news.set_approve.revision_id; + -- + update cr_news + set archive_date = news.set_approve.archive_date, + approval_date = news.set_approve.approval_date, + approval_user = news.set_approve.approval_user, + approval_ip = news.set_approve.approval_ip + where news_id = news.set_approve.revision_id; + -- + -- cannot use content_item.set_live_revision because it sets publish_date to sysdate + if news.set_approve.live_revision_p = 't' then + update cr_items + set live_revision = news.set_approve.revision_id, + publish_status = 'ready' + where item_id = v_item_id; + end if; + -- + end if; + end set_approve; + + + + -- the status function returns information on the puplish or archive status + -- it does not make any checks on the order of publish_date and archive_date + function status ( + news_id in cr_news.news_id%TYPE + ) return varchar2 + is + v_archive_date date; + v_publish_date date; + begin + -- populate variables + select archive_date into v_archive_date + from cr_news + where news_id = news.status.news_id; + -- + select publish_date into v_publish_date + from cr_revisions + where revision_id = news.status.news_id; + + -- if publish_date is not null the item is approved, otherwise it is not + if v_publish_date is not null then + if v_publish_date > sysdate then + -- to be published (2 cases) + -- archive date could be null if it has not been decided when to archive + if v_archive_date is null then + return 'going live in ' || + round(to_char(v_publish_date - sysdate),1) || ' days'; + else + return 'going live in ' || + round(to_char(v_publish_date - sysdate),1) || ' days' || + ', archived in ' || round(to_char(v_archive_date - sysdate),1) || ' days'; + end if; + else + -- already released or even archived (3 cases) + if v_archive_date is null then + return 'published, not scheduled for archive'; + else + if v_archive_date - sysdate > 0 then + return 'published, archived in ' || + round(to_char(v_archive_date - sysdate),1) || ' days'; + else + return 'archived'; + end if; + end if; + end if; + else + return 'unapproved'; + end if; + end status; + + + function name ( + news_id in cr_news.news_id%TYPE + ) return varchar2 + is + news_title varchar2(1000); + begin + select title + into news_title + from cr_revisions + where revision_id = news.name.news_id; + + return news_title; + end name; + + + -- + -- API for Revision management + -- + function revision_new ( + item_id in cr_items.item_id%TYPE, + -- + publish_date in cr_revisions.publish_date%TYPE default null, + text in varchar2 default null, + title in cr_revisions.title%TYPE, + -- + -- here goes the revision log + description in cr_revisions.description%TYPE, + -- + mime_type in cr_revisions.mime_type%TYPE default 'text/plain', + package_id in cr_news.package_id%TYPE default null, + archive_date in cr_news.archive_date%TYPE default null, + approval_user in cr_news.approval_user%TYPE default null, + approval_date in cr_news.approval_date%TYPE default null, + approval_ip in cr_news.approval_ip%TYPE default null, + -- + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_ip in acs_objects.creation_ip%TYPE default null, + creation_user in acs_objects.creation_user%TYPE default null, + -- + make_active_revision_p in varchar2 default 'f' + ) return cr_revisions.revision_id%TYPE + is + v_revision_id integer; + begin + -- create revision + v_revision_id := content_revision.new( + title => title, + description => description, + publish_date => publish_date, + mime_type => mime_type, + text => text, + item_id => item_id, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + -- create new news entry with new revision + insert into cr_news + (news_id, + package_id, + archive_date, + approval_user, + approval_date, + approval_ip) + values + (v_revision_id, + package_id, + archive_date, + approval_user, + approval_date, + approval_ip); + -- make active revision if indicated + if make_active_revision_p = 't' then + news.revision_set_active(v_revision_id); + end if; + return v_revision_id; + end revision_new; + + + + procedure revision_set_active ( + revision_id in cr_revisions.revision_id%TYPE + ) + is + v_news_item_p char; + -- could be used to check if really a 'news' item + begin + update + cr_items + set + live_revision = news.revision_set_active.revision_id, + publish_status = 'ready' + where + item_id = (select + item_id + from + cr_revisions + where + revision_id = news.revision_set_active.revision_id); + end revision_set_active; + + + procedure clone ( + new_package_id in cr_news.package_id%TYPE default null, + old_package_id in cr_news.package_id%TYPE default null + ) + is + new_news_id integer; + begin + for one_news in (select + publish_date, + content.blob_to_string(cr.content) as text, + cr.nls_language, + cr.title as title, + cr.mime_type, + cn.package_id, + archive_date, + approval_user, + approval_date, + approval_ip, + ao.creation_date, + ao.creation_ip, + ao.creation_user + from + cr_items ci, + cr_revisions cr, + cr_news cn, + acs_objects ao + where + (ci.item_id = cr.item_id + and ci.live_revision = cr.revision_id + and cr.revision_id = cn.news_id + and cr.revision_id = ao.object_id) + or (ci.live_revision is null + and ci.item_id = cr.item_id + and cr.revision_id = content_item.get_latest_revision(ci.item_id) + and cr.revision_id = cn.news_id + and cr.revision_id = ao.object_id)) + loop + + new_news_id := news.new( + publish_date => one_news.publish_date, + text => one_news.text, + nls_language => one_news.nls_language, + title => one_news.title, + mime_type => one_news.mime_type, + package_id => news.clone.new_package_id, + archive_date => one_news.archive_date, + approval_user => one_news.approval_user, + approval_date => one_news.approval_date, + approval_ip => one_news.approval_ip, + creation_date => one_news.creation_date, + creation_ip => one_news.creation_ip, + creation_user => one_news.creation_user + ); + + end loop; + end clone; + + -- currently not used, because we want to audit revisions + procedure revision_delete ( + revision_id in cr_revisions.revision_id%TYPE + ) + is + begin + -- delete from cr_news table + delete from cr_news + where news_id = news.revision_delete.revision_id; + -- delete revision + content_revision.del( + revision_id => news.revision_delete.revision_id + ); + end revision_delete; + +end news; +/ +show errors + + + Index: openacs-4/packages/notifications/sql/oracle/upgrade/upgrade-4.6.4-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/notifications/sql/oracle/upgrade/upgrade-4.6.4-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/notifications/sql/oracle/upgrade/upgrade-4.6.4-5.0d1.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,486 @@ + +-- +-- The Notifications Package +-- +-- ben@openforce.net +-- Copyright (C) 2000 MIT +-- +-- GNU GPL v2 +-- + + +-- The Notification Interval Package + +create or replace package notification_interval +as + function new ( + interval_id in notification_intervals.interval_id%TYPE default null, + name in notification_intervals.name%TYPE, + n_seconds in notification_intervals.n_seconds%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_intervals.interval_id%TYPE; + + procedure del ( + interval_id in notification_intervals.interval_id%TYPE + ); + +end notification_interval; +/ +show errors + + + +create or replace package body notification_interval +as + function new ( + interval_id in notification_intervals.interval_id%TYPE default null, + name in notification_intervals.name%TYPE, + n_seconds in notification_intervals.n_seconds%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_intervals.interval_id%TYPE + is + v_interval_id acs_objects.object_id%TYPE; + begin + v_interval_id:= acs_object.new ( + object_id => interval_id, + object_type => 'notification_interval', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notification_intervals + (interval_id, name, n_seconds) values + (v_interval_id, name, n_seconds); + + return v_interval_id; + end new; + + procedure del ( + interval_id in notification_intervals.interval_id%TYPE + ) + is + begin + acs_object.del(interval_id); + end del; + +end notification_interval; +/ +show errors + + +-- The notification delivery methods package + +create or replace package notification_delivery_method +as + function new ( + delivery_method_id in notification_delivery_methods.delivery_method_id%TYPE default null, + sc_impl_id in notification_delivery_methods.sc_impl_id%TYPE, + short_name in notification_delivery_methods.short_name%TYPE, + pretty_name in notification_delivery_methods.pretty_name%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_delivery_methods.delivery_method_id%TYPE; + + procedure del ( + delivery_method_id in notification_delivery_methods.delivery_method_id%TYPE + ); + +end notification_delivery_method; +/ +show errors + + + +create or replace package body notification_delivery_method +as + function new ( + delivery_method_id in notification_delivery_methods.delivery_method_id%TYPE default null, + sc_impl_id in notification_delivery_methods.sc_impl_id%TYPE, + short_name in notification_delivery_methods.short_name%TYPE, + pretty_name in notification_delivery_methods.pretty_name%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_delivery_methods.delivery_method_id%TYPE + is + v_delivery_method_id acs_objects.object_id%TYPE; + begin + v_delivery_method_id := acs_object.new ( + object_id => delivery_method_id, + object_type => 'notification_delivery_method', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notification_delivery_methods + (delivery_method_id, sc_impl_id, short_name, pretty_name) values + (v_delivery_method_id, sc_impl_id, short_name, pretty_name); + + return v_delivery_method_id; + end new; + + procedure del ( + delivery_method_id in notification_delivery_methods.delivery_method_id%TYPE + ) + is + begin + acs_object.del (delivery_method_id); + end del; + +end notification_delivery_method; +/ +show errors + + + +-- Notification Types Package +create or replace package notification_type +as + function new ( + type_id in notification_types.type_id%TYPE default null, + sc_impl_id in notification_types.sc_impl_id%TYPE, + short_name in notification_types.short_name%TYPE, + pretty_name in notification_types.pretty_name%TYPE, + description in notification_types.description%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_types.type_id%TYPE; + + procedure del ( + type_id in notification_types.type_id%TYPE default null + ); + +end notification_type; +/ +show errors + + + +create or replace package body notification_type +as + function new ( + type_id in notification_types.type_id%TYPE default null, + sc_impl_id in notification_types.sc_impl_id%TYPE, + short_name in notification_types.short_name%TYPE, + pretty_name in notification_types.pretty_name%TYPE, + description in notification_types.description%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_types.type_id%TYPE + is + v_type_id acs_objects.object_id%TYPE; + begin + v_type_id := acs_object.new ( + object_id => type_id, + object_type => 'notification_type', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notification_types + (type_id, sc_impl_id, short_name, pretty_name, description) values + (v_type_id, sc_impl_id, short_name, pretty_name, description); + + return v_type_id; + end new; + + procedure del ( + type_id in notification_types.type_id%TYPE default null + ) + is + begin + acs_object.del(type_id); + end del; + +end notification_type; +/ +show errors + + + +-- the notification request package + +create or replace package notification_request +as + function new ( + request_id in notification_requests.request_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'notification_request', + type_id in notification_requests.type_id%TYPE, + user_id in notification_requests.user_id%TYPE, + object_id in notification_requests.object_id%TYPE, + interval_id in notification_requests.interval_id%TYPE, + delivery_method_id in notification_requests.delivery_method_id%TYPE, + format in notification_requests.format%TYPE, + dynamic_p in notification_requests.dynamic_p%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_requests.request_id%TYPE; + + procedure del ( + request_id in notification_requests.request_id%TYPE default null + ); + + procedure delete_all ( + object_id in notification_requests.object_id%TYPE default null + ); +end notification_request; +/ +show errors + +create or replace package body notification_request +as + function new ( + request_id in notification_requests.request_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'notification_request', + type_id in notification_requests.type_id%TYPE, + user_id in notification_requests.user_id%TYPE, + object_id in notification_requests.object_id%TYPE, + interval_id in notification_requests.interval_id%TYPE, + delivery_method_id in notification_requests.delivery_method_id%TYPE, + format in notification_requests.format%TYPE, + dynamic_p in notification_requests.dynamic_p%TYPE, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notification_requests.request_id%TYPE + is + v_request_id acs_objects.object_id%TYPE; + begin + v_request_id := acs_object.new ( + object_id => request_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notification_requests + (request_id, type_id, user_id, object_id, interval_id, delivery_method_id, format, dynamic_p) values + (v_request_id, type_id, user_id, object_id, interval_id, delivery_method_id, format, dynamic_p); + + return v_request_id; + end new; + + procedure del ( + request_id in notification_requests.request_id%TYPE default null + ) + is + begin + for v_notifications in (select notification_id + from notifications n, notification_requests nr + where n.response_id = nr.object_id + and nr.request_id = request_id) + loop + acs_object.del(v_notifications.notification_id); + end loop; + acs_object.del(request_id); + end del; + + procedure delete_all ( + object_id in notification_requests.object_id%TYPE default null + ) + is + v_request notification_requests%ROWTYPE; + begin + for v_request in + (select request_id from notification_requests where object_id= delete_all.object_id) + LOOP + notification_request.del(v_request.request_id); + END LOOP; + end delete_all; + +end notification_request; +/ +show errors + + + + + +-- the notifications package +create or replace package notification +as + + function new ( + notification_id in notifications.notification_id%TYPE default null, + type_id in notifications.type_id%TYPE, + object_id in notifications.object_id%TYPE, + notif_date in notifications.notif_date%TYPE default sysdate, + response_id in notifications.response_id%TYPE default null, + notif_user in notifications.notif_user%TYPE default null, + notif_subject in notifications.notif_subject%TYPE default null, + notif_text in varchar default null, + notif_html in varchar default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notifications.notification_id%TYPE; + + procedure del ( + notification_id in notifications.notification_id%TYPE default null + ); + +end notification; +/ +show errors + + + +create or replace package body notification +as + + function new ( + notification_id in notifications.notification_id%TYPE default null, + type_id in notifications.type_id%TYPE, + object_id in notifications.object_id%TYPE, + notif_date in notifications.notif_date%TYPE default sysdate, + response_id in notifications.response_id%TYPE default null, + notif_user in notifications.notif_user%TYPE default null, + notif_subject in notifications.notif_subject%TYPE default null, + notif_text in varchar default null, + notif_html in varchar default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE default null + ) return notifications.notification_id%TYPE + is + v_notification_id acs_objects.object_id%TYPE; + begin + v_notification_id := acs_object.new ( + object_id => notification_id, + object_type => 'notification', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notifications + (notification_id, type_id, object_id, notif_date, response_id, notif_user, notif_subject, notif_text, notif_html) + values + (v_notification_id, type_id, object_id, notif_date, response_id, notif_user, notif_subject, notif_text, notif_html); + + return v_notification_id; + end new; + + procedure del ( + notification_id in notifications.notification_id%TYPE default null + ) + is + begin + delete from notifications where notification_id = notification.del.notification_id; + + acs_object.del (notification_id); + end del; + +end notification; +/ +show errors + +-- +-- The Notifications Package +-- +-- ben@openforce.net +-- Copyright (C) 2000 MIT +-- +-- GNU GPL v2 +-- + + +-- The Notification Replies Package + +create or replace package notification_reply +as + function new ( + reply_id in notification_replies.reply_id%TYPE default null, + object_id in notification_replies.object_id%TYPE, + type_id in notification_replies.type_id%TYPE, + from_user in notification_replies.from_user%TYPE, + subject in notification_replies.subject%TYPE, + content in varchar, + reply_date in notification_replies.reply_date%TYPE default sysdate, + 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, + context_id in acs_objects.context_id%TYPE default null + ) return notification_replies.reply_id%TYPE; + + procedure del ( + reply_id in notification_replies.reply_id%TYPE + ); +end notification_reply; +/ +show errors + + +create or replace package body notification_reply +as + function new ( + reply_id in notification_replies.reply_id%TYPE default null, + object_id in notification_replies.object_id%TYPE, + type_id in notification_replies.type_id%TYPE, + from_user in notification_replies.from_user%TYPE, + subject in notification_replies.subject%TYPE, + content in varchar, + reply_date in notification_replies.reply_date%TYPE default sysdate, + 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, + context_id in acs_objects.context_id%TYPE default null + ) return notification_replies.reply_id%TYPE + is + v_reply_id acs_objects.object_id%TYPE; + begin + v_reply_id:= acs_object.new ( + object_id => reply_id, + object_type => 'notification_reply', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into notification_replies + (reply_id, object_id, type_id, from_user, subject, content, reply_date) + values + (v_reply_id, object_id, type_id, from_user, subject, content, reply_date); + + return v_reply_id; + end new; + + procedure del ( + reply_id in notification_replies.reply_id%TYPE + ) + is + begin + acs_object.del(object_id => reply_id); + end del; + +end notification_reply; +/ +show errors Index: openacs-4/packages/photo-album/sql/oracle/upgrade/upgrade-4.6.0-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/photo-album/sql/oracle/upgrade/upgrade-4.6.0-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/photo-album/sql/oracle/upgrade/upgrade-4.6.0-5.0d1.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,524 @@ +-- /packages/photo-album/sql/postgresql/photo-album-clip.sql +-- +-- + +create or replace package pa_collection +as + function new ( + p_collection_id in pa_collections.collection_id%TYPE default null, + p_owner_id in pa_collections.owner_id%TYPE default null, + p_title in pa_collections.title%TYPE, + p_creation_date in acs_objects.creation_date%TYPE default sysdate, + p_creation_user in acs_objects.creation_user%TYPE default null, + p_creation_ip in acs_objects.creation_ip%TYPE default null, + p_context_id in acs_objects.context_id%TYPE default null + ) return pa_collections.collection_id%TYPE; + + procedure del ( + p_collection_id in pa_collections.collection_id%TYPE + ); + + function title ( + p_collection_id in pa_collections.collection_id%TYPE + ) return pa_collections.title%TYPE; + +end pa_collection; +/ +show errors + +create or replace package body pa_collection +as + function new ( + p_collection_id in pa_collections.collection_id%TYPE default null, + p_owner_id in pa_collections.owner_id%TYPE default null, + p_title in pa_collections.title%TYPE, + p_creation_date in acs_objects.creation_date%TYPE default sysdate, + p_creation_user in acs_objects.creation_user%TYPE default null, + p_creation_ip in acs_objects.creation_ip%TYPE default null, + p_context_id in acs_objects.context_id%TYPE default null + ) return pa_collections.collection_id%TYPE + is + v_collection_id pa_collections.collection_id%TYPE; + begin + v_collection_id := acs_object.new ( + object_id => p_collection_id, + object_type => 'photo_collection', + creation_date => p_creation_date, + creation_user => p_creation_user, + creation_ip => p_creation_ip, + context_id => p_context_id + ); + + insert into pa_collections + (collection_id, owner_id, title) + values + (v_collection_id, p_owner_id, p_title); + + acs_permission.grant_permission ( + v_collection_id, + p_owner_id, + 'admin' + ); + + return v_collection_id; + end new; + + + procedure del ( + p_collection_id in pa_collections.collection_id%TYPE + ) + is + begin + delete from acs_permissions + where object_id = p_collection_id; + + delete from pa_collections + where collection_id = p_collection_id; + + acs_object.del(p_collection_id); + end del; + + + function title ( + p_collection_id in pa_collections.collection_id%TYPE + ) return pa_collections.title%TYPE + is + v_title pa_collections.title%TYPE; + begin + select title into v_title + from pa_collections + where collection_id = p_collection_id; + return v_title; + end title; + +end pa_collection; +/ +show errors; + +-- /packages/photo-album/sql/plsql-packages.sql +-- +-- packages to support ACS photo ablum application +-- + +create or replace package pa_photo +as + --/** + -- creates new pa_photo + -- associated images must be created by calling script + --*/ + function new ( + name in cr_items.name%TYPE, + parent_id in cr_items.parent_id%TYPE default null, + item_id in acs_objects.object_id%TYPE default null, + revision_id in acs_objects.object_id%TYPE default null, + content_type in acs_object_types.object_type%TYPE default 'pa_photo', + 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, + locale in cr_items.locale%TYPE default null, + context_id in acs_objects.context_id%TYPE default null, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + relation_tag in cr_child_rels.relation_tag%TYPE default null, + is_live in char default 'f', + publish_date in cr_revisions.publish_date%TYPE default sysdate, + mime_type in cr_revisions.mime_type%TYPE default null, + nls_language in cr_revisions.nls_language%TYPE default null, + caption in pa_photos.caption%TYPE default null, + story in pa_photos.story%TYPE default null + ) return cr_items.item_id%TYPE; + + --/** + -- Deletes a single revision of a pa_photo + --*/ + procedure delete_revision ( + revision_id in acs_objects.object_id%TYPE + ); + + --/** + -- Deletes a a pa_photo and all revisions, + -- Deletes associated images (which schedules binary files for deleation) + -- + -- Be careful, cannot be undone (easily) + --*/ + procedure del ( + item_id in acs_objects.object_id%TYPE + ); + +end pa_photo; +/ +show errors; + +create or replace package body pa_photo +as + function new ( + name in cr_items.name%TYPE, + parent_id in cr_items.parent_id%TYPE default null, + item_id in acs_objects.object_id%TYPE default null, + revision_id in acs_objects.object_id%TYPE default null, + content_type in acs_object_types.object_type%TYPE default 'pa_photo', + 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, + locale in cr_items.locale%TYPE default null, + context_id in acs_objects.context_id%TYPE default null, + title in cr_revisions.title%TYPE default 'photo', + description in cr_revisions.description%TYPE default null, + relation_tag in cr_child_rels.relation_tag%TYPE default null, + is_live in char default 'f', + publish_date in cr_revisions.publish_date%TYPE default sysdate, + mime_type in cr_revisions.mime_type%TYPE default null, + nls_language in cr_revisions.nls_language%TYPE default null, + caption in pa_photos.caption%TYPE default null, + story in pa_photos.story%TYPE default null + ) return cr_items.item_id%TYPE + is + v_item_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + begin + + v_item_id := content_item.new ( + name => name, + item_id => item_id, + parent_id => parent_id, + relation_tag => relation_tag, + content_type => content_type, + creation_date => sysdate, + creation_user => creation_user, + creation_ip => creation_ip, + locale => locale, + context_id => context_id + ); + + v_revision_id := content_revision.new ( + title => title, + description => description, + item_id => v_item_id, + revision_id => revision_id, + publish_date => publish_date, + mime_type => mime_type, + nls_language => nls_language, + creation_date => sysdate, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into pa_photos + (pa_photo_id, caption, story, user_filename) + values + (v_revision_id, caption, story, title); + + -- is_live => 't' not used as part of content_item.new + -- because content_item.new does not let developer specify revision_id and doesn't return revision_id, + -- revision_id needed for the insert to pa_photos + + if is_live = 't' then + content_item.set_live_revision ( + revision_id => v_revision_id + ); + end if; + + return v_item_id; + end new; + + procedure delete_revision ( + revision_id in acs_objects.object_id%TYPE + ) + is + + -- do not need to delete from the pa_photos + -- the on delete cascade will take care of this + -- during the content_revision.delete + begin + content_revision.del ( + revision_id => revision_id + ); + + end delete_revision; + + procedure del ( + item_id in acs_objects.object_id%TYPE + ) + is + cursor pa_image_cur is + select + child_id + from + cr_child_rels + where + parent_id = pa_photo.del.item_id; + + begin + + -- delete all the images associated with the photo + for v_pa_image_val in pa_image_cur loop + image.del ( + item_id => v_pa_image_val.child_id + ); + end loop; + + -- content_item.delete takes care of all revision + -- on delete cascades take care of rest + + content_item.del ( + item_id => item_id + ); + + end del; + +end pa_photo; +/ +show errors + + +create or replace package pa_album +as + --/** + -- Creates a new pa_album + --*/ + function new ( + name in cr_items.name%TYPE, + album_id in cr_items.item_id%TYPE default null, + parent_id in cr_items.parent_id%TYPE default null, + is_live in char default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + story in pa_albums.story%TYPE default null, + photographer in pa_albums.photographer%TYPE default null, + revision_id in cr_revisions.revision_id%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + locale in cr_items.locale%TYPE default null, + context_id in acs_objects.context_id%TYPE default null, + publish_date in cr_revisions.publish_date%TYPE default sysdate, + nls_language in cr_revisions.nls_language%TYPE default null, + content_type in acs_object_types.object_type%TYPE default 'pa_album', + relation_tag in cr_child_rels.relation_tag%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default null + ) return cr_items.item_id%TYPE; + + --/** + -- Deletes a single revision of a pa_album + --*/ + procedure delete_revision ( + revision_id in cr_revisions.revision_id%TYPE + ); + + --/** + -- Deletes a pa_album and all revisions + -- Album must be empty to be deleted, + -- otherwise delete throws error + --*/ + procedure del ( + album_id in cr_items.item_id%TYPE + ); + +end pa_album; +/ +show errors + +create or replace package body pa_album +as + function new ( + name in cr_items.name%TYPE, + album_id in cr_items.item_id%TYPE default null, + parent_id in cr_items.parent_id%TYPE default null, + is_live in char default 'f', + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null, + title in cr_revisions.title%TYPE default null, + description in cr_revisions.description%TYPE default null, + story in pa_albums.story%TYPE default null, + photographer in pa_albums.photographer%TYPE default null, + revision_id in cr_revisions.revision_id%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + locale in cr_items.locale%TYPE default null, + context_id in acs_objects.context_id%TYPE default null, + publish_date in cr_revisions.publish_date%TYPE default sysdate, + nls_language in cr_revisions.nls_language%TYPE default null, + content_type in acs_object_types.object_type%TYPE default 'pa_album', + relation_tag in cr_child_rels.relation_tag%TYPE default null, + mime_type in cr_revisions.mime_type%TYPE default null + ) return cr_items.item_id%TYPE + is + v_item_id integer; + v_revision_id integer; + begin + v_item_id := content_item.new ( + name => name, + item_id => album_id, + parent_id => parent_id, + relation_tag => relation_tag, + content_type => content_type, + creation_date => sysdate, + creation_user => creation_user, + creation_ip => creation_ip, + locale => locale, + context_id => context_id + ); + + v_revision_id := content_revision.new ( + title => title, + description => description, + item_id => v_item_id, + revision_id => revision_id, + publish_date => publish_date, + mime_type => mime_type, + nls_language => nls_language, + creation_date => sysdate, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert into pa_albums (pa_album_id, story, photographer) + values + (v_revision_id, story, photographer); + + if is_live = 't' then + content_item.set_live_revision ( + revision_id => v_revision_id + ); + end if; + + return v_item_id; + + end new; + + procedure delete_revision ( + revision_id in cr_revisions.revision_id%TYPE + ) + is + -- do not need to delete from the pa_albums + -- the on delete cascade will take care of this + -- during the content_revision.delete + begin + content_revision.del ( + revision_id => revision_id + ); + + end delete_revision; + + procedure del ( + album_id in cr_items.item_id%TYPE + ) + is + v_num_children integer; + begin + -- check if album is empty (no rm -r *) + select count(*) into v_num_children + from cr_items + where parent_id = pa_album.del.album_id; + + if v_num_children > 0 then + raise_application_error(-20000, + 'The specified album ' || album_id || ' still contains photos. + An album must be empty before it can be deleted.'); + end if; + + -- content_item.delete takes care of all revision + -- on delete cascades take care of rest + + content_item.del ( + item_id => album_id + ); + + end del; + +end pa_album; +/ +show errors + +--/** +-- Package does not contain new or delete procedure because +-- it contains general funcition for the photo album application +-- and is not tied to a specific object. +--*/ +create or replace package photo_album +as + + --/** + -- Returns the root folder corresponding to a package instance. + -- If root folder does not already exist, function returns null + -- + -- tcl proc that calls this function from the index page + -- takes care of the case that there is no root folder (new package instance) + -- and creates one with appropriate permissions + --*/ + + function get_root_folder ( + package_id in apm_packages.package_id%TYPE + ) return pa_package_root_folder_map.folder_id%TYPE; + + -- wtem@olywa.net, 2001-09-22 + -- wrapped up some pl-sql from tcl/photo-album-procs.tcl.pa_new_root_folder + function new_root_folder ( + package_id in apm_packages.package_id%TYPE + ) return pa_package_root_folder_map.folder_id%TYPE; + +end photo_album; +/ +show errors + +create or replace package body photo_album +as + + function get_root_folder ( + package_id in apm_packages.package_id%TYPE + ) return pa_package_root_folder_map.folder_id%TYPE + is + v_folder_id pa_package_root_folder_map.folder_id%TYPE; + begin + + -- this uses 0 as a magic number for + -- no root folder + -- in acs there will never be a folder with id 0 + + select nvl(folder_id,0) into v_folder_id + from pa_package_root_folder_map + where package_id = get_root_folder.package_id; + + if v_folder_id > 0 then + return v_folder_id; + else + return null; + end if; + + end get_root_folder; + + function new_root_folder ( + package_id in apm_packages.package_id%TYPE + ) return pa_package_root_folder_map.folder_id%TYPE + is + v_folder_id pa_package_root_folder_map.folder_id%TYPE; + v_package_name apm_packages.instance_name%TYPE; + v_package_key apm_packages.package_key%TYPE; + begin + + select instance_name, package_key + into v_package_name, v_package_key + from apm_packages + where package_id = new_root_folder.package_id; + + v_folder_id := content_folder.new ( + name => v_package_key || '_' || new_root_folder.package_id, + label => v_package_name || ' Home', + description => 'Home for ' || v_package_name, + context_id => new_root_folder.package_id + ); + + insert into pa_package_root_folder_map + (package_id, folder_id) + values + (new_root_folder.package_id, v_folder_id); + + -- allow child items to be added + content_folder.register_content_type(v_folder_id,'pa_album'); + content_folder.register_content_type(v_folder_id,'content_folder'); + + return v_folder_id; + end new_root_folder; + +end photo_album; +/ +show errors Index: openacs-4/packages/ref-timezones/sql/oracle/upgrade/upgrade-0.3-0.4d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/ref-timezones/sql/oracle/upgrade/upgrade-0.3-0.4d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/ref-timezones/sql/oracle/upgrade/upgrade-0.3-0.4d1.sql 8 Oct 2003 16:53:46 -0000 1.1 @@ -0,0 +1,341 @@ +-- packages/ref-timezones/sql/oracle/ref-timezones-create.sql +-- +-- This package provides both the reference data for timezones and an +-- API for doing simple operations on timezones. The data provided is +-- a combination of the NIH timezone database and the Unix zoneinfo +-- database (conversion rules). +-- +-- @author jon@jongriffin.com +-- @author ron@arsdigita.com +-- @creation-date 2000-11-30 +-- @cvs-id $Id: upgrade-0.3-0.4d1.sql,v 1.1 2003/10/08 16:53:46 mohanp Exp $ + +------------------------------------------------------------------------------- +-- TimeZone package +------------------------------------------------------------------------------- + +create or replace package timezone +as +-- deprecated + procedure new ( + tz in timezones.tz%TYPE, + gmt_offset in timezones.gmt_offset%type + ); + + procedure del ( + tz_id in timezones.tz_id%TYPE + ); + + function get_id ( + -- Gets the ID number of the given timezone + tz in timezones.tz%TYPE + ) return integer; + + procedure add_rule ( + -- Adds a new conversion rule to the timezone_rules database + tz in timezones.tz%TYPE, + abbrev in timezone_rules.abbrev%TYPE, + isdst in integer, + gmt_offset in integer, + utc_start in varchar, + utc_end in varchar, + local_start in varchar, + local_end in varchar + ); + + -- The following are the primary time conversion functions + + function utc_to_local ( + -- Returns utc_time converted to local time + tz_id in timezones.tz_id%TYPE, + utc_time in date + ) return date; + + function local_to_utc ( + tz_id in timezones.tz_id%TYPE, + local_time in date + ) return date; + + -- The following provide access to the current offset information + + function get_offset ( + -- Gets the timezone offset in seconds, for the current date, + -- modified in case of DST. + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return integer; + + function get_rawoffset ( + -- Gets the timezone offset NOT modified for DST + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return integer; + + function get_abbrev ( + -- Returns abbreviation for the coversion rule + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return varchar; + + function get_zone_offset ( + -- Returns the relative offset between two zones at a + -- particular UTC time. + tz_this in timezones.tz_id%TYPE, + tz_other in timezones.tz_id%TYPE, + utc_time in date default sysdate + ) return integer; + + -- Access to flags + + function isdst_p ( + -- Returns 't' if timezone is currently using DST + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return char; + + -- Special formatting functions + + function get_date ( + -- Returns a formatted date with timezone info appended + tz_id in timezones.tz_id%TYPE, + local_time in date, + format in varchar default 'yyyy-mm-ss hh24:mi:ss', + append_timezone_p in char default 't' + ) return varchar; + +end timezone; +/ +show errors + +-- +-- +-- + +create or replace package body timezone +as + procedure new ( + tz in timezones.tz%TYPE, + gmt_offset in timezones.gmt_offset%type + ) + is + begin + insert into timezones + (tz_id, tz, gmt_offset) + values + (timezone_seq.nextval, tz, gmt_offset); + end; + + procedure del ( + tz_id in timezones.tz_id%TYPE + ) + is + begin + delete from timezone_rules where tz_id = tz_id; + delete from timezones where tz_id = tz_id; + end; + + -- private function for looking up timezone id's + + function get_id ( + tz in timezones.tz%TYPE + ) return integer + is + tz_id integer; + begin + select tz_id into tz_id + from timezones + where tz = get_id.tz; + + return tz_id; + end; + + procedure add_rule ( + tz in timezones.tz%TYPE, + abbrev in timezone_rules.abbrev%TYPE, + isdst in integer, + gmt_offset in integer, + utc_start in varchar, + utc_end in varchar, + local_start in varchar, + local_end in varchar + ) + is + begin + insert into timezone_rules + (tz_id, + abbrev, + utc_start, + utc_end, + local_start, + local_end, + gmt_offset, + isdst) + values + (get_id(tz), + abbrev, + to_date(utc_start,'Mon dd hh24:mi:ss yyyy'), + to_date(utc_end, 'Mon dd hh24:mi:ss yyyy'), + to_date(local_start,'Mon dd hh24:mi:ss yyyy'), + to_date(local_end,'Mon dd hh24:mi:ss yyyy'), + gmt_offset, + decode(isdst,0,'f',1,'t')); + end; + + function utc_to_local ( + tz_id in timezones.tz_id%TYPE, + utc_time in date + ) return date + is + local_time date; + begin + select utc_time + gmt_offset/86400 into local_time + from timezone_rules + where tz_id = utc_to_local.tz_id + and utc_time between utc_start and utc_end + and rownum = 1; + + return local_time; + exception + when no_data_found then + return utc_time; + end utc_to_local; + + function local_to_utc ( + tz_id in timezones.tz_id%TYPE, + local_time in date + ) return date + is + utc_time date; + begin + select local_time - gmt_offset/86400 into utc_time + from timezone_rules + where tz_id = local_to_utc.tz_id + and local_time between local_start and local_end + and rownum = 1; + + return utc_time; + exception + when no_data_found then + return local_time; + end; + + function get_offset ( + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return integer + is + v_offset integer; + begin + select gmt_offset into v_offset + from timezone_rules + where tz_id = get_offset.tz_id + and local_time between local_start and local_end + and rownum = 1; + + return v_offset; + exception + when no_data_found then + return 0; + end; + + function get_rawoffset ( + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return integer + is + v_offset number; + begin + select decode (isdst,'t', gmt_offset - 3600, + 'f', gmt_offset) into v_offset + from timezone_rules + where tz_id = get_rawoffset.tz_id + and local_time between local_start and local_end + and rownum = 1; + + return v_offset; + exception + when no_data_found then + return 0; + end; + + function get_abbrev ( + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return varchar + is + v_abbrev timezone_rules.abbrev%TYPE; + begin + select abbrev into v_abbrev + from timezone_rules + where tz_id = get_abbrev.tz_id + and local_time between local_start and local_end; + + return v_abbrev; + exception + when no_data_found then + return 'GMT'; + end; + + function get_date ( + -- Returns a formatted date with timezone info appended + tz_id in timezones.tz_id%TYPE, + local_time in date, + format in varchar default 'yyyy-mm-ss hh24:mi:ss', + append_timezone_p in char default 't' + ) return varchar + is + v_date varchar(1000); + begin + if append_timezone_p = 't' then + select to_char(local_time,format) || ' ' || abbrev into v_date + from timezone_rules + where tz_id = get_date.tz_id + and local_time between local_start and local_end + and rownum = 1; + else + select to_char(local_time,format) into v_date + from dual; + end if; + + return v_date; + exception + when no_data_found then + select to_char(local_time,format) into v_date from dual; + return v_date; + end; + + function isdst_p ( + -- Returns 't' if timezone is currently using DST + tz_id in timezones.tz_id%TYPE, + local_time in date default sysdate + ) return char + is + v_isdst char; + begin + select isdst into v_isdst + from timezone_rules + where tz_id = isdst_p.tz_id + and local_time between local_start and local_end + and rownum = 1; + + return v_isdst; + exception + when no_data_found then + return 'f'; + end; + + function get_zone_offset ( + tz_this in timezones.tz_id%TYPE, + tz_other in timezones.tz_id%TYPE, + utc_time in date default sysdate + ) return integer + is + begin + return get_offset(tz_this, utc_to_local(tz_this, utc_time)) - + get_offset(tz_other,utc_to_local(tz_other,utc_time)); + end; + +end timezone; +/ +show errors + Index: openacs-4/packages/simple-survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/simple-survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/simple-survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql 8 Oct 2003 16:54:36 -0000 1.1 @@ -0,0 +1,232 @@ +create or replace package survsimp_survey +as + function new ( + survey_id in survsimp_surveys.survey_id%TYPE default null, + name in survsimp_surveys.name%TYPE, + short_name in survsimp_surveys.short_name%TYPE, + description in survsimp_surveys.description%TYPE, + description_html_p in survsimp_surveys.description_html_p%TYPE default 'f', + single_response_p in survsimp_surveys.single_response_p%TYPE default 'f', + single_editable_p in survsimp_surveys.single_editable_p%TYPE default 't', + enabled_p in survsimp_surveys.enabled_p%TYPE default 'f', + type in survsimp_surveys.type%TYPE default 'general', + display_type in survsimp_surveys.display_type%TYPE default 'list', + package_id in survsimp_surveys.package_id%TYPE, + object_type in acs_objects.object_type%TYPE default 'survsimp_survey', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + survey_id in survsimp_surveys.survey_id%TYPE + ); +end survsimp_survey; +/ +show errors + +create or replace package body survsimp_survey +as + function new ( + survey_id in survsimp_surveys.survey_id%TYPE default null, + name in survsimp_surveys.name%TYPE, + short_name in survsimp_surveys.short_name%TYPE, + description in survsimp_surveys.description%TYPE, + description_html_p in survsimp_surveys.description_html_p%TYPE default 'f', + single_response_p in survsimp_surveys.single_response_p%TYPE default 'f', + single_editable_p in survsimp_surveys.single_editable_p%TYPE default 't', + enabled_p in survsimp_surveys.enabled_p%TYPE default 'f', + type in survsimp_surveys.type%TYPE default 'general', + display_type in survsimp_surveys.display_type%TYPE default 'list', + package_id in survsimp_surveys.package_id%TYPE, + object_type in acs_objects.object_type%TYPE default 'survsimp_survey', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_survey_id survsimp_surveys.survey_id%TYPE; + begin + v_survey_id := acs_object.new ( + object_id => survey_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into survsimp_surveys + (survey_id, name, short_name, description, description_html_p, + single_response_p, single_editable_p, enabled_p, type, display_type, package_id) + values + (v_survey_id, new.name, new.short_name, new.description, new.description_html_p, + new.single_response_p, new.single_editable_p, new.enabled_p, new.type, new.display_type, new.package_id); + + return v_survey_id; + end new; + + procedure del ( + survey_id survsimp_surveys.survey_id%TYPE + ) + is + begin + delete from survsimp_surveys + where survey_id = survsimp_survey.del.survey_id; + acs_object.del(survey_id); + end del; +end survsimp_survey; +/ +show errors + +-- +-- constructor for a survsimp_question +-- +create or replace package survsimp_question +as + function new ( + question_id in survsimp_questions.question_id%TYPE default null, + survey_id in survsimp_questions.survey_id%TYPE default null, + sort_key in survsimp_questions.sort_key%TYPE default null, + question_text in survsimp_questions.question_text%TYPE default null, + abstract_data_type in survsimp_questions.abstract_data_type%TYPE default null, + required_p in survsimp_questions.required_p%TYPE default 't', + active_p in survsimp_questions.active_p%TYPE default 't', + presentation_type in survsimp_questions.presentation_type%TYPE default null, + presentation_options in survsimp_questions.presentation_options%TYPE default null, + presentation_alignment in survsimp_questions.presentation_alignment%TYPE default 'below', + object_type in acs_objects.object_type%TYPE default 'survsimp_question', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + question_id in survsimp_questions.question_id%TYPE + ); +end survsimp_question; +/ +show errors + +create or replace package body survsimp_question +as + function new ( + question_id in survsimp_questions.question_id%TYPE default null, + survey_id in survsimp_questions.survey_id%TYPE default null, + sort_key in survsimp_questions.sort_key%TYPE default null, + question_text in survsimp_questions.question_text%TYPE default null, + abstract_data_type in survsimp_questions.abstract_data_type%TYPE default null, + required_p in survsimp_questions.required_p%TYPE default 't', + active_p in survsimp_questions.active_p%TYPE default 't', + presentation_type in survsimp_questions.presentation_type%TYPE default null, + presentation_options in survsimp_questions.presentation_options%TYPE default null, + presentation_alignment in survsimp_questions.presentation_alignment%TYPE default 'below', + object_type in acs_objects.object_type%TYPE default 'survsimp_question', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_question_id survsimp_questions.question_id%TYPE; + begin + v_question_id := acs_object.new ( + object_id => question_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => survey_id + ); + insert into survsimp_questions + (question_id, survey_id, sort_key, question_text, abstract_data_type, + required_p, active_p, presentation_type, presentation_options, + presentation_alignment) + values + (v_question_id, new.survey_id, new.sort_key, new.question_text, new.abstract_data_type, + new.required_p, new.active_p, new.presentation_type, new.presentation_options, + new.presentation_alignment); + return v_question_id; + end new; + + procedure del ( + question_id in survsimp_questions.question_id%TYPE + ) + is + begin + delete from survsimp_questions + where question_id = survsimp_question.del.question_id; + acs_object.del(question_id); + end del; +end survsimp_question; +/ +show errors + +-- +-- constructor for a survsimp_response +-- +create or replace package survsimp_response +as + function new ( + response_id in survsimp_responses.response_id %TYPE default null, + survey_id in survsimp_responses.survey_id%TYPE default null, + title in survsimp_responses.title%TYPE default null, + notify_on_comment_p in survsimp_responses.notify_on_comment_p%TYPE default 'f', + object_type in acs_objects.object_type%TYPE default 'survsimp_response', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure del ( + response_id in survsimp_responses.response_id%TYPE + ); +end survsimp_response; +/ +show errors + +create or replace package body survsimp_response +as + function new ( + response_id in survsimp_responses.response_id %TYPE default null, + survey_id in survsimp_responses.survey_id%TYPE default null, + title in survsimp_responses.title%TYPE default null, + notify_on_comment_p in survsimp_responses.notify_on_comment_p%TYPE default 'f', + object_type in acs_objects.object_type%TYPE default 'survsimp_response', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_response_id survsimp_responses.response_id%TYPE; + begin + v_response_id := acs_object.new ( + object_id => response_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into survsimp_responses (response_id, survey_id, title, notify_on_comment_p) + values + (v_response_id, new.survey_id, new.title, new.notify_on_comment_p); + return v_response_id; + end new; + + procedure del ( + response_id in survsimp_responses.response_id%TYPE + ) + is + begin + delete from survsimp_responses + where response_id = survsimp_response.del.response_id; + acs_object.del(response_id); + end del; +end survsimp_response; +/ +show errors Index: openacs-4/packages/static-pages/sql/oracle/upgrade/upgrade-4.3-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/static-pages/sql/oracle/upgrade/upgrade-4.3-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/static-pages/sql/oracle/upgrade/upgrade-4.3-5.0d1.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,605 @@ +-- packages/static-pages/sql/oracle/static-page-ph.sql +-- Package header ONLY. +-- @cvs-id $Id: upgrade-4.3-5.0d1.sql,v 1.1 2003/10/08 16:59:23 mohanp Exp $ +-- @author Brandoch Calef (bcalef@arsdigita.com) + + +create or replace package static_page as + function new ( + -- /** + -- * Creates a new content_item and content_revision for a + -- * static page. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-02 + -- **/ + static_page_id in static_pages.static_page_id%TYPE + default null, + folder_id in sp_folders.folder_id%TYPE, + filename in static_pages.filename%TYPE default null, + title in cr_revisions.title%TYPE default null, + content in cr_revisions.content%TYPE default null, + show_comments_p in static_pages.show_comments_p%TYPE default 't', + 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, + context_id in acs_objects.context_id%TYPE + default null + ,mime_type in cr_revisions.mime_type%TYPE default 'text/html' + ) return static_pages.static_page_id%TYPE; + + procedure del ( + -- /** + -- * Delete a static page, including the associated content_item. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-02 + -- **/ + static_page_id in static_pages.static_page_id%TYPE + ); + + function get_root_folder ( + -- /** + -- * Returns the id of the root folder belonging to this package. + -- * If none exists, one is created. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-22 + -- **/ + package_id in apm_packages.package_id%TYPE + ) return sp_folders.folder_id%TYPE; + + function new_folder ( + -- /** + -- * Create a folder in the content_repository to hold files in + -- * a particular directory. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-02 + -- **/ + folder_id in sp_folders.folder_id%TYPE + default null, + name in cr_items.name%TYPE, + label in cr_folders.label%TYPE, + description in cr_folders.description%TYPE default null, + parent_id in cr_items.parent_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, + context_id in acs_objects.context_id%TYPE + default null + ) return sp_folders.folder_id%TYPE; + + procedure delete_folder ( + -- /** + -- * Delete a folder and all the folders and files it contains. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-02 + -- **/ + folder_id in sp_folders.folder_id%TYPE + ); + + procedure delete_stale_items ( + -- /** + -- * Delete items that are in the content repository but not in + -- * extant_files/extant_folders with the given session_id. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-02 + -- **/ + session_id in sp_extant_files.session_id%TYPE, + package_id in apm_packages.package_id%TYPE + ); + + procedure grant_permission ( + -- /** + -- * Grant a privilege on a file or folder, perhaps recursively. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-21 + -- **/ + item_id in acs_permissions.object_id%TYPE, + grantee_id in acs_permissions.grantee_id%TYPE, + privilege in acs_permissions.privilege%TYPE, + recursive_p in char + ); + + procedure revoke_permission ( + -- /** + -- * Revoke a privilege on a file or folder, perhaps recursively. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-21 + -- **/ + item_id in acs_permissions.object_id%TYPE, + grantee_id in acs_permissions.grantee_id%TYPE, + privilege in acs_permissions.privilege%TYPE, + recursive_p in char + ); + + function five_n_spaces ( + -- /** + -- * Return 5n nonbreaking spaces. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-27 + -- **/ + n in integer + ) return varchar2; + + procedure set_show_comments_p ( + -- /** + -- * Establish whether the contents of a comment are displayed + -- * on a particular page. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-23 + -- **/ + item_id in acs_permissions.object_id%TYPE, + show_comments_p in static_pages.show_comments_p%TYPE + ); + + function get_show_comments_p ( + -- /** + -- * Retrieve the comment display policy. + -- * + -- * @author Brandoch Calef + -- * @creation-date 2001-02-23 + -- **/ + item_id in acs_permissions.object_id%TYPE + ) return static_pages.show_comments_p%TYPE; + +end static_page; +/ +show errors +-- packages/static-pages/sql/oracle/static-page-pb.sql +-- Package body ONLY. +-- @cvs-id $Id: upgrade-4.3-5.0d1.sql,v 1.1 2003/10/08 16:59:23 mohanp Exp $ +-- @author Brandoch Calef (bcalef@arsdigita.com) + +set def off + +create or replace package body static_page as + function new ( + static_page_id in static_pages.static_page_id%TYPE + default null, + folder_id in sp_folders.folder_id%TYPE, + filename in static_pages.filename%TYPE default null, + title in cr_revisions.title%TYPE default null, + content in cr_revisions.content%TYPE default null, + show_comments_p in static_pages.show_comments_p%TYPE default 't', + 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, + context_id in acs_objects.context_id%TYPE + default null + ,mime_type in cr_revisions.mime_type%TYPE default 'text/html' + ) return static_pages.static_page_id%TYPE is + v_item_id static_pages.static_page_id%TYPE; + begin + -- Create content item; this also makes the content revision. + -- One might be tempted to set the content_type to static_page, + -- But this would confuse site-wide-search, which expects to + -- see a content_type of content_revision. + v_item_id := content_item.new( + item_id => static_page.new.static_page_id, + parent_id => static_page.new.folder_id, + name => static_page.new.filename, + title => static_page.new.title, + mime_type => static_page.new.mime_type, + creation_date => static_page.new.creation_date, + creation_user => static_page.new.creation_user, + creation_ip => static_page.new.creation_ip, + context_id => static_page.new.context_id, + is_live => 't', + data => static_page.new.content + ); + + -- We want to be able to have non-commentable folders below + -- commentable folders. We can't do this if we leave security + -- inheritance enabled. + -- + update acs_objects set security_inherit_p = 'f' + where object_id = v_item_id; + + -- Copy permissions from the parent: + for permission_row in ( + select grantee_id,privilege from acs_permissions + where object_id = folder_id + ) loop + acs_permission.grant_permission( + object_id => v_item_id, + grantee_id => permission_row.grantee_id, + privilege => permission_row.privilege + ); + end loop; + + -- Insert row into static_pages: + insert into static_pages + (static_page_id, filename, folder_id, show_comments_p) + values ( + v_item_id, + static_page.new.filename, + static_page.new.folder_id, + static_page.new.show_comments_p + ); + + return v_item_id; + end; + + procedure del ( + static_page_id in static_pages.static_page_id%TYPE + ) is + begin + -- Delete all permissions on this page: + delete from acs_permissions where object_id = static_page_id; + + -- Drop all comments on this page. general-comments doesn't have + -- a comment.delete() function, so I just do this (see the + -- general-comments drop script): + for comment_row in ( + select comment_id from general_comments + where object_id = static_page_id + ) loop + delete from images + where image_id in ( + select latest_revision + from cr_items + where parent_id = comment_row.comment_id + ); + + acs_message.del(comment_row.comment_id); + end loop; + + -- Delete the page. + -- WE SHOULDN'T NEED TO DO THIS: CONTENT_ITEM.DELETE SHOULD TAKE CARE OF + -- DELETING FROM STATIC PAGES. + delete from static_pages where static_page_id = static_page.del.static_page_id; + content_item.del(static_page_id); + end; + + function get_root_folder ( + package_id in apm_packages.package_id%TYPE + ) return sp_folders.folder_id%TYPE is + folder_exists_p integer; + folder_id sp_folders.folder_id%TYPE; + begin + -- If there isn't a root folder for this package, create one. + -- Otherwise, just return its id. + select count(*) into folder_exists_p from dual where exists ( + select 1 from sp_folders + where package_id = static_page.get_root_folder.package_id + and parent_id is null + ); + + if folder_exists_p = 0 then + folder_id := static_page.new_folder ( + -- name NEEDS to be unique, label does not + name => 'sp_root_package_id_' || package_id, + label => 'sp_root_package_id_' || package_id + ); + + update sp_folders + set package_id = static_page.get_root_folder.package_id + where folder_id = static_page.get_root_folder.folder_id; + + acs_permission.grant_permission ( + object_id => folder_id, + grantee_id => acs.magic_object_id('the_public'), + privilege => 'general_comments_create' + ); + -- The comments will inherit read permission from the pages, + -- so the public should be able to read the static pages. + acs_permission.grant_permission ( + object_id => folder_id, + grantee_id => acs.magic_object_id('the_public'), + privilege => 'read' + ); + else + select folder_id into folder_id from sp_folders + where package_id = static_page.get_root_folder.package_id + and parent_id is null; + end if; + + return folder_id; + end get_root_folder; + + + function new_folder ( + folder_id in sp_folders.folder_id%TYPE + default null, + name in cr_items.name%TYPE, + label in cr_folders.label%TYPE, + description in cr_folders.description%TYPE default null, + parent_id in cr_items.parent_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, + context_id in acs_objects.context_id%TYPE + default null + ) return sp_folders.folder_id%TYPE is + v_folder_id sp_folders.folder_id%TYPE; + v_parent_id cr_items.parent_id%TYPE; + v_package_id apm_packages.package_id%TYPE; + begin + if parent_id is null then + v_parent_id := 0; + else + v_parent_id := parent_id; + end if; + + v_folder_id := content_folder.new ( + name => static_page.new_folder.name, + label => static_page.new_folder.label, + folder_id => static_page.new_folder.folder_id, + parent_id => v_parent_id, + description => static_page.new_folder.description, + creation_date => static_page.new_folder.creation_date, + creation_user => static_page.new_folder.creation_user, + creation_ip => static_page.new_folder.creation_ip, + context_id => static_page.new_folder.context_id + ); + + if parent_id is not null then + -- Get the package_id from the parent: + select package_id into v_package_id from sp_folders + where folder_id = static_page.new_folder.parent_id; + + insert into sp_folders (folder_id, parent_id, package_id) + values (v_folder_id, parent_id, v_package_id); + + update acs_objects set security_inherit_p = 'f' + where object_id = v_folder_id; + + -- Copy permissions from the parent: + for permission_row in ( + select grantee_id,privilege from acs_permissions + where object_id = parent_id + ) loop + acs_permission.grant_permission( + object_id => v_folder_id, + grantee_id => permission_row.grantee_id, + privilege => permission_row.privilege + ); + end loop; + else + insert into sp_folders (folder_id, parent_id) + values (v_folder_id, parent_id); + + -- if it's a root folder, allow it to contain static pages and + -- other folders (subfolders will inherit these properties) + content_folder.register_content_type ( + folder_id => v_folder_id, + content_type => 'static_page' + ); + content_folder.register_content_type ( + folder_id => v_folder_id, + content_type => 'content_revision' + ); + content_folder.register_content_type ( + folder_id => v_folder_id, + content_type => 'content_folder' + ); + end if; + + return v_folder_id; + end; + + procedure delete_folder ( + folder_id in sp_folders.folder_id%TYPE + ) is + begin + for folder_row in ( + select folder_id from ( + select folder_id,level as path_depth from sp_folders + start with folder_id = static_page.delete_folder.folder_id + connect by parent_id = prior folder_id + ) order by path_depth desc + ) loop + for page_row in ( + select static_page_id from static_pages + where folder_id = folder_row.folder_id + ) loop + static_page.del(page_row.static_page_id); + end loop; + + delete from sp_folders where folder_id = folder_row.folder_id; + content_folder.del(folder_row.folder_id); + end loop; + end; + + procedure delete_stale_items ( + session_id in sp_extant_files.session_id%TYPE, + package_id in apm_packages.package_id%TYPE + ) is + root_folder_id sp_folders.folder_id%TYPE; + begin + root_folder_id := static_page.get_root_folder(package_id); + + -- First delete all files that are descendants of the root folder + -- but aren't in sp_extant_files: + -- + for stale_file_row in ( + select static_page_id from static_pages + where folder_id in ( + select folder_id from sp_folders + start with folder_id = root_folder_id + connect by parent_id = prior folder_id + ) and static_page_id not in ( + select static_page_id + from sp_extant_files + where session_id = static_page.delete_stale_items.session_id + ) + ) loop + static_page.del(stale_file_row.static_page_id); + end loop; + + -- Now delete all folders that aren't in sp_extant_folders. There are two + -- views created on the fly here: dead (all descendants of the root + -- folder not in sp_extant_folders) and path (each folder and its depth). + -- They are joined together to get the depth of all the folders that + -- need to be deleted. The root folder is excluded because it won't + -- show up in the filesystem search, so it will be missing from + -- sp_extant_folders. + -- + for stale_folder_row in ( + select dead.folder_id from + (select folder_id from sp_folders + where (folder_id) not in ( + select folder_id + from sp_extant_folders + where session_id = static_page.delete_stale_items.session_id + ) + ) dead, + (select folder_id,level as depth from sp_folders + start with folder_id = root_folder_id + connect by parent_id = prior folder_id + ) path + where dead.folder_id = path.folder_id + and dead.folder_id <> root_folder_id + order by path.depth desc + ) loop + delete from sp_folders + where folder_id = stale_folder_row.folder_id; + + content_folder.del(stale_folder_row.folder_id); + end loop; + end delete_stale_items; + + procedure grant_permission ( + item_id in acs_permissions.object_id%TYPE, + grantee_id in acs_permissions.grantee_id%TYPE, + privilege in acs_permissions.privilege%TYPE, + recursive_p in char + ) is + begin + if recursive_p = 't' then + -- For each folder that is a descendant of item_id, grant. + for folder_row in ( + select folder_id from sp_folders + start with folder_id = item_id + connect by parent_id = prior folder_id + ) loop + acs_permission.grant_permission( + object_id => folder_row.folder_id, + grantee_id => static_page.grant_permission.grantee_id, + privilege => static_page.grant_permission.privilege + ); + end loop; + -- For each file that is a descendant of item_id, grant. + for file_row in ( + select static_page_id from static_pages + where folder_id in ( + select folder_id from sp_folders + start with folder_id = item_id + connect by parent_id = prior folder_id + ) + ) loop + acs_permission.grant_permission( + object_id => file_row.static_page_id, + grantee_id => static_page.grant_permission.grantee_id, + privilege => static_page.grant_permission.privilege + ); + end loop; + else + acs_permission.grant_permission( + object_id => item_id, + grantee_id => static_page.grant_permission.grantee_id, + privilege => static_page.grant_permission.privilege + ); + end if; + end grant_permission; + + procedure revoke_permission ( + item_id in acs_permissions.object_id%TYPE, + grantee_id in acs_permissions.grantee_id%TYPE, + privilege in acs_permissions.privilege%TYPE, + recursive_p in char + ) is + begin + if recursive_p = 't' then + -- For each folder that is a descendant of item_id, revoke. + for folder_row in ( + select folder_id from sp_folders + start with folder_id = item_id + connect by parent_id = prior folder_id + ) loop + acs_permission.revoke_permission( + object_id => folder_row.folder_id, + grantee_id => static_page.revoke_permission.grantee_id, + privilege => static_page.revoke_permission.privilege + ); + end loop; + -- For each file that is a descendant of item_id, revoke. + for file_row in ( + select static_page_id from static_pages + where folder_id in ( + select folder_id from sp_folders + start with folder_id = item_id + connect by parent_id = prior folder_id + ) + ) loop + acs_permission.revoke_permission( + object_id => file_row.static_page_id, + grantee_id => static_page.revoke_permission.grantee_id, + privilege => static_page.revoke_permission.privilege + ); + end loop; + else + acs_permission.revoke_permission( + object_id => item_id, + grantee_id => static_page.revoke_permission.grantee_id, + privilege => static_page.revoke_permission.privilege + ); + end if; + end revoke_permission; + + function five_n_spaces ( + n in integer + ) return varchar2 is + space_string varchar2(400); + begin + space_string := ''; + for i in 1..n loop + space_string := space_string || '     '; + end loop; + return space_string; + end five_n_spaces; + + procedure set_show_comments_p ( + item_id in acs_permissions.object_id%TYPE, + show_comments_p in static_pages.show_comments_p%TYPE + ) is + begin + update static_pages + set show_comments_p = static_page.set_show_comments_p.show_comments_p + where static_page_id = static_page.set_show_comments_p.item_id; + end; + + function get_show_comments_p ( + item_id in acs_permissions.object_id%TYPE + ) return static_pages.show_comments_p%TYPE is + v_show_comments_p static_pages.show_comments_p%TYPE; + begin + select show_comments_p into v_show_comments_p from static_pages + where static_page_id = static_page.get_show_comments_p.item_id; + + return v_show_comments_p; + end; + +end static_page; +/ +show errors Index: openacs-4/packages/survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/survey/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,466 @@ +-- start off with package declarations + + +create or replace package survey +as + function new ( + survey_id in surveys.survey_id%TYPE default null, + name in surveys.name%TYPE, + description in surveys.description%TYPE, + description_html_p in surveys.description_html_p%TYPE default 'f', + single_response_p in surveys.single_response_p%TYPE default 'f', + editable_p in surveys.editable_p%TYPE default 't', + enabled_p in surveys.enabled_p%TYPE default 'f', + single_section_p in surveys.single_section_p%TYPE default 't', + type in surveys.type%TYPE default 'general', + display_type in surveys.display_type%TYPE default 'list', + package_id in surveys.package_id%TYPE, + object_type in acs_objects.object_type%TYPE default 'survey', + 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, + context_id in acs_objects.context_id%TYPE default null +) return acs_objects.object_id%TYPE; + + procedure remove ( + survey_id in surveys.survey_id%TYPE + ); + + function name ( + survey_id in surveys.survey_id%TYPE + ) return varchar; + +end survey; +/ +show errors + + + +-- survey_section + +create or replace package survey_section +as + function new ( + section_id in survey_sections.section_id%TYPE default null, + survey_id in survey_sections.survey_id%TYPE default null, + name in survey_sections.name%TYPE default null, + description in survey_sections.description%TYPE default null, + description_html_p in survey_sections.description_html_p%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'survey_section', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure remove ( + section_id in survey_sections.section_id%TYPE + ); +end survey_section; +/ +show errors + +-- +-- constructor for a survey_question +-- + +create or replace package survey_question +as + function new ( + question_id in survey_questions.question_id%TYPE default null, + section_id in survey_questions.section_id%TYPE default null, + sort_order in survey_questions.sort_order%TYPE default null, + question_text in survey_questions.question_text%TYPE default null, + abstract_data_type in survey_questions.abstract_data_type%TYPE default null, + required_p in survey_questions.required_p%TYPE default 't', + active_p in survey_questions.active_p%TYPE default 't', + presentation_type in survey_questions.presentation_type%TYPE default null, + presentation_options in survey_questions.presentation_options%TYPE default null, + presentation_alignment in survey_questions.presentation_alignment%TYPE default 'below', + object_type in acs_objects.object_type%TYPE default 'survey_question', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + procedure remove ( + question_id in survey_questions.question_id%TYPE + ); +end survey_question; +/ +show errors + + +-- +-- constructor for a survey_response +-- + +create or replace package survey_response +as + function new ( + response_id in survey_responses.response_id %TYPE default null, + survey_id in survey_responses.survey_id%TYPE default null, + title in survey_responses.title%TYPE default null, + notify_on_comment_p in survey_responses.notify_on_comment_p%TYPE default 'f', + object_type in acs_objects.object_type%TYPE default 'survey_response', + 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, + context_id in acs_objects.context_id%TYPE default null, + initial_response_id in survey_responses.initial_response_id%TYPE default null + ) return acs_objects.object_id%TYPE; + + function initial_response_id ( + response_id in survey_responses.response_id%TYPE + ) return survey_responses.response_id%TYPE; + + function initial_user_id ( + response_id in survey_responses.response_id%TYPE + ) return acs_objects.creation_user%TYPE; + + procedure remove ( + response_id in survey_responses.response_id%TYPE + ); + + procedure del ( + response_id in survey_responses.response_id%TYPE + ); + + function boolean_answer ( + answer varchar, + question_id survey_questions.question_id%TYPE + ) return varchar; + +end survey_response; +/ +show errors + + +-- next we define the package bodies + +create or replace package body survey +as + function new ( + survey_id in surveys.survey_id%TYPE default null, + name in surveys.name%TYPE, + description in surveys.description%TYPE, + description_html_p in surveys.description_html_p%TYPE default 'f', + single_response_p in surveys.single_response_p%TYPE default 'f', + editable_p in surveys.editable_p%TYPE default 't', + enabled_p in surveys.enabled_p%TYPE default 'f', + single_section_p in surveys.single_section_p%TYPE default 't', + type in surveys.type%TYPE default 'general', + display_type in surveys.display_type%TYPE default 'list', + package_id in surveys.package_id%TYPE, + object_type in acs_objects.object_type%TYPE default 'survey', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_survey_id surveys.survey_id%TYPE; + begin + v_survey_id := acs_object.new ( + object_id => survey_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into surveys + (survey_id, name, description, description_html_p, + single_response_p, editable_p, enabled_p, single_section_p, type, display_type, package_id) + values + (v_survey_id, new.name, new.description, new.description_html_p, + new.single_response_p, new.editable_p, new.enabled_p, new.single_section_p, new.type, new.display_type, new.package_id); + + return v_survey_id; + end new; + + procedure remove ( + survey_id surveys.survey_id%TYPE + ) + is + v_response_row survey_responses%ROWTYPE; + v_section_row survey_sections%ROWTYPE; + begin + + for v_response_row in (select response_id + from survey_responses + where survey_id=remove.survey_id + and initial_response_id is NULL) loop + survey_response.remove(v_response_row.response_id); + end loop; + + for v_section_row in (select section_id + from survey_sections + where survey_id=remove.survey_id) loop + survey_section.remove(v_section_row.section_id); + end loop; + + delete from surveys where survey_id=remove.survey_id; + acs_object.del(survey_id); + end remove; + + function name ( + survey_id in surveys.survey_id%TYPE + ) return varchar + is + v_name surveys.name%TYPE; + begin + select name + into v_name + from surveys + where survey_id = name.survey_id; + + return v_name; + end name; +end survey; +/ +show errors + + +create or replace package body survey_section +as + function new ( + section_id in survey_sections.section_id%TYPE default null, + survey_id in survey_sections.survey_id%TYPE default null, + name in survey_sections.name%TYPE default null, + description in survey_sections.description%TYPE default null, + description_html_p in survey_sections.description_html_p%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'survey_section', + 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, + context_id in acs_objects.context_id%TYPE default null + + ) return acs_objects.object_id%TYPE + is + v_section_id survey_sections.section_id%TYPE; + begin + v_section_id := acs_object.new ( + object_id => section_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into survey_sections + (section_id, survey_id, name, description, description_html_p) + values + (v_section_id, new.survey_id, new.name, new.description, new.description_html_p); + + return v_section_id; + end new; + + procedure remove ( + section_id in survey_sections.section_id%TYPE + ) is + v_question_row survey_questions%ROWTYPE; + begin + for v_question_row in (select question_id + from survey_questions + where section_id=remove.section_id) loop + survey_question.remove(v_question_row.question_id); + end loop; + delete from survey_sections where section_id=remove.section_id; + acs_object.del(remove.section_id); + end remove; +end survey_section; +/ +show errors + + +create or replace package body survey_question +as + function new ( + question_id in survey_questions.question_id%TYPE default null, + section_id in survey_questions.section_id%TYPE default null, + sort_order in survey_questions.sort_order%TYPE default null, + question_text in survey_questions.question_text%TYPE default null, + abstract_data_type in survey_questions.abstract_data_type%TYPE default null, + required_p in survey_questions.required_p%TYPE default 't', + active_p in survey_questions.active_p%TYPE default 't', + presentation_type in survey_questions.presentation_type%TYPE default null, + presentation_options in survey_questions.presentation_options%TYPE default null, + presentation_alignment in survey_questions.presentation_alignment%TYPE default 'below', + object_type in acs_objects.object_type%TYPE default 'survey_question', + 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, + context_id in acs_objects.context_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_question_id survey_questions.question_id%TYPE; + begin + v_question_id := acs_object.new ( + object_id => question_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => section_id + ); + insert into survey_questions + (question_id, section_id, sort_order, question_text, abstract_data_type, + required_p, active_p, presentation_type, presentation_options, + presentation_alignment) + values + (v_question_id, new.section_id, new.sort_order, new.question_text, new.abstract_data_type, + new.required_p, new.active_p, new.presentation_type, new.presentation_options, + new.presentation_alignment); + return v_question_id; + end new; + + procedure remove ( + question_id in survey_questions.question_id%TYPE + ) + is + begin + + delete from survey_question_responses + where question_id=remove.question_id; + delete from survey_question_choices + where question_id=remove.question_id; + delete from survey_questions + where question_id = remove.question_id; + acs_object.del(remove.question_id); + end remove; +end survey_question; +/ +show errors + + +create or replace package body survey_response +as + function new ( + response_id in survey_responses.response_id %TYPE default null, + survey_id in survey_responses.survey_id%TYPE default null, + title in survey_responses.title%TYPE default null, + notify_on_comment_p in survey_responses.notify_on_comment_p%TYPE default 'f', + object_type in acs_objects.object_type%TYPE default 'survey_response', + 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, + context_id in acs_objects.context_id%TYPE default null, + initial_response_id in survey_responses.initial_response_id%TYPE default null + ) return acs_objects.object_id%TYPE + is + v_response_id survey_responses.response_id%TYPE; + begin + v_response_id := acs_object.new ( + object_id => response_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + insert into survey_responses (response_id, survey_id, title, notify_on_comment_p, initial_response_id) + values + (v_response_id, new.survey_id, new.title, new.notify_on_comment_p, new.initial_response_id); + return v_response_id; + end new; + + function initial_response_id ( + response_id in survey_responses.response_id%TYPE + ) return survey_responses.response_id%TYPE + is + v_initial_response_id survey_responses.response_id%TYPE; + begin + select initial_response_id into v_initial_response_id + from survey_responses where + response_id = initial_response_id.response_id; + if v_initial_response_id is NULL then + v_initial_response_id := initial_response_id.response_id; + end if; + return v_initial_response_id; + end initial_response_id; + + function initial_user_id ( + response_id in survey_responses.response_id%TYPE + ) return acs_objects.creation_user%TYPE + is + v_user_id acs_objects.creation_user%TYPE; + begin + select o.creation_user into v_user_id + from acs_objects o, + survey_responses s + where o.object_id = nvl(s.initial_response_id, s.response_id) + and s.response_id=initial_user_id.response_id; + return v_user_id; + end initial_user_id; + + procedure remove ( + response_id in survey_responses.response_id%TYPE + ) is + v_response_row survey_responses%ROWTYPE; + begin + for v_response_row in (select response_id from survey_responses + where initial_response_id=remove.response_id) loop + survey_response.del(v_response_row.response_id); + end loop; + + survey_response.del(remove.response_id); + end remove; + + procedure del ( + response_id in survey_responses.response_id%TYPE + ) + is + v_question_response_row survey_question_responses%ROWTYPE; + begin + for v_question_response_row in ( + select item_id + from survey_question_responses, cr_revisions + where response_id=del.response_id + and attachment_answer=revision_id) + loop + content_item.del(v_question_response_row.item_id); + end loop; + + delete from survey_question_responses + where response_id=del.response_id; + delete from survey_responses + where response_id=del.response_id; + acs_object.del(del.response_id); + end del; + + function boolean_answer ( + answer varchar, + question_id survey_questions.question_id%TYPE + ) return varchar + is + v_answer varchar(100); + v_presentation_options survey_questions.presentation_options%TYPE; + v_split_pos integer; + begin + + if answer is NOT NULL then + select presentation_options into v_presentation_options + from survey_questions where question_id=boolean_answer.question_id; + + v_split_pos:= instr(v_presentation_options, '/'); + + if answer = 't' then + v_answer:=substr(v_presentation_options, 1, v_split_pos -1 ); + end if; + if answer = 'f' then + v_answer:=substr(v_presentation_options, v_split_pos + 1 ); + end if; + + else + v_answer := ''; + end if; + return v_answer; + end boolean_answer; + +end survey_response; +/ +show errors + + Index: openacs-4/packages/user-preferences/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/user-preferences/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/user-preferences/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql 8 Oct 2003 16:55:34 -0000 1.1 @@ -0,0 +1,203 @@ + +-- +-- The User Preferences package +-- +-- Copyright (C) 2000 MIT +-- ben@openforce +-- +-- distributed under the GPL v2 +-- +-- May 21st 2002 +-- + +-- package + +create or replace package user_pref_type +as + function new ( + preference_type_id in user_preference_types.preference_type_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'user_pref_type', + package_key in user_preference_types.package_key%TYPE, + short_name in user_preference_types.short_name%TYPE, + pretty_name in user_preference_types.pretty_name%TYPE, + datatype in user_preference_types.datatype%TYPE default 'text', + options in user_preference_types.options%TYPE default null, + default_value in user_preference_types.default_value%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE + ) return user_preference_types.preference_type_id%TYPE; + + function get_user_pref ( + preference_type in user_preference_types.short_name%TYPE, + package_id in user_preference_values.package_id%TYPE default null, + user_id in user_preference_values.user_id%TYPE + ) return user_preference_values.value%TYPE; + + procedure set_package_default ( + preference_type_id in user_preference_default_values.preference_type_id%TYPE, + package_id in user_preference_default_values.package_id%TYPE, + default_value in user_preference_default_values.default_value%TYPE + ); + + procedure set_user_pref ( + preference_type_id in user_preference_default_values.preference_type_id%TYPE, + package_id in user_preference_default_values.package_id%TYPE, + user_id in user_preference_values.user_id%TYPE, + value in user_preference_default_values.default_value%TYPE + ); + + procedure del ( + preference_type_id in user_preference_types.preference_type_id%TYPE + ); +end user_pref_type; +/ +show errors + + + +create or replace package body user_pref_type +as + function new ( + preference_type_id in user_preference_types.preference_type_id%TYPE default null, + object_type in acs_objects.object_type%TYPE default 'user_pref_type', + package_key in user_preference_types.package_key%TYPE, + short_name in user_preference_types.short_name%TYPE, + pretty_name in user_preference_types.pretty_name%TYPE, + datatype in user_preference_types.datatype%TYPE default 'text', + options in user_preference_types.options%TYPE default null, + default_value in user_preference_types.default_value%TYPE default null, + creation_date in acs_objects.creation_date%TYPE default sysdate, + creation_user in acs_objects.creation_user%TYPE, + creation_ip in acs_objects.creation_ip%TYPE, + context_id in acs_objects.context_id%TYPE + ) return user_preference_types.preference_type_id%TYPE + is + v_pref_type_id user_preference_types.preference_type_id%TYPE; + begin + v_pref_type_id := acs_object.new ( + object_id => preference_type_id, + object_type => object_type, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + context_id => context_id + ); + + insert into user_preference_types + (preference_type_id, package_key, short_name, pretty_name, datatype, options, default_value) + values + (v_pref_type_id, package_key, short_name, pretty_name, datatype, options, default_value); + + return v_pref_type_id; + end new; + + function get_user_pref ( + preference_type in user_preference_types.short_name%TYPE, + package_id in user_preference_values.package_id%TYPE, + user_id in user_preference_values.user_id%TYPE + ) return user_preference_values.value%TYPE + is + v_type_id user_preference_types.preference_type_id%TYPE; + v_pref user_preference_values.value%TYPE; + begin + select preference_type_id into v_type_id + from user_preference_types where short_name = preference_type; + + -- if there is no such preference type + if SQL%NOTFOUND then return NULL; end if; + + -- check direct user pref for package_id not null + select value into v_pref from user_preference_values + where preference_type_id = v_type_id + and package_id = get_user_pref.package_id + and user_id = get_user_pref.user_id; + + if SQL%FOUND then return v_pref; end if; + + -- check user pref with package_id NULL + select value into v_pref from user_preference_values + where preference_type_id = v_type_id + and package_id is NULL + and user_id = get_user_pref.user_id; + + if SQL%FOUND then return v_pref; end if; + + -- if not found, check package default + select default_value into v_pref from user_preference_default_values + where preference_type_id = v_type_id + and package_id = get_user_pref.package_id; + + if SQL%FOUND then return v_pref; end if; + + -- if not found check default value for preference type + select default_value into v_pref from user_preference_types + where preference_type_id = v_type_id; + + return v_pref; + + end get_user_pref; + + procedure set_package_default ( + preference_type_id in user_preference_default_values.preference_type_id%TYPE, + package_id in user_preference_default_values.package_id%TYPE, + default_value in user_preference_default_values.default_value%TYPE + ) + is + v_count integer; + begin + update user_preference_default_values + set default_value= set_package_default.default_value + where preference_type_id= set_package_default.preference_type_id + and package_id= set_package_default.package_id; + + v_count:= SQL%ROWCOUNT; + + if v_count = 0 + then + insert into user_preference_default_values + (preference_type_id, package_id, default_value) values + (preference_type_id, package_id, default_value); + end if; + + end set_package_default; + + procedure set_user_pref ( + preference_type_id in user_preference_default_values.preference_type_id%TYPE, + package_id in user_preference_default_values.package_id%TYPE, + user_id in user_preference_values.user_id%TYPE, + value in user_preference_default_values.default_value%TYPE + ) + is + v_count integer; + begin + update user_preference_values + set value= set_user_pref.value + where preference_type_id= set_user_pref.preference_type_id + and package_id= set_user_pref.package_id + and user_id= set_user_pref.user_id; + + v_count:= SQL%ROWCOUNT; + + if v_count = 0 + then + insert into user_preference_values + (preference_type_id, package_id, user_id, value) values + (preference_type_id, package_id, user_id, value); + end if; + + end set_user_pref; + + procedure del ( + preference_type_id in user_preference_types.preference_type_id%TYPE + ) + is + begin + acs_object.del(preference_type_id); + end del; + +end user_pref_type; +/ +show errors + Index: openacs-4/packages/user-profile/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/user-profile/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/user-profile/sql/oracle/upgrade/upgrade-0.1d-0.2d.sql 8 Oct 2003 16:56:30 -0000 1.1 @@ -0,0 +1,100 @@ +-- +-- Copyright (C) 2001, 2002 MIT +-- +-- This file is part of dotLRN. +-- +-- dotLRN is free software; you can redistribute it and/or modify it under the +-- terms of the GNU General Public License as published by the Free Software +-- Foundation; either version 2 of the License, or (at your option) any later +-- version. +-- +-- dotLRN is distributed in the hope that it will be useful, but WITHOUT ANY +-- WARRANTY; without even the implied warranty of MERCHANTABILITY or FITNESS +-- FOR A PARTICULAR PURPOSE. See the GNU General Public License for more +-- details. +-- + +-- +-- Create the User Profile package +-- +-- @author yon@openforce.net +-- @version $Id: upgrade-0.1d-0.2d.sql,v 1.1 2003/10/08 16:56:30 mohanp Exp $ +-- + +create or replace package user_profile_rel +as + function new ( + rel_id in user_profile_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'user_profile_rel', + group_id in groups.group_id%TYPE default null, + user_id in users.user_id%TYPE, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return user_profile_rels.rel_id%TYPE; + + procedure del ( + rel_id in user_profile_rels.rel_id%TYPE + ); + +end; +/ +show errors + +create or replace package body user_profile_rel +as + function new ( + rel_id in user_profile_rels.rel_id%TYPE default null, + rel_type in acs_rels.rel_type%TYPE default 'user_profile_rel', + group_id in groups.group_id%TYPE default null, + user_id in users.user_id%TYPE, + creation_user in acs_objects.creation_user%TYPE default null, + creation_ip in acs_objects.creation_ip%TYPE default null + ) return user_profile_rels.rel_id%TYPE + is + v_rel_id membership_rels.rel_id%TYPE; + v_group_id groups.group_id%TYPE; + begin + if group_id is null then + select min(group_id) + into v_group_id + from profiled_groups + where profile_provider = (select min(impl_id) + from acs_sc_impls + where impl_name = 'user_profile_provider'); + else + v_group_id := group_id; + end if; + + v_rel_id := membership_rel.new( + rel_id => rel_id, + rel_type => rel_type, + object_id_one => v_group_id, + object_id_two => user_id, + creation_user => creation_user, + creation_ip => creation_ip + ); + + insert + into user_profile_rels + (rel_id) + values + (v_rel_id); + + return v_rel_id; + end; + + procedure del ( + rel_id in user_profile_rels.rel_id%TYPE + ) + is + begin + delete + from user_profile_rels + where rel_id = user_profile_rel.del.rel_id; + + membership_rel.del(rel_id); + end; + +end; +/ +show errors Index: openacs-4/packages/wp-slim/sql/oracle/upgrade/upgrade-4.6-5.0d1.sql =================================================================== RCS file: /usr/local/cvsroot/openacs-4/packages/wp-slim/sql/oracle/upgrade/upgrade-4.6-5.0d1.sql,v diff -u --- /dev/null 1 Jan 1970 00:00:00 -0000 +++ openacs-4/packages/wp-slim/sql/oracle/upgrade/upgrade-4.6-5.0d1.sql 8 Oct 2003 16:59:23 -0000 1.1 @@ -0,0 +1,1172 @@ +-- Wimpy Point Data Model for ACS 4.0 +-- +-- Paul Konigsberg paulk@arsdigita.com 10/22/00 +-- original module author Jon Salz jsalz@mit.edu + + +-- Define a PL/SQL package containing construstor/deletor functions for the +-- wp_presentation object. +create or replace package wp_presentation +as + function new ( + 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, + pres_title in cr_wp_presentations.pres_title%TYPE, + page_signature in cr_wp_presentations.page_signature%TYPE, + copyright_notice in cr_wp_presentations.copyright_notice%TYPE, + style in cr_wp_presentations.style%TYPE default -1, + public_p in cr_wp_presentations.public_p%TYPE default 'f', + show_modified_p in cr_wp_presentations.show_modified_p%TYPE default 'f', + audience in varchar2, + background in varchar2, + parent_id in integer + ) return cr_items.item_id%TYPE; + + procedure delete_audience ( + audience_item_id in cr_items.item_id%TYPE + ); + + procedure delete_background ( + background_item_id in cr_items.item_id%TYPE + ); + + procedure del ( + pres_item_id in cr_items.item_id%TYPE + ); + + function get_audience ( + pres_item_id in cr_items.item_id%TYPE + ) return blob; + + function get_audience_revision ( + pres_revision_id in cr_revisions.revision_id%TYPE + ) return blob; + + function get_background ( + pres_item_id in cr_items.item_id%TYPE + ) return blob; + + function get_background_revision ( + pres_revision_id in cr_revisions.revision_id%TYPE + ) return blob; + + procedure new_revision ( + 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, + pres_item_id in cr_items.item_id%TYPE, + pres_title in cr_wp_presentations.pres_title%TYPE, + page_signature in cr_wp_presentations.page_signature%TYPE, + copyright_notice in cr_wp_presentations.copyright_notice%TYPE, + style in cr_wp_presentations.style%TYPE, + public_p in cr_wp_presentations.public_p%TYPE, + show_modified_p in cr_wp_presentations.show_modified_p%TYPE, + audience in varchar2, + background in varchar2 + ); + +end wp_presentation; +/ +show errors + +-- Define a PL/SQL package containing construstor/deletor functions for the +-- wp_slide object. +-- context_id should be the presentation_id this slide belongs to. +create or replace package wp_slide +as + function new ( + pres_item_id in cr_items.item_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, + slide_title in cr_wp_slides.slide_title%TYPE, + style in cr_wp_slides.style%TYPE default -1, + original_slide_id in cr_wp_slides.original_slide_id%TYPE, + sort_key in cr_wp_slides.sort_key%TYPE, + preamble in varchar2, + bullet_items in varchar2, + postamble in varchar2, + include_in_outline_p in cr_wp_slides.include_in_outline_p%TYPE default 't', + context_break_after_p in cr_wp_slides.context_break_after_p%TYPE default 'f', + context_id in acs_objects.context_id%TYPE default null + ) return cr_items.item_id%TYPE; + + + procedure delete_preamble ( + preamble_item_id in cr_items.item_id%TYPE + ); + + procedure delete_postamble ( + postamble_item_id in cr_items.item_id%TYPE + ); + + procedure delete_bullet_items ( + bullet_items_item_id in cr_items.item_id%TYPE + ); + + procedure del ( + slide_item_id in cr_items.item_id%TYPE + ); + + function get_preamble ( + slide_item_id in cr_items.item_id%TYPE + ) return blob; + + function get_preamble_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob; + + function get_postamble ( + slide_item_id in cr_items.item_id%TYPE + ) return blob; + + function get_postamble_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob; + + function get_bullet_items ( + slide_item_id in cr_items.item_id%TYPE + ) return blob; + + function get_bullet_items_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob; + + procedure new_revision ( + 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, + slide_item_id in cr_items.item_id%TYPE, + slide_title in cr_wp_slides.slide_title%TYPE, + preamble in varchar2, + bullet_items in varchar2, + postamble in varchar2, + style in cr_wp_slides.style%TYPE default -1, + original_slide_id in cr_wp_slides.original_slide_id%TYPE, + sort_key in cr_wp_slides.sort_key%TYPE, + include_in_outline_p in cr_wp_slides.include_in_outline_p%TYPE default 't', + context_break_after_p in cr_wp_slides.context_break_after_p%TYPE default 'f' + ); + +end wp_slide; +/ +show errors + +-- DRB: Creating an attachment is handled by cr_import_content + +create or replace package wp_attachment +as + + procedure del ( + attach_item_id in cr_items.item_id%TYPE + ); + + procedure new_revision ( + attach_item_id in cr_items.item_id%TYPE + ); + +end wp_attachment; +/ +show errors + +create or replace package body wp_presentation +as + function new ( + 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, + pres_title in cr_wp_presentations.pres_title%TYPE, + page_signature in cr_wp_presentations.page_signature%TYPE, + copyright_notice in cr_wp_presentations.copyright_notice%TYPE, + style in cr_wp_presentations.style%TYPE default -1, + public_p in cr_wp_presentations.public_p%TYPE, + show_modified_p in cr_wp_presentations.show_modified_p%TYPE default 'f', + audience in varchar2, + background in varchar2, + parent_id in integer + ) return cr_items.item_id%TYPE + is + v_item_id cr_items.item_id%TYPE; + v_audience_item_id cr_items.item_id%TYPE; + v_background_item_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + v_audience_revision_id cr_revisions.revision_id%TYPE; + v_background_revision_id cr_revisions.revision_id%TYPE; + v_max_id integer; + v_name cr_wp_presentations.pres_title%TYPE; + begin + -- (name, parent_id) must be unique. For type cr_wp_presentation, + -- name has to be unique because parent_id is null. + + select nvl(max(item_id),0) into v_max_id + from cr_items + where content_type = 'cr_wp_presentation' + and name like new.pres_title || '%'; + + v_name := new.pres_title || '_' || v_max_id; + + v_item_id := content_item.new( + name => v_name, + content_type => 'cr_wp_presentation', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + parent_id => parent_id + ); + + v_revision_id := content_revision.new( + item_id => v_item_id, + title => '', + data => null, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_revision_id); + + insert into cr_wp_presentations + ( + presentation_id, + pres_title, + page_signature, + copyright_notice, + style, + public_p, + show_modified_p + ) + values + ( + v_revision_id, + new.pres_title, + new.page_signature, + new.copyright_notice, + new.style, + new.public_p, + new.show_modified_p + ); + + v_audience_item_id := content_item.new( + name => 'aud', + parent_id => v_item_id, + content_type => 'cr_wp_presentation_aud', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_audience_revision_id := content_revision.new( + item_id => v_audience_item_id, + title => '', + text => audience, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_audience_revision_id); + + insert into cr_wp_presentations_aud + ( + id, + presentation_id + ) + values + ( + v_audience_revision_id, + v_revision_id + ); + + v_background_item_id := content_item.new( + name => 'back', + parent_id => v_item_id, + content_type => 'cr_wp_presentation_back', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_background_revision_id := content_revision.new( + item_id => v_background_item_id, + title => '', + text => background, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_background_revision_id); + + insert into cr_wp_presentations_back + ( + id, + presentation_id + ) + values + ( + v_background_revision_id, + v_revision_id + ); + + return v_item_id; + end; + + + procedure delete_audience ( + audience_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_presentations_aud + where exists (select 1 from cr_revisions where revision_id = cr_wp_presentations_aud.id and item_id = audience_item_id); + + delete from cr_item_publish_audit + where item_id = audience_item_id; + + content_item.del(audience_item_id); + end; + + procedure delete_background ( + background_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_presentations_back + where exists (select 1 from cr_revisions where revision_id = cr_wp_presentations_back.id and item_id = background_item_id); + + delete from cr_item_publish_audit + where item_id = background_item_id; + + content_item.del(background_item_id); + end; + + procedure del ( + pres_item_id in cr_items.item_id%TYPE + ) + is + v_audience_item_id cr_items.item_id%TYPE; + v_background_item_id cr_items.item_id%TYPE; + cursor v_slide_cursor is + select item_id as slide_item_id + from cr_items + where content_type = 'cr_wp_slide' + and parent_id = pres_item_id; + begin + for c in v_slide_cursor loop + wp_slide.del(c.slide_item_id); + end loop; + + select item_id into v_audience_item_id + from cr_items + where content_type = 'cr_wp_presentation_aud' + and parent_id = pres_item_id; + + delete_audience(v_audience_item_id); + + select item_id into v_background_item_id + from cr_items + where content_type = 'cr_wp_presentation_back' + and parent_id = pres_item_id; + + delete_audience(v_background_item_id); + + delete from acs_permissions where object_id = pres_item_id; + update acs_objects set context_id=null where context_id = pres_item_id; + delete from cr_wp_presentations where exists (select 1 from cr_revisions where cr_revisions.revision_id = cr_wp_presentations.presentation_id and cr_revisions.item_id = pres_item_id); + content_item.del(pres_item_id); + end; + + function get_audience ( + pres_item_id in cr_items.item_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions, cr_items + where cr_items.content_type = 'cr_wp_presentation_aud' + and cr_items.parent_id = pres_item_id + and cr_revisions.revision_id = cr_items.live_revision; + return v_blob; + end; + + function get_audience_revision ( + pres_revision_id in cr_revisions.revision_id%TYPE + ) return blob + is + v_blob blob; + begin + select r.content into v_blob + from cr_revisions r, + cr_wp_presentations_aud pa + where pa.presentation_id = pres_revision_id + and r.revision_id = pa.id; + return v_blob; + end; + + function get_background ( + pres_item_id in cr_items.item_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions, cr_items + where cr_items.content_type = 'cr_wp_presentation_back' + and cr_items.parent_id = pres_item_id + and cr_revisions.revision_id = cr_items.live_revision; + return v_blob; + end; + + function get_background_revision ( + pres_revision_id in cr_revisions.revision_id%TYPE + ) return blob + is + v_blob blob; + begin + select r.content into v_blob + from cr_revisions r, + cr_wp_presentations_back pb + where pb.presentation_id = pres_revision_id + and r.revision_id = pb.id; + return v_blob; + end; + + procedure new_revision ( + 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, + pres_item_id in cr_items.item_id%TYPE, + pres_title in cr_wp_presentations.pres_title%TYPE, + page_signature in cr_wp_presentations.page_signature%TYPE, + copyright_notice in cr_wp_presentations.copyright_notice%TYPE, + style in cr_wp_presentations.style%TYPE, + public_p in cr_wp_presentations.public_p%TYPE, + show_modified_p in cr_wp_presentations.show_modified_p%TYPE, + audience in varchar2, + background in varchar2 + ) + is + v_audience_item_id cr_items.item_id%TYPE; + v_background_item_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + v_audience_revision_id cr_revisions.revision_id%TYPE; + v_background_revision_id cr_revisions.revision_id%TYPE; + begin + + v_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => pres_item_id, + title => '', + data => null + ); + + content_item.set_live_revision(v_revision_id); + + insert into cr_wp_presentations + ( + presentation_id, + pres_title, + page_signature, + copyright_notice, + style, + public_p, + show_modified_p + ) + values + ( + v_revision_id, + new_revision.pres_title, + new_revision.page_signature, + new_revision.copyright_notice, + new_revision.style, + new_revision.public_p, + new_revision.show_modified_p + ); + + select item_id into v_audience_item_id + from cr_items + where parent_id = pres_item_id + and content_type = 'cr_wp_presentation_aud'; + + v_audience_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => v_audience_item_id, + title => '', + text => audience + ); + + content_item.set_live_revision(v_audience_revision_id); + + insert into cr_wp_presentations_aud + ( + id, + presentation_id + ) + values + ( + v_audience_revision_id, + v_revision_id + ); + + select item_id into v_background_item_id + from cr_items + where parent_id = pres_item_id + and content_type = 'cr_wp_presentation_back'; + + v_background_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => v_background_item_id, + title => '', + text => background + ); + + content_item.set_live_revision(v_background_revision_id); + + insert into cr_wp_presentations_back + ( + id, + presentation_id + ) + values + ( + v_background_revision_id, + v_revision_id + ); + + end; + +end wp_presentation; +/ +show errors + + + +create or replace package body wp_slide +as + function new ( + pres_item_id in cr_items.item_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, + slide_title in cr_wp_slides.slide_title%TYPE, + style in cr_wp_slides.style%TYPE default -1, + original_slide_id in cr_wp_slides.original_slide_id%TYPE, + sort_key in cr_wp_slides.sort_key%TYPE, + preamble in varchar2, + bullet_items in varchar2, + postamble in varchar2, + include_in_outline_p in cr_wp_slides.include_in_outline_p%TYPE default 't', + context_break_after_p in cr_wp_slides.context_break_after_p%TYPE default 'f', + context_id in acs_objects.context_id%TYPE default null + ) return cr_items.item_id%TYPE + is + v_item_id cr_items.item_id%TYPE; + v_preamble_item_id cr_items.item_id%TYPE; + v_postamble_item_id cr_items.item_id%TYPE; + v_bullet_items_item_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + v_preamble_revision_id cr_revisions.revision_id%TYPE; + v_postamble_revision_id cr_revisions.revision_id%TYPE; + v_bullet_items_revision_id cr_revisions.revision_id%TYPE; + v_max_id integer; + v_name cr_wp_slides.slide_title%TYPE; + begin + -- (name, parent_id) must be unique. Therefore, slide item + -- name has to be unique within a presentation. + + select nvl(max(item_id),0) into v_max_id + from cr_items + where content_type = 'cr_wp_slide' + and name like new.slide_title || '%'; + + v_name := new.slide_title || '_' || v_max_id; + + v_item_id := content_item.new( + name => v_name, + parent_id => pres_item_id, + content_type => 'cr_wp_slide', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_revision_id := content_revision.new( + item_id => v_item_id, + title => '', + data => null, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_revision_id); + + -- update sort_key + update cr_wp_slides + set sort_key = sort_key + 1 + where sort_key >= new.sort_key + and exists (select 1 from cr_items, cr_revisions where parent_id = pres_item_id and cr_items.item_id = cr_revisions.item_id and cr_revisions.revision_id=cr_wp_slides.slide_id); + + insert into cr_wp_slides + ( + slide_id, + slide_title, + style, + original_slide_id, + sort_key, + include_in_outline_p, + context_break_after_p + ) + values + ( + v_revision_id, + new.slide_title, + new.style, + new.original_slide_id, + new.sort_key, + new.include_in_outline_p, + new.context_break_after_p + ); + + + v_preamble_item_id := content_item.new( + name => 'preamble', + parent_id => v_item_id, + content_type => 'cr_wp_slide_preamble', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_preamble_revision_id := content_revision.new( + item_id => v_preamble_item_id, + title => '', + text => preamble, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_preamble_revision_id); + + insert into cr_wp_slides_preamble + ( + id, + slide_id + ) + values + ( + v_preamble_revision_id, + v_revision_id + ); + + v_postamble_item_id := content_item.new( + name => 'postamble', + parent_id => v_item_id, + content_type => 'cr_wp_slide_postamble', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_postamble_revision_id := content_revision.new( + item_id => v_postamble_item_id, + title => '', + text => postamble, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_postamble_revision_id); + + insert into cr_wp_slides_postamble + ( + id, + slide_id + ) + values + ( + v_postamble_revision_id, + v_revision_id + ); + + v_bullet_items_item_id := content_item.new( + name => 'bullet_items', + parent_id => v_item_id, + content_type => 'cr_wp_slide_bullet_items', + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + v_bullet_items_revision_id := content_revision.new( + item_id => v_bullet_items_item_id, + title => '', + text => bullet_items, + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip + ); + + content_item.set_live_revision(v_bullet_items_revision_id); + + insert into cr_wp_slides_bullet_items + ( + id, + slide_id + ) + values + ( + v_bullet_items_revision_id, + v_revision_id + ); + + return v_item_id; + end; + + procedure delete_preamble ( + preamble_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_slides_preamble + where exists (select 1 from cr_revisions where revision_id = cr_wp_slides_preamble.id and item_id = preamble_item_id); + + delete from cr_item_publish_audit + where item_id = preamble_item_id; + + content_item.del(preamble_item_id); + end; + + procedure delete_postamble ( + postamble_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_slides_postamble + where exists (select 1 from cr_revisions where revision_id = cr_wp_slides_postamble.id and item_id = postamble_item_id); + + delete from cr_item_publish_audit + where item_id = postamble_item_id; + + content_item.del(postamble_item_id); + end; + + procedure delete_bullet_items ( + bullet_items_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_slides_bullet_items + where exists (select 1 from cr_revisions where revision_id = cr_wp_slides_bullet_items.id and item_id = bullet_items_item_id); + + delete from cr_item_publish_audit + where item_id = bullet_items_item_id; + + content_item.del(bullet_items_item_id); + end; + + procedure del ( + slide_item_id in cr_items.item_id%TYPE + ) + is + v_sort_key cr_wp_slides.sort_key%TYPE; + v_pres_item_id cr_items.item_id%TYPE; + v_preamble_item_id cr_items.item_id%TYPE; + v_postamble_item_id cr_items.item_id%TYPE; + v_bullet_items_item_id cr_items.item_id%TYPE; + cursor v_attach_cursor is + select item_id as attach_item_id + from cr_items + where content_type in ('cr_wp_image_attachment', 'cr_wp_file_attachment') + and parent_id = slide_item_id; + begin + for c in v_attach_cursor loop + wp_attachment.del(c.attach_item_id); + end loop; + + select item_id into v_preamble_item_id + from cr_items + where content_type = 'cr_wp_slide_preamble' + and parent_id = slide_item_id; + + delete_preamble(v_preamble_item_id); + + select item_id into v_postamble_item_id + from cr_items + where content_type = 'cr_wp_slide_postamble' + and parent_id = slide_item_id; + + delete_postamble(v_postamble_item_id); + + select item_id into v_bullet_items_item_id + from cr_items + where content_type = 'cr_wp_slide_bullet_items' + and parent_id = slide_item_id; + + delete_bullet_items(v_bullet_items_item_id); + + -- sort_key of all revisions should be the same + select max(s.sort_key), max(i.parent_id) into v_sort_key, v_pres_item_id + from cr_wp_slides s, cr_revisions r, cr_items i + where r.item_id = slide_item_id + and r.revision_id = s.slide_id + and i.item_id = r.item_id; + delete from cr_wp_slides where exists (select 1 from cr_revisions where cr_revisions.revision_id = cr_wp_slides.slide_id and cr_revisions.item_id = slide_item_id); + update cr_wp_slides set sort_key = sort_key - 1 where sort_key > v_sort_key and exists (select 1 from cr_revisions r, cr_items i where i.parent_id = v_pres_item_id and i.item_id = r.item_id and r.revision_id = cr_wp_slides.slide_id); + update acs_objects set context_id=null where context_id = slide_item_id; + delete from cr_item_publish_audit where item_id = slide_item_id; + content_item.del(slide_item_id); + end; + + function get_preamble ( + slide_item_id in cr_items.item_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions, cr_items + where cr_items.content_type = 'cr_wp_slide_preamble' + and cr_items.parent_id = slide_item_id + and cr_revisions.revision_id = cr_items.live_revision; + return v_blob; + end; + + function get_preamble_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions r, cr_wp_slides_preamble sp + where sp.slide_id = slide_revision_id + and r.revision_id = sp.id; + + return v_blob; + end; + + function get_postamble ( + slide_item_id in cr_items.item_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions, cr_items + where cr_items.content_type = 'cr_wp_slide_postamble' + and cr_items.parent_id = slide_item_id + and cr_revisions.revision_id = cr_items.live_revision; + return v_blob; + end; + + function get_postamble_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions r, cr_wp_slides_postamble sp + where sp.slide_id = slide_revision_id + and r.revision_id = sp.id; + + return v_blob; + end; + + function get_bullet_items ( + slide_item_id in cr_items.item_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions, cr_items + where cr_items.content_type = 'cr_wp_slide_bullet_items' + and cr_items.parent_id = slide_item_id + and cr_revisions.revision_id = cr_items.live_revision; + return v_blob; + end; + + function get_bullet_items_revision ( + slide_revision_id in cr_revisions.revision_id%TYPE + ) return blob + is + v_blob blob; + begin + select content into v_blob + from cr_revisions r, cr_wp_slides_bullet_items sb + where sb.slide_id = slide_revision_id + and r.revision_id = sb.id; + + return v_blob; + end; + + procedure new_revision ( + 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, + slide_item_id in cr_items.item_id%TYPE, + slide_title in cr_wp_slides.slide_title%TYPE, + preamble in varchar2, + bullet_items in varchar2, + postamble in varchar2, + style in cr_wp_slides.style%TYPE default -1, + original_slide_id in cr_wp_slides.original_slide_id%TYPE, + sort_key in cr_wp_slides.sort_key%TYPE, + include_in_outline_p in cr_wp_slides.include_in_outline_p%TYPE default 't', + context_break_after_p in cr_wp_slides.context_break_after_p%TYPE default 'f' + ) + is + v_preamble_item_id cr_items.item_id%TYPE; + v_postamble_item_id cr_items.item_id%TYPE; + v_bullet_items_item_id cr_items.item_id%TYPE; + v_revision_id cr_revisions.revision_id%TYPE; + v_preamble_revision_id cr_revisions.revision_id%TYPE; + v_postamble_revision_id cr_revisions.revision_id%TYPE; + v_bullet_items_revision_id cr_revisions.revision_id%TYPE; + begin + + v_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => slide_item_id, + title => '', + data => null + ); + + content_item.set_live_revision(v_revision_id); + + insert into cr_wp_slides + ( + slide_id, + slide_title, + style, + original_slide_id, + sort_key, + include_in_outline_p, + context_break_after_p + ) + values + ( + v_revision_id, + new_revision.slide_title, + new_revision.style, + new_revision.original_slide_id, + new_revision.sort_key, + new_revision.include_in_outline_p, + new_revision.context_break_after_p + ); + + + select item_id into v_preamble_item_id + from cr_items + where parent_id = slide_item_id + and content_type = 'cr_wp_slide_preamble'; + + v_preamble_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => v_preamble_item_id, + title => '', + text => preamble + ); + + content_item.set_live_revision(v_preamble_revision_id); + + insert into cr_wp_slides_preamble + ( + id, + slide_id + ) + values + ( + v_preamble_revision_id, + v_revision_id + ); + + select item_id into v_postamble_item_id + from cr_items + where parent_id = slide_item_id + and content_type = 'cr_wp_slide_postamble'; + + v_postamble_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => v_postamble_item_id, + title => '', + text => postamble + ); + + content_item.set_live_revision(v_postamble_revision_id); + + insert into cr_wp_slides_postamble + ( + id, + slide_id + ) + values + ( + v_postamble_revision_id, + v_revision_id + ); + + select item_id into v_bullet_items_item_id + from cr_items + where parent_id = slide_item_id + and content_type = 'cr_wp_slide_bullet_items'; + + v_bullet_items_revision_id := content_revision.new( + creation_date => creation_date, + creation_user => creation_user, + creation_ip => creation_ip, + item_id => v_bullet_items_item_id, + title => '', + text => bullet_items + ); + + content_item.set_live_revision(v_bullet_items_revision_id); + + insert into cr_wp_slides_bullet_items + ( + id, + slide_id + ) + values + ( + v_bullet_items_revision_id, + v_revision_id + ); + end; + +end wp_slide; +/ +show errors + + +create or replace package body wp_attachment +as + + procedure del ( + attach_item_id in cr_items.item_id%TYPE + ) + is + begin + delete from cr_wp_image_attachments + where exists (select 1 from cr_revisions where revision_id = cr_wp_image_attachments.attach_id and item_id = attach_item_id); + + delete from cr_wp_file_attachments + where exists (select 1 from cr_revisions where revision_id = cr_wp_file_attachments.attach_id and item_id = attach_item_id); + + delete from cr_item_publish_audit + where item_id = attach_item_id; + + content_item.del(attach_item_id); + end; + + procedure new_revision ( + attach_item_id in cr_items.item_id%TYPE + ) + is + begin + return; + end; + +end wp_attachment; +/ +show errors + + +--style package roc@ + +create or replace package wp_style +as + +procedure del ( + p_style_id in wp_styles.style_id%TYPE +); + +procedure image_delete( + p_revision_id in wp_style_images.wp_style_images_id%TYPE +); + +end wp_style; +/ +show errors + + + +create or replace package body wp_style +as + +procedure del ( + p_style_id in wp_styles.style_id%TYPE +) +is + p_item_id integer; +begin + + for one_image in ( + select * from wp_style_images + where wp_style_images_id = (select background_image from wp_styles where style_id = wp_style.del.p_style_id)) + loop + delete from wp_style_images where wp_style_images_id = one_image.wp_style_images_id; + select item_id into p_item_id from cr_revisions where revision_id = one_image.wp_style_images_id; + + content_item.del(item_id => p_item_id); + end loop; + + update cr_wp_slides set style = -1 where style = wp_style.del.p_style_id; + update cr_wp_presentations set style = -1 where style = wp_style.del.p_style_id; + delete from wp_styles where style_id = wp_style.del.p_style_id; + +end; + + + +procedure image_delete( + p_revision_id in wp_style_images.wp_style_images_id%TYPE +) +is + p_item_id integer; +begin + + update wp_styles set background_image = 0 where background_image = wp_style.image_delete.p_revision_id; + + delete from wp_style_images + where wp_style_images_id = wp_style.image_delete.p_revision_id; + + select item_id into p_item_id from cr_revisions where revision_id = wp_style.image_delete.p_revision_id; + + content_item.del(item_id => p_item_id); + +end; + + +end wp_style; +/ +show errors + + +commit;