Commit 7a72953b authored by Frank Bergmann's avatar Frank Bergmann

- OpenACS 5.9 Import

parent ffaefa17
This diff is collapsed.
create or replace package util
as
function multiple_nextval(
v_sequence_name in varchar2,
v_count in integer)
return varchar2;
function logical_negation (
true_or_false IN varchar2)
return varchar2;
function table_exists (
name in varchar2)
return boolean;
function table_column_exists (
t_name in varchar2,
c_name in varchar2)
return boolean;
function view_exists (
name in varchar2)
return boolean;
function index_exists (
name in varchar2)
return boolean;
end util;
/
show errors
create or replace package body util
as
-- Retrieves v_count (not necessarily consecutive) nextval values from the
-- sequence named v_sequence_name.
function multiple_nextval(
v_sequence_name in varchar2,
v_count in integer
)
return varchar2
is
a_sequence_values varchar2(4000);
begin
execute immediate '
declare
a_nextval integer;
begin
for counter in 1..:v_count loop
select ' || v_sequence_name || '.nextval into a_nextval from dual;
:a_sequence_values := :a_sequence_values || '','' || a_nextval;
end loop;
end;
' using in v_count, in out a_sequence_values;
return substr(a_sequence_values, 2);
end;
function logical_negation (
true_or_false IN varchar2)
return varchar2
as
begin
IF true_or_false is null THEN
return null;
ELSIF true_or_false = 'f' THEN
return 't';
ELSE
return 'f';
END IF;
END logical_negation;
function table_exists (
name IN varchar2)
return boolean
as
begin
return exists (select 1 from user_tables where table_name = t_name);
END table_exists;
function table_column_exists (
t_name IN varchar2,
c_name IN varchar2)
return boolean
as
begin
return exists (select 1 from user_tab_columns where c.table_name = t_name and c.column_name = c_name);
END table_column_exists;
function view_exists (
name IN varchar2)
return boolean
as
begin
return exists (select 1 from user_views where view_name = name);
END view_exists;
function index_exists (
name IN varchar2)
return boolean
as
begin
return exists (select 1 from user_indexes where index_name = name);
END index_exists;
end util;
/
show errors
drop index site_nodes_parent_id_idx;
create index site_nodes_parent_object_node_id_idx on site_nodes(parent_id, object_id, node_id);
create index site_nodes_parent_id_idx on site_nodes(parent_id);
create index site_node_object_mappings_node_id_idx on site_node_object_mappings(node_id);
create or replace package sec_session_property
as
procedure upsert (
p_session_id in sec_session_properties.session_id%TYPE,
p_module in sec_session_properties.module%TYPE,
p_name in sec_session_properties.property_name%TYPE,
p_value in sec_session_properties.property_value%TYPE,
p_secure_p in sec_session_properties.secure_p%TYPE,
p_last_hit in sec_session_properties.last_hit%TYPE
);
end sec_session_property;
/
show errors
create or replace package body sec_session_property
as
procedure upsert(
p_session_id in sec_session_properties.session_id%TYPE,
p_module in sec_session_properties.module%TYPE,
p_name in sec_session_properties.property_name%TYPE,
p_value in sec_session_properties.property_value%TYPE,
p_secure_p in sec_session_properties.secure_p%TYPE,
p_last_hit in sec_session_properties.last_hit%TYPE
)
is
BEGIN
insert into sec_session_properties
(session_id, module, property_name, secure_p, last_hit)
values (p_session_id, p_module, p_name, p_secure_p, p_last_hit);
exception
when dup_val_on_index then
update sec_session_properties
set property_value = p_value,
secure_p = p_secure_p,
last_hit = p_last_hit
where
session_id = p_session_id and
module = p_module and
property_name = p_name;
END upsert;
end sec_session_property;
/
show errors
create or replace function acs_object_type__create_type (varchar,varchar,varchar,varchar,varchar,varchar,varchar,boolean,varchar,varchar, boolean, boolean)
returns integer as '
declare
p_object_type alias for $1;
p_pretty_name alias for $2;
p_pretty_plural alias for $3;
p_supertype alias for $4;
p_table_name alias for $5; -- default null
p_id_column alias for $6; -- default null
p_package_name alias for $7; -- default null
p_abstract_p alias for $8; -- default ''f''
p_type_extension_table alias for $9; -- default null
p_name_method alias for $10; -- default null
p_create_table_p alias for $11;
p_dynamic_p alias for $12;
v_package_name acs_object_types.package_name%TYPE;
v_supertype acs_object_types.supertype%TYPE;
v_name_method varchar;
v_idx integer;
v_temp_p boolean;
v_supertype_table acs_object_types.table_name%TYPE;
v_id_column acs_object_types.id_column%TYPE;
v_table_name acs_object_types.table_name%TYPE;
begin
v_idx := position(''.'' in p_name_method);
if v_idx <> 0 then
v_name_method := substr(p_name_method,1,v_idx - 1) ||
''__'' || substr(p_name_method, v_idx + 1);
else
v_name_method := p_name_method;
end if;
-- If we are asked to create the table, provide reasonable default values for the
-- table name and id column. Traditionally OpenACS uses the plural form of the type
-- name. This code appends "_t" (for "table") because the use of english plural rules
-- does not work well for all languages.
if p_create_table_p and (p_table_name is null or p_table_name = '''') then
v_table_name := p_object_type || ''_t'';
else
v_table_name := p_table_name;
end if;
if p_create_table_p and (p_id_column is null or p_id_column = '''') then
v_id_column := p_object_type || ''_id'';
else
v_id_column := p_id_column;
end if;
if p_package_name is null or p_package_name = '''' then
v_package_name := p_object_type;
else
v_package_name := p_package_name;
end if;
if p_supertype is null or p_supertype = '''' then
v_supertype := ''acs_object'';
else
v_supertype := p_supertype;
if not acs_object_type__is_subtype_p(''acs_object'', p_supertype)
then
raise exception ''%s is not a valid type'', p_supertype;
end if;
end if;
insert into acs_object_types
(object_type, pretty_name, pretty_plural, supertype, table_name,
id_column, abstract_p, type_extension_table, package_name,
name_method, dynamic_p)
values
(p_object_type, p_pretty_name,
p_pretty_plural, v_supertype,
v_table_name, v_id_column,
p_abstract_p, p_type_extension_table,
v_package_name, v_name_method, p_dynamic_p);
if p_create_table_p then
if exists (select 1
from pg_class
where relname = lower(v_table_name)) then
raise exception ''Table "%" already exists'', v_table_name;
end if;
loop
select table_name,object_type into v_supertype_table,v_supertype
from acs_object_types
where object_type = v_supertype;
exit when v_supertype_table is not null;
end loop;
execute ''create table '' || v_table_name || '' ('' ||
v_id_column || '' integer constraint '' || v_table_name ||
''_pk primary key '' || '' constraint '' || v_table_name ||
''_fk references '' || v_supertype_table || '' on delete cascade)'';
end if;
return 0;
end;' language 'plpgsql';
-- DRB: backwards compatibility version, don't allow for table creation.
create or replace function acs_object_type__create_type (varchar,varchar,varchar,varchar,varchar,varchar,varchar,boolean,varchar,varchar)
returns integer as '
declare
p_object_type alias for $1;
p_pretty_name alias for $2;
p_pretty_plural alias for $3;
p_supertype alias for $4;
p_table_name alias for $5; -- default null
p_id_column alias for $6; -- default null
p_package_name alias for $7; -- default null
p_abstract_p alias for $8; -- default ''f''
p_type_extension_table alias for $9; -- default null
p_name_method alias for $10; -- default null
begin
return acs_object_type__create_type(p_object_type, p_pretty_name,
p_pretty_plural, p_supertype, p_table_name,
p_id_column, p_package_name, p_abstract_p,
p_type_extension_table, p_name_method,''f'',''f'');
end;' language 'plpgsql';
update acs_object_types set supertype = null where object_type = 'acs_object';
create or replace function acs_object_type__create_type (varchar,varchar,varchar,varchar,varchar,varchar,varchar,boolean,varchar,varchar, boolean, boolean)
returns integer as '
declare
p_object_type alias for $1;
p_pretty_name alias for $2;
p_pretty_plural alias for $3;
p_supertype alias for $4;
p_table_name alias for $5; -- default null
p_id_column alias for $6; -- default null
p_package_name alias for $7; -- default null
p_abstract_p alias for $8; -- default ''f''
p_type_extension_table alias for $9; -- default null
p_name_method alias for $10; -- default null
p_create_table_p alias for $11;
p_dynamic_p alias for $12;
v_package_name acs_object_types.package_name%TYPE;
v_supertype acs_object_types.supertype%TYPE;
v_name_method varchar;
v_idx integer;
v_temp_p boolean;
v_supertype_table acs_object_types.table_name%TYPE;
v_id_column acs_object_types.id_column%TYPE;
v_table_name acs_object_types.table_name%TYPE;
begin
v_idx := position(''.'' in p_name_method);
if v_idx <> 0 then
v_name_method := substr(p_name_method,1,v_idx - 1) ||
''__'' || substr(p_name_method, v_idx + 1);
else
v_name_method := p_name_method;
end if;
-- If we are asked to create the table, provide reasonable default values for the
-- table name and id column. Traditionally OpenACS uses the plural form of the type
-- name. This code appends "_t" (for "table") because the use of english plural rules
-- does not work well for all languages.
if p_create_table_p and (p_table_name is null or p_table_name = '''') then
v_table_name := p_object_type || ''_t'';
else
v_table_name := p_table_name;
end if;
if p_create_table_p and (p_id_column is null or p_id_column = '''') then
v_id_column := p_object_type || ''_id'';
else
v_id_column := p_id_column;
end if;
if p_package_name is null or p_package_name = '''' then
v_package_name := p_object_type;
else
v_package_name := p_package_name;
end if;
if p_object_type <> ''acs_object'' then
if p_supertype is null or p_supertype = '''' then
v_supertype := ''acs_object'';
else
v_supertype := p_supertype;
if not acs_object_type__is_subtype_p(''acs_object'', p_supertype) then
raise exception ''%s is not a valid type'', p_supertype;
end if;
end if;
end if;
insert into acs_object_types
(object_type, pretty_name, pretty_plural, supertype, table_name,
id_column, abstract_p, type_extension_table, package_name,
name_method, dynamic_p)
values
(p_object_type, p_pretty_name,
p_pretty_plural, v_supertype,
v_table_name, v_id_column,
p_abstract_p, p_type_extension_table,
v_package_name, v_name_method, p_dynamic_p);
if p_create_table_p then
if exists (select 1
from pg_class
where relname = lower(v_table_name)) then
raise exception ''Table "%" already exists'', v_table_name;
end if;
loop
select table_name,object_type into v_supertype_table,v_supertype
from acs_object_types
where object_type = v_supertype;
exit when v_supertype_table is not null;
end loop;
execute ''create table '' || v_table_name || '' ('' ||
v_id_column || '' integer constraint '' || v_table_name ||
''_pk primary key '' || '' constraint '' || v_table_name ||
''_fk references '' || v_supertype_table || '' on delete cascade)'';
end if;
return 0;
end;' language 'plpgsql';
-- DRB: backwards compatibility version, don't allow for table creation.
create or replace function acs_object_type__create_type (varchar,varchar,varchar,varchar,varchar,varchar,varchar,boolean,varchar,varchar)
returns integer as '
declare
p_object_type alias for $1;
p_pretty_name alias for $2;
p_pretty_plural alias for $3;
p_supertype alias for $4;
p_table_name alias for $5; -- default null
p_id_column alias for $6; -- default null
p_package_name alias for $7; -- default null
p_abstract_p alias for $8; -- default ''f''
p_type_extension_table alias for $9; -- default null
p_name_method alias for $10; -- default null
begin
return acs_object_type__create_type(p_object_type, p_pretty_name,
p_pretty_plural, p_supertype, p_table_name,
p_id_column, p_package_name, p_abstract_p,
p_type_extension_table, p_name_method,''f'',''f'');
end;' language 'plpgsql';
select define_function_args('acs_object_type__drop_type','object_type,drop_table_p;f,drop_children_p;f');
-- procedure drop_type
create or replace function acs_object_type__drop_type (varchar,boolean,boolean)
returns integer as '
declare
p_object_type alias for $1;
p_drop_children_p alias for $2;
p_drop_table_p alias for $3;
row record;
object_row record;
v_table_name acs_object_types.table_name%TYPE;
begin
-- drop children recursively
if p_drop_children_p then
for row in select object_type
from acs_object_types
where supertype = p_object_type
loop
perform acs_object_type__drop_type(row.object_type, ''t'', p_drop_table_p);
end loop;
end if;
-- drop all the attributes associated with this type
for row in select attribute_name
from acs_attributes
where object_type = p_object_type
loop
perform acs_attribute__drop_attribute (p_object_type, row.attribute_name);
end loop;
-- Remove the associated table if it exists and p_drop_table_p is true
if p_drop_table_p then
select table_name into v_table_name
from acs_object_types
where object_type = p_object_type;
if found then
if not exists (select 1
from pg_class
where relname = lower(v_table_name)) then
raise exception ''Table "%" does not exist'', v_table_name;
end if;
execute ''drop table '' || v_table_name || '' cascade'';
end if;
end if;
delete from acs_object_types
where object_type = p_object_type;
return 0;
end;' language 'plpgsql';
-- Retained for backwards compatibility
create or replace function acs_object_type__drop_type (varchar,boolean)
returns integer as '
begin
return acs_object_type__drop_type($1,$2,''f'');
end;' language 'plpgsql';
create or replace function number_src(text) returns text as '
declare
v_src alias for $1;
v_pos integer;
v_ret text default '''';
v_tmp text;
v_cnt integer default -1;
begin
if v_src is null then
return null;
end if;
v_tmp := v_src;
LOOP
v_pos := position(''\n'' in v_tmp);
v_cnt := v_cnt + 1;
exit when v_pos = 0;
if v_cnt != 0 then
v_ret := v_ret || to_char(v_cnt,''9999'') || '':'' || substr(v_tmp,1,v_pos);
end if;
v_tmp := substr(v_tmp,v_pos + 1);
end LOOP;
return v_ret || to_char(v_cnt,''9999'') || '':'' || v_tmp;
end;' language 'plpgsql' immutable strict;
create or replace function get_func_definition (varchar,oidvector) returns text as '
declare
fname alias for $1;
args alias for $2;
nargs integer default 0;
v_pos integer;
v_funcdef text default '''';
v_args varchar;
v_one_arg varchar;
v_one_type varchar;
v_nargs integer;
v_src text;
v_rettype varchar;
begin
select proargtypes, pronargs, number_src(prosrc),
(select typname from pg_type where oid = p.prorettype::integer)
into v_args, v_nargs, v_src, v_rettype
from pg_proc p
where proname = fname::name
and proargtypes = args;
v_funcdef := v_funcdef || ''
create or replace function '' || fname || ''('';
v_pos := position('' '' in v_args);
while nargs < v_nargs loop
nargs := nargs + 1;
if nargs = v_nargs then
v_one_arg := v_args;
v_args := '''';
else
v_one_arg := substr(v_args, 1, v_pos \- 1);
v_args := substr(v_args, v_pos + 1);
v_pos := position('' '' in v_args);
end if;
select case when nargs = 1
then typname
else '','' || typname
end into v_one_type
from pg_type
where oid = v_one_arg::integer;
v_funcdef := v_funcdef || v_one_type;
end loop;
v_funcdef := v_funcdef || '') returns '' || v_rettype || '' as \\\'\\n'' || v_src || ''\\\' language \\\'plpgsql\\\';'';
return v_funcdef;
end;' language 'plpgsql' stable strict;
This diff is collapsed.
-- providing missing upgrade script in order to get rid of
-- syntax seq_foo.nextval
--
-- procedure acs_log__notice/2
--
CREATE OR REPLACE FUNCTION acs_log__notice(
notice__log_key varchar,
notice__message varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_logs
(log_id, log_level, log_key, message)
values
(nextval('t_acs_log_id_seq'), 'notice', notice__log_key, notice__message);
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_log__warn/2
--
CREATE OR REPLACE FUNCTION acs_log__warn(
warn__log_key varchar,
warn__message varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_logs
(log_id, log_level, log_key, message)
values
(nextval('t_acs_log_id_seq'), 'warn', warn__log_key, warn__message);
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_log__error/2
--
CREATE OR REPLACE FUNCTION acs_log__error(
error__log_key varchar,
error__message varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_logs
(log_id, log_level, log_key, message)
values
(nextval('t_acs_log_id_seq'), 'error', error__log_key, error__message);
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_log__debug/2
--
CREATE OR REPLACE FUNCTION acs_log__debug(
debug__log_key varchar,
debug__message varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_logs
(log_id, log_level, log_key, message)
values
(nextval('t_acs_log_id_seq'), 'debug', debug__log_key, debug__message);
return 0;
END;
$$ LANGUAGE plpgsql;
select define_function_args('cmp_pg_version','p__version');
CREATE or REPLACE function cmp_pg_version(
p__version varchar
) RETURNS integer AS $$
DECLARE
pg_version integer[];
user_pg_version integer[];
index integer;
ret_val integer;
i integer;
BEGIN
ret_val = 0;
user_pg_version := string_to_array(trim(p__version),'.')::int[];
select string_to_array(setting, '.')::int[] into pg_version from pg_settings where name = 'server_version';
for index in array_length(user_pg_version, 1) + 1..array_length(pg_version, 1) loop
user_pg_version[index] := 0;
end loop;
index := 1;
while (index <= array_length(pg_version, 1) and ret_val = 0) loop
if user_pg_version[index] > pg_version[index] then
ret_val := -1;
elsif user_pg_version[index] < pg_version[index] then
ret_val := 1;
end if;
index := index + 1;
end loop;
return ret_val;
END;
$$ LANGUAGE plpgsql;
create function inline_0()
returns integer as $inline_0$
begin
IF cmp_pg_version('8.4') >= 0 THEN
-- recursive permissions functions - START
--
-- procedure acs_permission__permission_p/3
--
CREATE OR REPLACE FUNCTION acs_permission__permission_p(
permission_p__object_id integer,
permission_p__party_id integer,
permission_p__privilege varchar
) RETURNS boolean AS $$
DECLARE
exists_p boolean;
BEGIN
return exists (With RECURSIVE object_context(object_id, context_id) AS (
select permission_p__object_id, permission_p__object_id
from acs_objects
where object_id = permission_p__object_id
union all
select ao.object_id,
case when (ao.security_inherit_p = 'f' or ao.context_id is null)
then acs__magic_object_id('security_context_root') else ao.context_id end
from object_context oc, acs_objects ao
where ao.object_id = oc.context_id
and ao.object_id != acs__magic_object_id('security_context_root')
), privilege_ancestors(privilege, child_privilege) AS (
select permission_p__privilege, permission_p__privilege
union all
select aph.privilege, aph.child_privilege
from privilege_ancestors pa join acs_privilege_hierarchy aph
on aph.child_privilege = pa.privilege
) select
1
from
acs_permissions p
join party_approved_member_map pap on pap.party_id = p.grantee_id
join privilege_ancestors pa on pa.privilege = p.privilege
join object_context oc on p.object_id = oc.context_id
where pap.member_id = permission_p__party_id
);
END;
$$ LANGUAGE plpgsql stable;
-- for tsearch
PERFORM define_function_args('acs_permission__permission_p_recursive_array','a_objects,a_party_id,a_privilege');
CREATE OR REPLACE FUNCTION acs_permission__permission_p_recursive_array(
permission_p__objects integer[],
permission_p__party_id integer,
permission_p__privilege varchar
) RETURNS table (object_id integer, orig_object_id integer) as $$
BEGIN
return query With RECURSIVE object_context(obj_id, context_id, orig_obj_id) AS (
select unnest(permission_p__objects), unnest(permission_p__objects), unnest(permission_p__objects)
union all
select ao.object_id,
case when (ao.security_inherit_p = 'f' or ao.context_id is null)
then acs__magic_object_id('security_context_root') else ao.context_id END,
oc.orig_obj_id
from object_context oc, acs_objects ao
where ao.object_id = oc.context_id
and ao.object_id != acs__magic_object_id('security_context_root')
), privilege_ancestors(privilege, child_privilege) AS (
select permission_p__privilege, permission_p__privilege
union all
select aph.privilege, aph.child_privilege
from privilege_ancestors pa join acs_privilege_hierarchy aph
on aph.child_privilege = pa.privilege
) select
p.object_id, oc.orig_obj_id
from
acs_permissions p
join party_approved_member_map pap on pap.party_id = p.grantee_id
join privilege_ancestors pa on pa.privilege = p.privilege
join object_context oc on p.object_id = oc.context_id
where pap.member_id = permission_p__party_id
;
END;
$$ LANGUAGE plpgsql stable;
CREATE OR REPLACE FUNCTION site_node__url(
url__node_id integer
) RETURNS varchar AS $$
BEGIN
return ( With RECURSIVE site_nodes_recursion(parent_id, path, directory_p, node_id) as (
select parent_id, ARRAY[name || case when directory_p then '/' else ' ' end]::text[] as path, directory_p, node_id
from site_nodes where node_id = url__node_id
UNION ALL
select sn.parent_id, sn.name::text || snr.path , sn.directory_p, snr.parent_id
from site_nodes sn join site_nodes_recursion snr on sn.node_id = snr.parent_id
where snr.parent_id is not null
) select array_to_string(path,'/') from site_nodes_recursion where parent_id is null
);
END;
$$ LANGUAGE plpgsql;
-- recursive permissions functions END
END IF;
return null;
end;
$inline_0$ LANGUAGE plpgsql;
select inline_0();
drop function inline_0();
-- added
select define_function_args('apm__register_parameter','parameter_id;null,package_key,parameter_name,description;null,scope,datatype;string,default_value;null,section_name;null,min_n_values;1,max_n_values;1');
--
-- procedure apm__register_parameter/10
--
CREATE OR REPLACE FUNCTION apm__register_parameter(
register_parameter__parameter_id integer, -- default null
register_parameter__package_key varchar,
register_parameter__parameter_name varchar,
register_parameter__description varchar, -- default null
register_parameter__scope varchar,
register_parameter__datatype varchar, -- default 'string'
register_parameter__default_value varchar, -- default null
register_parameter__section_name varchar, -- default null
register_parameter__min_n_values integer, -- default 1
register_parameter__max_n_values integer -- default 1
) RETURNS integer AS $$
DECLARE
v_parameter_id apm_parameters.parameter_id%TYPE;
v_value_id apm_parameter_values.value_id%TYPE;
v_pkg record;
BEGIN
-- Create the new parameter.
v_parameter_id := acs_object__new(
register_parameter__parameter_id,
'apm_parameter',
now(),
null,
null,
null,
't',
register_parameter__package_key || ' - ' || register_parameter__parameter_name,
null
);
insert into apm_parameters
(parameter_id, parameter_name, scope, description, package_key, datatype,
default_value, section_name, min_n_values, max_n_values)
values
(v_parameter_id, register_parameter__parameter_name, register_parameter__scope,
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.
if register_parameter__scope = 'instance' then
for v_pkg in
select package_id
from apm_packages
where package_key = register_parameter__package_key
loop
v_value_id := apm_parameter_value__new(
null,
v_pkg.package_id,
v_parameter_id,
register_parameter__default_value);
end loop;
else
v_value_id := apm_parameter_value__new(
null,
null,
v_parameter_id,
register_parameter__default_value);
end if;
return v_parameter_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION acs_group__delete(
delete__group_id integer
) RETURNS integer AS $$
DECLARE
row record;
BEGIN
-- 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 = delete__group_id
or r.object_id_two = delete__group_id)
LOOP
execute 'select ' || row.package_name || '__delete(' || row.rel_id || ')';
end loop;
-- Delete all segments defined for this group
for row in select segment_id
from rel_segments
where group_id = delete__group_id
LOOP
PERFORM rel_segment__delete(row.segment_id);
end loop;
PERFORM party__delete(delete__group_id);
return 0;
END;
$$ LANGUAGE plpgsql;
select define_function_args('acs_object__initialize_attributes','object_id');
select define_function_args('acs_object__name','object_id');
select define_function_args('acs_object__default_name','object_id');
select define_function_args('acs_object__check_context_index','object_id,ancestor_id,n_generations');
select define_function_args('acs_object__check_path','object_id,ancestor_id');
select define_function_args('acs_object__check_representation','object_id');
select define_function_args('acs_object__update_last_modified','object_id,modifying_user,modifying_ip,last_modified;now()');
select define_function_args('cmp_pg_version','version');
select define_function_args('acs_object__object_id','object_id');
-- added
select define_function_args('util__table_exists','name');
--
-- procedure util__table_exists/1
--
CREATE OR REPLACE FUNCTION util__table_exists(
name text
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (
select 1 from pg_class
where relname = name
and pg_table_is_visible(oid));
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__table_column_exists','t_name,c_name');
--
-- procedure util__table_column_exists/1
--
CREATE OR REPLACE FUNCTION util__table_column_exists(
t_name text,
c_name text
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (
select 1 from information_schema.columns c
where c.table_name = t_name
and c.column_name = c_name);
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__view_exists','name');
--
-- procedure util__view_exists/1
--
CREATE OR REPLACE FUNCTION util__view_exists(
name text
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (
select 1 from pg_views where viewname = name);
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__index_exists','name');
--
-- procedure util__index_exists/1
--
CREATE OR REPLACE FUNCTION util__index_exists(
name text
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (
select 1 from pg_indexes where indexname = name);
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_object__new/9
--
CREATE OR REPLACE FUNCTION acs_object__new(
new__object_id integer, -- default null
new__object_type varchar, -- default 'acs_object'
new__creation_date timestamptz, -- default now()
new__creation_user integer, -- default null
new__creation_ip varchar, -- default null
new__context_id integer, -- default null
new__security_inherit_p boolean, -- default 't'
new__title varchar, -- default null
new__package_id integer -- default null
) RETURNS integer AS $$
DECLARE
v_object_id acs_objects.object_id%TYPE;
v_creation_date timestamptz;
v_title acs_objects.title%TYPE;
v_object_type_pretty_name acs_object_types.pretty_name%TYPE;
BEGIN
if new__object_id is null then
select nextval('t_acs_object_id_seq') into v_object_id;
else
v_object_id := new__object_id;
end if;
if new__title is null then
select pretty_name
into v_object_type_pretty_name
from acs_object_types
where object_type = new__object_type;
v_title := v_object_type_pretty_name || ' ' || v_object_id;
else
v_title := new__title;
end if;
if new__creation_date is null then
v_creation_date:= now();
else
v_creation_date := new__creation_date;
end if;
insert into acs_objects
(object_id, object_type, title, package_id, context_id,
creation_date, creation_user, creation_ip, security_inherit_p)
values
(v_object_id, new__object_type, v_title, new__package_id, new__context_id,
v_creation_date, new__creation_user, new__creation_ip,
new__security_inherit_p);
PERFORM acs_object__initialize_attributes(v_object_id);
return v_object_id;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION acs_group__delete(
delete__group_id integer
) RETURNS integer AS $$
DECLARE
row record;
BEGIN
-- 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 = delete__group_id
or r.object_id_two = delete__group_id)
LOOP
execute 'select ' || row.package_name || '__delete(' || row.rel_id || ')';
end loop;
-- Delete all segments defined for this group
for row in select segment_id
from rel_segments
where group_id = delete__group_id
LOOP
PERFORM rel_segment__delete(row.segment_id);
end loop;
--Lets clear the groups table first
delete from groups
where group_id = delete__group_id;
PERFORM party__delete(delete__group_id);
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- Make sure that patch
-- http://cvs.openacs.org/browse/OpenACS/openacs-4/packages/acs-kernel/sql/postgresql/apm-create.sql?r2=1.74&r1=1.73
-- is applied for sites upgrading (use v_parameter_id and not get_value__parameter_id)
--
--
CREATE OR REPLACE FUNCTION apm__get_value(
get_value__package_id integer,
get_value__parameter_name varchar
) RETURNS varchar AS $$
DECLARE
v_parameter_id apm_parameter_values.parameter_id%TYPE;
value apm_parameter_values.attr_value%TYPE;
BEGIN
v_parameter_id := apm__id_for_name (get_value__package_id, get_value__parameter_name);
select attr_value into value from apm_parameter_values v
where v.package_id = get_value__package_id
and parameter_id = v_parameter_id;
return value;
END;
$$ LANGUAGE plpgsql stable strict;
CREATE OR REPLACE FUNCTION apm__get_value(
get_value__package_key varchar,
get_value__parameter_name varchar
) RETURNS varchar AS $$
DECLARE
v_parameter_id apm_parameter_values.parameter_id%TYPE;
value apm_parameter_values.attr_value%TYPE;
BEGIN
v_parameter_id := apm__id_for_name (get_value__package_key, get_value__parameter_name);
select attr_value into value from apm_parameter_values v
where v.package_id is null
and parameter_id = v_parameter_id;
return value;
END;
$$ LANGUAGE plpgsql stable strict;
alter table acs_attributes drop constraint acs_attributes_datatype_fk;
alter table acs_attributes add constraint acs_attributes_datatype_fk
foreign key (datatype)
references acs_datatypes(datatype) on update cascade;
alter table sec_session_properties alter column session_id type bigint;
drop index site_nodes_parent_id_idx;
create index site_nodes_parent_id_idx on site_nodes(parent_id);
create or replace function __create_index(name varchar, def varchar)
returns integer as $$
declare v_exists integer;
begin
select into v_exists count(*) from pg_class where relname = name;
if v_exists = 0 then
execute 'create index ' || name || ' ' || def;
end if;
return 1;
end;
$$ language plpgsql;
select __create_index('site_nodes_parent_object_node_id_idx','on site_nodes(parent_id, object_id, node_id)');
select __create_index('site_node_object_mappings_node_id_idx','on site_node_object_mappings(node_id)');
drop function __create_index(name varchar, def varchar);
--
-- procedure acs_object__delete/1
--
CREATE OR REPLACE FUNCTION acs_object__delete(
delete__object_id integer
) RETURNS integer AS $$
DECLARE
obj_type record;
BEGIN
-- GN: the following deletion operation iterates over the id_columns
-- of the acs_object_types of the type tree for the obejct and
-- performs manual deletions in these tables by trying to delete the
-- delete__object_id from the id_column. This deletion includes as
-- well the deletion in acs_objects.
--
-- In the best of all possible worlds, this would not
-- be necessary, when the objects would have specified "on delete
-- cascade" for the id_columns.
for obj_type
in select o2.table_name, o2.id_column
from acs_object_types o1, acs_object_types o2
where o1.object_type = (select object_type
from acs_objects o
where o.object_id = delete__object_id)
and o1.tree_sortkey between o2.tree_sortkey and tree_right(o2.tree_sortkey)
order by o2.tree_sortkey desc
loop
-- Delete from the table.
-- DRB: I removed the quote_ident calls that DanW originally included
-- because the table names appear to be stored in upper case. Quoting
-- causes them to not match the actual lower or potentially mixed-case
-- table names. We will just forbid squirrely names that include quotes.
-- daveB
-- ETP is creating a new object, but not a table, although it does specify a
-- table name, so we need to check if the table exists. Wp-slim does this too
if table_exists(obj_type.table_name) then
execute 'delete from ' || obj_type.table_name ||
' where ' || obj_type.id_column || ' = ' || delete__object_id;
end if;
end loop;
return 0;
END;
$$ LANGUAGE plpgsql;
select define_function_args('sec_session_property__upsert','session_id,module,name,secure_p,last_hit');
CREATE OR REPLACE FUNCTION sec_session_property__upsert(
p_session_id bigint,
p_module varchar,
p_name varchar,
p_value varchar,
p_secure_p boolean,
p_last_hit integer
) RETURNS void as
$$
BEGIN
LOOP
-- first try to update the key
update sec_session_properties
set property_value = p_value, secure_p = p_secure_p, last_hit = p_last_hit
where session_id = p_session_id and module = p_module and property_name = p_name;
IF found THEN
return;
END IF;
-- not there, so try to insert the key
-- if someone else inserts the same key concurrently,
-- we could get a unique-key failure
BEGIN
insert into sec_session_properties
(session_id, module, property_name, secure_p, last_hit)
values (p_session_id, p_module, p_name, p_secure_p, p_last_hit);
RETURN;
EXCEPTION WHEN unique_violation THEN
-- Do nothing, and loop to try the UPDATE again.
END;
END LOOP;
END;
$$ LANGUAGE plpgsql;
ALTER TABLE acs_objects drop column IF EXISTS tree_sortkey cascade;
ALTER TABLE acs_objects drop column IF EXISTS max_child_sortkey cascade;
DROP TRIGGER IF EXISTS acs_objects_insert_tr on acs_objects;
DROP TRIGGER IF EXISTS acs_objects_update_tr on acs_objects;
--
-- procedure content_type__refresh_view/1
--
CREATE OR REPLACE FUNCTION content_type__refresh_view(
refresh_view__content_type varchar
) RETURNS integer AS $$
DECLARE
cols varchar default '';
tabs varchar default '';
joins varchar default '';
v_table_name varchar;
join_rec record;
BEGIN
for join_rec in select ot2.table_name, ot2.id_column, tree_level(ot2.tree_sortkey) as level
from acs_object_types ot1, acs_object_types ot2
where ot2.object_type <> 'acs_object'
and ot2.object_type <> 'content_revision'
and lower(ot2.table_name) <> 'acs_objects'
and lower(ot2.table_name) <> 'cr_revisions'
and ot1.object_type = refresh_view__content_type
and ot1.tree_sortkey between ot2.tree_sortkey and tree_right(ot2.tree_sortkey)
order by ot2.tree_sortkey desc
LOOP
if join_rec.table_name is not null then
cols := cols || ', ' || join_rec.table_name || '.*';
tabs := tabs || ', ' || join_rec.table_name;
joins := joins || ' and acs_objects.object_id = ' ||
join_rec.table_name || '.' || join_rec.id_column;
end if;
end loop;
-- Since we allow null table name use object type if table name is null so
-- we still can have a view.
select coalesce(table_name,object_type) into v_table_name from acs_object_types
where object_type = refresh_view__content_type;
if length(v_table_name) > 57 then
raise exception 'Table name cannot be longer than 57 characters, because that causes conflicting rules when we create the views.';
end if;
-- create the input view (includes content columns)
if table_exists(v_table_name || 'i') then
execute 'drop view ' || v_table_name || 'i' || ' CASCADE';
end if;
-- FIXME: need to look at content_revision__get_content. Since the CR
-- can store data in a lob, a text field or in an external file, getting
-- the data attribute for this view will be problematic.
execute 'create view ' || v_table_name ||
'i as select acs_objects.object_id,
acs_objects.object_type,
acs_objects.title as object_title,
acs_objects.package_id as object_package_id,
acs_objects.context_id,
acs_objects.security_inherit_p,
acs_objects.creation_user,
acs_objects.creation_date,
acs_objects.creation_ip,
acs_objects.last_modified,
acs_objects.modifying_user,
acs_objects.modifying_ip,
cr.revision_id, cr.title, cr.item_id,
content_revision__get_content(cr.revision_id) as data,
cr_text.text_data as text,
cr.description, cr.publish_date, cr.mime_type, cr.nls_language' ||
cols ||
' from acs_objects, cr_revisions cr, cr_text' || tabs || ' where
acs_objects.object_id = cr.revision_id ' || joins;
-- create the output view (excludes content columns to enable SELECT *)
if table_exists(v_table_name || 'x') then
execute 'drop view ' || v_table_name || 'x cascade';
end if;
execute 'create view ' || v_table_name ||
'x as select acs_objects.object_id,
acs_objects.object_type,
acs_objects.title as object_title,
acs_objects.package_id as object_package_id,
acs_objects.context_id,
acs_objects.security_inherit_p,
acs_objects.creation_user,
acs_objects.creation_date,
acs_objects.creation_ip,
acs_objects.last_modified,
acs_objects.modifying_user,
acs_objects.modifying_ip,
cr.revision_id, cr.title, cr.item_id,
cr.description, cr.publish_date, cr.mime_type, cr.nls_language,
i.name, i.parent_id' ||
cols ||
' from acs_objects, cr_revisions cr, cr_items i, cr_text' || tabs ||
' where acs_objects.object_id = cr.revision_id
and cr.item_id = i.item_id' || joins;
PERFORM content_type__refresh_trigger(refresh_view__content_type);
-- exception
-- when others then
-- dbms_output.put_line('Error creating attribute view or trigger for'
-- || content_type);
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- The ALTER TABLE ... CASCADE deletes several automatically and
-- manually built views and functions. The automatically built
-- dependent objects can be rebuilt with the helper function
-- 'content_type__refresh_view'.
--
-- However, we have as well rebuild a few views which included
-- (sometimes implicitely, e.g. via acs_objects.*) the
-- tree_sortkey. We perform this operation here (since the views were
-- dropped by this upgrade script) but as well in update scripts for
-- the relevant packages refering explicitly to the tree_sortkey
-- fields.
--
SELECT t2.object_type, content_type__refresh_view(t2.object_type)
from acs_object_types t1, acs_object_types t2
where t2.tree_sortkey between t1.tree_sortkey and
tree_right(t1.tree_sortkey) and t1.object_type = 'content_revision';
--
-- we have to recreate cc_users, since it exports o.*
--
create or replace view cc_users as
select o.*, pa.*, pe.*, u.*, mr.member_state, mr.rel_id
from acs_objects o, parties pa, persons pe, users u, group_member_map m, membership_rels mr
where o.object_id = pa.party_id
and pa.party_id = pe.person_id
and pe.person_id = u.user_id
and u.user_id = m.member_id
and m.group_id = acs__magic_object_id('registered_users')
and m.rel_id = mr.rel_id
and m.container_id = m.group_id
and m.rel_type = 'membership_rel';
--
-- we have to recreate fs_urls_full, when file-storage is in use,
-- since the view exports acs_objects.*
--
create function inline_0()
returns integer as $inline_0$
declare success integer;
begin
-- We know we have to update when we have one of the tables of the
-- file-storage package.
select 1 from pg_class into success where relname = 'fs_folders';
IF found THEN
create or replace view fs_urls_full as
select cr_extlinks.extlink_id as url_id,
cr_extlinks.url,
cr_items.parent_id as folder_id,
cr_extlinks.label as name,
cr_extlinks.description,
acs_objects.*
from cr_extlinks,
cr_items,
acs_objects
where cr_extlinks.extlink_id = cr_items.item_id
and cr_items.item_id = acs_objects.object_id;
END IF;
return null;
end;
$inline_0$ LANGUAGE plpgsql;
select inline_0();
drop function inline_0();
--
-- We have to recreate download_repository_obj and
-- download_arch_revisions_obj, when download is in use, since the
-- views exports acs_objects.tree_sortkey
--
create function inline_0()
returns integer as $inline_0$
declare success integer;
begin
--
-- We know we have to update the view when we have one of the base tables.
--
select 1 from pg_class into success where relname = 'download_repository';
IF found THEN
-- If the upgrade script is run multiple times, then
-- "ALTER TABLE acs_objects drop column ..."
-- might not have dropped the view. So we do this manually.
select 1 from pg_class into success where relname = 'download_repository_obj';
IF found THEN
drop view download_repository_obj;
END if;
create view download_repository_obj as
select repository_id,
o.object_id, o.object_type, o.title as obj_title, o.package_id as obj_package_id, o.context_id,
o.security_inherit_p, o.creation_user, o.creation_date, o.creation_ip, o.last_modified, o.modifying_user,
o.modifying_ip,
i.parent_id,
r.title,
r.description,
r.content as help_text
from download_repository dr, acs_objects o, cr_items i, cr_revisions r
where dr.repository_id = o.object_id
and i.item_id = o.object_id
and r.revision_id = i.live_revision;
--
-- now the same with download_arch_revisions_obj
--
select 1 from pg_class into success where relname = 'download_arch_revisions_obj';
IF found THEN
drop view download_arch_revisions_obj;
END if;
create view download_arch_revisions_obj as
select dar.*,
o.object_id, o.object_type, o.title as obj_title, o.package_id as obj_package_id, o.context_id,
o.security_inherit_p, o.creation_user, o.creation_date, o.creation_ip, o.last_modified, o.modifying_user,
o.modifying_ip,
r.item_id as archive_id,
r.title as file_name,
r.description as version_name,
r.publish_date,
r.mime_type,
r.content
from download_archive_revisions dar, acs_objects o, cr_revisions r
where dar.revision_id = o.object_id
and dar.revision_id = r.revision_id;
END IF;
return null;
end;
$inline_0$ LANGUAGE plpgsql;
select inline_0();
drop function inline_0();
-- the triggers are deleted automatically
--
-- drop trigger acs_objects_insert_tr on acs_objects;
-- drop trigger acs_objects_update_tr on acs_objects;
drop function IF EXISTS acs_objects_get_tree_sortkey(integer);
drop function IF EXISTS acs_objects_insert_tr();
drop function IF EXISTS acs_objects_update_tr();
-- Antonio Pisano 2015-07-29: removed exclusive lock
-- for this procedures as it is sufficient to handle
-- exception/ignore the case. Locking esclusively
-- could cause deadlock in certain situations.
--
-- procedure acs_permission__grant_permission/3
--
CREATE OR REPLACE FUNCTION acs_permission__grant_permission(
grant_permission__object_id integer,
grant_permission__grantee_id integer,
grant_permission__privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_permissions
(object_id, grantee_id, privilege)
values
(grant_permission__object_id, grant_permission__grantee_id,
grant_permission__privilege);
return 0;
EXCEPTION
when unique_violation then
return 0;
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_permission__revoke_permission/3
--
CREATE OR REPLACE FUNCTION acs_permission__revoke_permission(
revoke_permission__object_id integer,
revoke_permission__grantee_id integer,
revoke_permission__privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
delete from acs_permissions
where object_id = revoke_permission__object_id
and grantee_id = revoke_permission__grantee_id
and privilege = revoke_permission__privilege;
return 0;
END;
$$ LANGUAGE plpgsql;
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment