Commit b67f6239 authored by Frank Bergmann's avatar Frank Bergmann

- Added missing OpenACS 5.9.1 upgrade scripts

parent 34d343d0
This diff is collapsed.
-- fix typo in parameter name
update apm_parameters set parameter_name = 'TclTraceLogSeverities' where parameter_name = 'TclTraceLogServerities';
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
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_tables where table_name = upper(table_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END table_exists;
function table_column_exists (
t_name IN varchar2,
c_name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count from user_tab_columns
where table_name = upper(table_column_exists.t_name)
and column_name = upper(table_column_exists.c_name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END table_column_exists;
function view_exists (
name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_views where view_name = upper(view_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END view_exists;
function index_exists (
name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_indexes where index_name = upper(index_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END index_exists;
end util;
/
show errors
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
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_tables where table_name = upper(table_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END table_exists;
function table_column_exists (
t_name IN varchar2,
c_name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count from user_tab_columns
where table_name = upper(table_column_exists.t_name)
and column_name = upper(table_column_exists.c_name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END table_column_exists;
function view_exists (
name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_views where view_name = upper(view_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END view_exists;
function index_exists (
name IN varchar2)
return boolean
as
v_count integer;
v_exists boolean;
begin
select decode(count(*),0,0,1) into v_count
from user_indexes where index_name = upper(index_exists.name);
if v_count = 1 then
v_exists := true;
else
v_exists := false;
end if;
return v_exists;
END index_exists;
end util;
/
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);
update acs_objects
set title = group_name
where object_id = v_group_id;
-- 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, rels.rel_type
from
( select distinct g.rel_type
from group_type_rels g,
( select object_type as parent_type
from acs_object_types
start with new.object_type = object_type
connect by prior supertype = object_type
) types
where g.group_type = types.parent_type
and not exists
( select 1 from group_rels
where group_rels.group_id = v_group_id
and group_rels.rel_type = g.rel_type)
) rels;
return v_group_id;
end new;
procedure del (
group_id in groups.group_id%TYPE
)
is
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 = 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;
-- 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;
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, acs_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
delete from acs_permissions where grantee_id in(
select object_id from acs_objects where object_type = 'user' and object_id not in (select party_id from parties)
);
ALTER TABLE acs_permissions DROP CONSTRAINT IF EXISTS acs_permissions_grantee_id_fk;
ALTER TABLE acs_permissions ADD CONSTRAINT acs_permissions_grantee_id_fk
FOREIGN KEY (grantee_id) REFERENCES parties(party_id) ON DELETE CASCADE;
ALTER TABLE acs_permissions DROP CONSTRAINT IF EXISTS acs_permissions_on_what_id_fk;
ALTER TABLE acs_permissions DROP CONSTRAINT IF EXISTS acs_permissions_object_id_fk;
ALTER TABLE acs_permissions ADD CONSTRAINT acs_permissions_object_id_fk
FOREIGN KEY (object_id) REFERENCES acs_objects(object_id) ON DELETE CASCADE;
ALTER TABLE acs_permissions DROP CONSTRAINT IF EXISTS acs_permissions_priv_fk;
ALTER TABLE acs_permissions DROP CONSTRAINT IF EXISTS acs_permissions_privilege_fk;
ALTER TABLE acs_permissions ADD CONSTRAINT acs_permissions_privilege_fk
FOREIGN KEY (privilege) REFERENCES acs_privileges(privilege) ON DELETE CASCADE;
-- This data model change is not required for people installing
-- OpenACS from versions >= 5.2, but was never put in an upgrade
-- script and therefore older instances will need it.
begin;
-- make sure the old constraint names don't exist
alter table acs_rels drop constraint if exists acs_object_rels_one_fk;
alter table acs_rels drop constraint if exists acs_object_rels_two_fk;
-- create the new constraints if they don't exist already
DO $$
BEGIN
BEGIN
alter table acs_rels add constraint acs_rels_object_id_one_fk foreign key (object_id_one) references acs_objects(object_id) on delete cascade;
EXCEPTION
WHEN duplicate_object THEN RAISE NOTICE 'Table constraint acs_rels_object_id_one_fk already exists, skipping';
END;
BEGIN
alter table acs_rels add constraint acs_rels_object_id_two_fk foreign key (object_id_two) references acs_objects(object_id) on delete cascade;
EXCEPTION
WHEN duplicate_object THEN RAISE NOTICE 'Table constraint acs_rels_object_id_two_fk already exists, skipping';
END;
END $$;
end;
-- fix typo in parameter name
update apm_parameters set parameter_name = 'TclTraceLogSeverities' where parameter_name = 'TclTraceLogServerities';
--
-- Create an SQL schema to allow the same dot notation as in
-- Oracle. The advantage of this notation is that the function can be
-- called identically for PostgreSQL and Oracle, so much duplicated
-- code can be removed.
--
-- Actually, at least all permission functions should be defined this
-- way, keeping the old "__" notation around for backwards
-- compatibility for custom packages.
--
-- TODO: handling of schema names in define_function_args
--
DO $$
DECLARE
v_found boolean;
BEGIN
SELECT exists(select schema_name FROM information_schema.schemata WHERE schema_name = 'acs_permission')
INTO v_found;
if v_found IS FALSE then
CREATE SCHEMA acs_permission;
end if;
END$$;
--
-- procedure acs_permission.permission_p/3
--
CREATE OR REPLACE FUNCTION acs_permission.permission_p(
p_object_id integer,
p_party_id integer,
p_privilege varchar
) RETURNS boolean AS $$
DECLARE
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
RETURN EXISTS (WITH RECURSIVE
object_context(object_id, context_id) AS (
SELECT p_object_id, p_object_id
FROM acs_objects
WHERE object_id = p_object_id
UNION ALL
SELECT ao.object_id,
CASE WHEN (ao.security_inherit_p = 'f' OR ao.context_id IS NULL)
THEN v_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 != v_security_context_root
), privilege_ancestors(privilege, child_privilege) AS (
SELECT p_privilege, 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 = p_party_id
);
END;
$$ LANGUAGE plpgsql stable;
--
-- procedure acs_permission.permission_p_recursive_array/3
--
-- Return for a an array of objects a set of objects where the
-- specified user has the specified rights.
CREATE OR REPLACE FUNCTION acs_permission.permission_p_recursive_array(
p_objects integer[],
p_party_id integer,
p_privilege varchar
) RETURNS table (object_id integer, orig_object_id integer) AS $$
DECLARE
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
RETURN QUERY WITH RECURSIVE
object_context(obj_id, context_id, orig_obj_id) AS (
SELECT unnest(p_objects), unnest(p_objects), unnest(p_objects)
UNION ALL
SELECT
ao.object_id,
CASE WHEN (ao.security_inherit_p = 'f' OR ao.context_id IS NULL)
THEN v_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 != v_security_context_root
), privilege_ancestors(privilege, child_privilege) AS (
SELECT p_privilege, 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 = p_party_id;
END;
$$ LANGUAGE plpgsql stable;
--
-- procedure acs_permission.parties_with_object_privilege/2
--
-- Find all party_ids which have a given privilege on a given
-- object. The function is equivalent to an SQL query on the
-- deprecated acs_object_party_privilege_map such as e.g.:
--
-- select p.party_id
-- from acs_object_party_privilege_map p
-- where p.object_id = :object_id
-- and p.privilege = 'admin';
--
CREATE OR REPLACE FUNCTION acs_permission.parties_with_object_privilege(
p_object_id integer,
p_privilege varchar
) RETURNS table (party_id integer) AS $$
DECLARE
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
RETURN QUERY WITH RECURSIVE
object_context(obj_id, context_id, orig_obj_id) AS (
SELECT p_object_id, p_object_id, p_object_id
UNION ALL
SELECT
ao.object_id,
CASE WHEN (ao.security_inherit_p = 'f' OR ao.context_id IS NULL)
THEN v_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 != v_security_context_root
), privilege_ancestors(privilege, child_privilege) AS (
SELECT p_privilege, 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 pap.member_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;
END;
$$ LANGUAGE plpgsql stable;
--
-- procedure acs_permission.grant_permission/3
--
CREATE OR REPLACE FUNCTION acs_permission.grant_permission(
p_object_id integer,
p_grantee_id integer,
p_privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
insert into acs_permissions
(object_id, grantee_id, privilege)
values
(p_object_id, p_grantee_id, p_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(
p_object_id integer,
p_grantee_id integer,
p_privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
delete from acs_permissions
where object_id = p_object_id
and grantee_id = p_grantee_id
and privilege = p_privilege;
return 0;
END;
$$ LANGUAGE plpgsql;
---
--- Functions for backwards compatibility
---
select define_function_args('acs_permission__permission_p','object_id,party_id,privilege');
DROP FUNCTION IF EXISTS acs_permission__permission_p(integer, integer, varchar);
CREATE OR REPLACE FUNCTION acs_permission__permission_p(
p_object_id integer,
p_party_id integer,
p_privilege varchar
) RETURNS boolean AS $$
BEGIN
RETURN acs_permission.permission_p(p_object_id, p_party_id, p_privilege);
END;
$$ LANGUAGE plpgsql stable;
select define_function_args('acs_permission__permission_p_recursive_array','objects,party_id,privilege');
DROP FUNCTION IF EXISTS acs_permission__permission_p_recursive_array(integer[], integer, varchar);
CREATE OR REPLACE FUNCTION acs_permission__permission_p_recursive_array(
p_objects integer[],
p_party_id integer,
p_privilege varchar
) RETURNS table (object_id integer, orig_object_id integer) AS $$
SELECT acs_permission.permission_p_recursive_array($1, $2, $3);
$$ LANGUAGE sql stable;
select define_function_args('acs_permission__grant_permission','object_id,grantee_id,privilege');
DROP FUNCTION IF EXISTS acs_permission__grant_permission(integer, integer, varchar);
CREATE OR REPLACE FUNCTION acs_permission__grant_permission(
p_object_id integer,
p_grantee_id integer,
p_privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
RETURN acs_permission.grant_permission(p_object_id, p_grantee_id, p_privilege);
END;
$$ LANGUAGE plpgsql;
select define_function_args('acs_permission__revoke_permission','object_id,grantee_id,privilege');
DROP FUNCTION IF EXISTS acs_permission__revoke_permission(integer, integer, varchar);
CREATE OR REPLACE FUNCTION acs_permission__revoke_permission(
p_object_id integer,
p_grantee_id integer,
p_privilege varchar
) RETURNS integer AS $$
DECLARE
BEGIN
RETURN acs_permission.revoke_permission(p_object_id, p_grantee_id, p_privilege);
END;
$$ LANGUAGE plpgsql;
--
-- procedure acs_permission.permissions_all/1
--
CREATE OR REPLACE FUNCTION acs_permission.permissions_all(
p_object_id integer
) RETURNS table (object_id integer, grantee_id integer, privilege varchar) AS $$
DECLARE
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
RETURN QUERY
WITH RECURSIVE object_context(obj_id, context_id, orig_obj_id) AS (
SELECT p_object_id, p_object_id, p_object_id
UNION ALL
SELECT
ao.object_id,
CASE WHEN (ao.security_inherit_p = 'f' OR ao.context_id IS NULL)
THEN v_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 != v_security_context_root
)
select p_object_id, p.grantee_id, p.privilege
from object_context oc, acs_permissions p where p.object_id = oc.context_id;
END;
$$ LANGUAGE plpgsql stable;
--
-- procedure acs_group__member_p/3
--
CREATE OR REPLACE FUNCTION acs_group__member_p(
p_party_id integer,
p_group_id integer,
p_cascade_membership boolean
) RETURNS boolean AS $$
DECLARE
BEGIN
if p_cascade_membership then
--
-- Direct and indirect memberships
--
return count(*) > 0
from group_member_map
where group_id = p_group_id
and member_id = p_party_id;
else
--
-- Only direct memberships
--
return count(*) > 0
from acs_rels rels
where rels.rel_type = 'membership_rel'
and rels.object_id_one = p_group_id
and rels.object_id_two = p_party_id
and acs_permission.permission_p(rels.rel_id, p_party_id, 'read');
end if;
END;
$$ LANGUAGE plpgsql stable;
--
-- Changes:
-- * remove length limitation on URL segments from the data model (PostgreSQL only)
-- * function site_node__node_id()
-- + use built-in string functions instead of characterwise loop
-- + use default for last argument
-- + Improve source-code documentation
--
ALTER table site_nodes alter COLUMN name TYPE text;
DROP FUNCTION IF EXISTS site_node__node_id(varchar, integer);
--
-- procedure site_node__node_id/2
--
CREATE OR REPLACE FUNCTION site_node__node_id(
p_url varchar,
p_parent_id integer default null
) RETURNS integer AS $$
DECLARE
v_pos integer;
v_first site_nodes.name%TYPE;
v_rest text;
v_node_id integer;
v_pattern_p site_nodes.pattern_p%TYPE;
v_url text;
v_directory_p site_nodes.directory_p%TYPE;
v_trailing_slash_p boolean;
BEGIN
v_url := p_url;
if substr(v_url, length(v_url), 1) = '/' then
--
-- The URL ends with a / so it must be a directory. Strip the
-- trailing slash.
--
v_trailing_slash_p := true;
v_url := substr(v_url, 1, length(v_url) - 1);
end if;
--
-- Split the URL on the first "/" into v_first and v_rest.
--
select position('/' in v_url) into v_pos;
if v_pos = 0 then
--
-- No slash found.
--
v_first := v_url;
v_rest := null;
else
--
-- Split URL.
--
v_first := substr(v_url, 1, v_pos - 1);
v_rest := substr(v_url, v_pos + 1);
end if;
if p_parent_id is not null then
select node_id, directory_p into v_node_id, v_directory_p
from site_nodes
where parent_id = p_parent_id
and name = v_first;
else
--
-- This is typically just the query on the (empty) top-node.
--
select node_id, directory_p into v_node_id, v_directory_p
from site_nodes
where parent_id is null
and name = v_first;
end if;
if NOT FOUND then
return site_node__find_pattern(p_parent_id);
end if;
--
-- v_first was found.
--
if v_rest is null then
--
-- We are at the end of the URL. If we have a trailing slash and
-- the site node is not a directory, return the result of
-- find_pattern(). Otherwise, return the found node_id
--
if v_trailing_slash_p is true and v_directory_p is false then
return site_node__find_pattern(p_parent_id);
else
return v_node_id;
end if;
else
--
-- Call the function recursively on the v_rest chunk
--
return site_node__node_id(v_rest, v_node_id);
end if;
END;
$$ LANGUAGE plpgsql;
This diff is collapsed.
begin;
-- added
select define_function_args('util__foreign_key_exists','table,column,reftable,refcolumn');
--
-- procedure util__foreign_key_exists/4
--
CREATE OR REPLACE FUNCTION util__foreign_key_exists(
p_table text,
p_column text,
p_reftable text,
p_refcolumn text
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (
select 1 from
information_schema.table_constraints AS tc,
information_schema.key_column_usage AS kcu,
information_schema.constraint_column_usage AS ccu
where tc.constraint_name = kcu.constraint_name
and tc.constraint_catalog = kcu.constraint_catalog
and tc.constraint_schema = kcu.constraint_schema
and tc.table_catalog = kcu.table_catalog
and tc.table_schema = kcu.table_schema
and ccu.constraint_name = tc.constraint_name
and ccu.constraint_catalog = kcu.constraint_catalog
and ccu.constraint_schema = kcu.constraint_schema
and ccu.table_catalog = kcu.table_catalog
and ccu.table_schema = kcu.table_schema
and tc.constraint_type = 'FOREIGN KEY'
and tc.table_name = p_table
and kcu.column_name = p_column
and ccu.table_name = p_reftable
and ccu.column_name = p_refcolumn);
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__unique_exists','table,column,single_p;true');
--
-- procedure util__unique_exists/3
--
CREATE OR REPLACE FUNCTION util__unique_exists(
p_table text,
p_column text,
p_single_p boolean default true
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (select 1
from
information_schema.table_constraints AS tc,
information_schema.key_column_usage AS kcu
where tc.constraint_name = kcu.constraint_name
and tc.constraint_catalog = kcu.constraint_catalog
and tc.constraint_schema = kcu.constraint_schema
and tc.table_catalog = kcu.table_catalog
and tc.table_schema = kcu.table_schema
and tc.constraint_type = 'UNIQUE'
and tc.table_name = p_table
and kcu.column_name = p_column
and (not p_single_p or (
-- this to ensure the constraint involves only one
-- column
select count(*) from information_schema.key_column_usage
where constraint_name = kcu.constraint_name
and constraint_catalog = kcu.constraint_catalog
and constraint_schema = kcu.constraint_schema) = 1));
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__primary_key_exists','table,column,single_p;true');
--
-- procedure util__unique_exists/3
--
CREATE OR REPLACE FUNCTION util__primary_key_exists(
p_table text,
p_column text,
p_single_p boolean default true
) RETURNS boolean AS $$
DECLARE
BEGIN
return exists (select 1
from
information_schema.table_constraints AS tc,
information_schema.key_column_usage AS kcu
where tc.constraint_name = kcu.constraint_name
and tc.constraint_catalog = kcu.constraint_catalog
and tc.constraint_schema = kcu.constraint_schema
and tc.table_catalog = kcu.table_catalog
and tc.table_schema = kcu.table_schema
and tc.constraint_type = 'PRIMARY KEY'
and tc.table_name = p_table
and kcu.column_name = p_column
and (not p_single_p or (
-- this to ensure the constraint involves only one
-- column
select count(*) from information_schema.key_column_usage
where constraint_name = kcu.constraint_name
and constraint_catalog = kcu.constraint_catalog
and constraint_schema = kcu.constraint_schema) = 1));
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__not_null_exists','table,column');
--
-- procedure util__not_null_exists/2
--
--
-- procedure util__not_null_exists/2
--
CREATE OR REPLACE FUNCTION util__not_null_exists(
p_table text,
p_column text
) RETURNS boolean AS $$
DECLARE
BEGIN
return (
coalesce((
select is_nullable = 'NO'
from information_schema.columns
where table_name = p_table
and column_name = p_column), false));
END;
$$ LANGUAGE plpgsql;
-- added
select define_function_args('util__get_default','table,column');
--
-- procedure util__get_default/2
--
CREATE OR REPLACE FUNCTION util__get_default(
p_table text,
p_column text
) RETURNS information_schema.columns.column_default%TYPE AS $$
DECLARE
BEGIN
return (
select column_default
from information_schema.columns
where table_name = p_table
and column_name = p_column);
END;
$$ LANGUAGE plpgsql;
end;
begin;
-- added
select define_function_args('util__get_primary_keys','table');
--
-- procedure util__get_primary_keys/1
--
CREATE OR REPLACE FUNCTION util__get_primary_keys(
p_table text
) RETURNS SETOF pg_attribute.attname%TYPE AS $$
SELECT a.attname
FROM pg_index i
JOIN pg_attribute a ON a.attrelid = i.indrelid
AND a.attnum = ANY(i.indkey)
WHERE i.indrelid = p_table::regclass
AND i.indisprimary;
$$ LANGUAGE sql;
end;
CREATE or REPLACE FUNCTION inline_0 ()
returns integer as $$
DECLARE
v_dummy integer;
BEGIN
SELECT 1 FROM pg_views WHERE viewname = 'anon_func_seq' INTO v_dummy;
IF found THEN
DROP VIEW IF EXISTS anon_func_seq;
IF EXISTS (SELECT 0 FROM pg_class WHERE relname = 't_anon_func_seq' ) THEN
ALTER SEQUENCE t_anon_func_seq RENAME TO anon_func_seq;
END IF;
END IF;
return 1;
END;
$$ language plpgsql;
select inline_0();
drop function inline_0();
--
-- Since many years, new installations are created with "Registered
-- Users" (object_id -2) having object_type as "application_group" and
-- the context id of the main subsite (see
-- acs-kernel/sql/postgresql/acs-install.sql).
--
-- However, it seems as if some prior upgrade scripts have not cared
-- sufficiently to update all installation correctly (some have still
-- "group", some have no context_id set). This upgrade script tries to
-- bring everything in sync such that "newer" and "older"
-- installations behave the same.
--
DO $$
DECLARE
v_main_subsite_id acs_objects.object_id%TYPE;
BEGIN
select object_id from site_nodes
into v_main_subsite_id
where parent_id is NULL order by node_id limit 1;
update acs_objects
set context_id = v_main_subsite_id
where object_id = -2
and context_id is NULL;
update acs_objects
set object_type = 'application_group'
where object_id = -2
and object_type = 'group';
update acs_objects
set title = '#acs-kernel.Registered_Users#'
where object_id = -2;
END$$;
--
-- The DO statement is used to allow this script to be run multiple
-- times without raising exceptions
--
DO $$
DECLARE
v_found boolean;
BEGIN
--
-- Was the column already renamed?
--
SELECT exists(
SELECT column_name
FROM information_schema.columns
WHERE table_name = 'party_approved_member_map' and column_name = 'originating_rel_id'
) INTO v_found;
if v_found IS FALSE then
--
-- Use a better name for attribute "tag" in party_approved_member_map
--
alter table party_approved_member_map rename tag to originating_rel_id;
--
-- Create an "identity relationship"
--
perform acs_object__new(-10, 'relationship') from dual;
insert into acs_rels (rel_id, rel_type, object_id_one, object_id_two) values (-10, 'relationship', 0, 0);
end if;
END$$;
--
-- Use the new identity relation instead of value "0"
--
update party_approved_member_map
set originating_rel_id = -10
where originating_rel_id = 0;
--
-- Make sure, there are no leftovers in the old "tag" attribute, which
-- did not have a foreign key defined
--
delete from party_approved_member_map
where originating_rel_id in
(select originating_rel_id from party_approved_member_map
except select rel_id from acs_rels);
--
-- Add a foreign key ...
-- ... and let the script run multiple times...
--
ALTER TABLE party_approved_member_map
DROP CONSTRAINT IF EXISTS party_member_rel_id_fk;
ALTER TABLE party_approved_member_map
ADD CONSTRAINT party_member_rel_id_fk foreign key (originating_rel_id)
references acs_rels on delete cascade;
DO $$
DECLARE
v_found boolean;
BEGIN
--
-- Was the index already created?
--
SELECT exists(
SELECT relname from pg_class
WHERE relname ='party_member_party_idx'
) into v_found;
if v_found IS FALSE then
--
-- speed up referential integrity
--
create index party_member_party_idx on party_approved_member_map(party_id);
create index party_member_originating_idx on party_approved_member_map(originating_rel_id);
end if;
END$$;
--
-- Redefine the stored procedures/functions referring to the attribute
-- "tag".
--
--
-- procedure party_approved_member__add_one/3
--
CREATE OR REPLACE FUNCTION party_approved_member__add_one(
p_party_id integer,
p_member_id integer,
p_rel_id integer
) RETURNS integer AS $$
DECLARE
BEGIN
insert into party_approved_member_map
(party_id, member_id, originating_rel_id)
values
(p_party_id, p_member_id, p_rel_id);
return 1;
END;
$$ LANGUAGE plpgsql;
--
-- procedure party_approved_member__remove_one/3
--
CREATE OR REPLACE FUNCTION party_approved_member__remove_one(
p_party_id integer,
p_member_id integer,
p_rel_id integer
) RETURNS integer AS $$
DECLARE
BEGIN
delete from party_approved_member_map
where party_id = p_party_id
and member_id = p_member_id
and originating_rel_id = p_rel_id;
return 1;
END;
$$ LANGUAGE plpgsql;
-- Triggers to maintain party_approved_member_map when parties are created or
-- destroyed. These don't call the above helper functions because we're just
-- creating the identity row for the party.
CREATE OR REPLACE FUNCTION parties_in_tr () RETURNS trigger AS $$
BEGIN
insert into party_approved_member_map
(party_id, member_id, originating_rel_id)
values
(new.party_id, new.party_id, -10);
return new;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE FUNCTION rel_segments_in_tr () RETURNS trigger AS $$
BEGIN
insert into party_approved_member_map
(party_id, member_id, originating_rel_id)
select new.segment_id, element_id, rel_id
from group_element_index
where group_id = new.group_id
and rel_type = new.rel_type;
return new;
END;
$$ LANGUAGE plpgsql;
--
-- Improve get_func_definition() to return SQL function/procedure
-- definitions with argument names and defaults
--
--
-- procedure get_func_definition/2
--
CREATE OR REPLACE FUNCTION get_func_definition(
fname varchar,
args oidvector
) RETURNS text AS $PROC$
DECLARE
v_funcdef text default '';
v_args varchar;
v_nargs integer;
v_src text;
v_rettype varchar;
BEGIN
select pg_get_function_arguments(oid), pronargs, prosrc, -- was 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 :=
E'--\n-- ' || fname || '/' || v_nargs || E'\n--'
|| E'\ncreate or replace function ' || fname || E'(\n '
|| replace(v_args, ', ', E',\n ')
|| E'\n) returns ' || v_rettype
|| E' as $$\n' || v_src || '$$ language plpgsql;';
return v_funcdef;
END;
$PROC$ LANGUAGE plpgsql stable strict;
--
-- Slightly faster (around 10%) versions for the base permission query functions.
-- In the new versions the lookup of acs__magic_object_id was moved out of the loop.
--
--
-- procedure acs_permission__permission_p/3
--
DROP FUNCTION IF EXISTS acs_permission__permission_p(integer, integer, varchar);
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
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
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 v_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 != v_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
--
-- procedure acs_permission__permission_p_recursive_array/3
--
DROP FUNCTION IF EXISTS acs_permission__permission_p_recursive_array(integer[], integer, varchar);
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 $$
DECLARE
v_security_context_root integer;
BEGIN
v_security_context_root := acs__magic_object_id('security_context_root');
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 v_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 != v_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;
--
-- Type discrepancy cleanup for object_types in OpenACS:
--
-- Fixing an inconsistency introduced in 2002: In PostgreSQL the table
-- "acs_object_types" the type of column "object_type" is
-- varchar(1000), while the supertype has varchar(100);
--
-- https://github.com/openacs/openacs-core/blame/oacs-5-9/packages/acs-kernel/sql/postgresql/acs-metadata-create.sql#L26
--
-- Similarly, the type of column acs_objects.object_type has
-- varchar(100). These attributes have a length of 1000 in the Oracle
-- versions. An additional consequence of this discrepancy is that
-- casts are required when resolving the object-type-tree with
-- recursive queries. So, aligning these column types is desirable.
-- Another option would be to use type "text" instead if
-- varchar(1000), but such a change would require a much larger
-- cleanup and the result would not be compatible with Oracle.
--
-- Unfortunately, there are several other tables affected to address
-- this type discrepancies, since these use the object_type as foreign
-- keys.
--
ALTER TABLE acs_object_types ALTER COLUMN supertype TYPE varchar(1000);
-- ALTER TABLE acs_objects ALTER COLUMN object_type TYPE varchar(1000);
ALTER TABLE acs_attribute_descriptions ALTER COLUMN object_type TYPE varchar(1000);
-- ALTER TABLE acs_attributes ALTER COLUMN object_type TYPE varchar(1000);
ALTER TABLE acs_object_type_tables ALTER COLUMN object_type TYPE varchar(1000);
-- ALTER TABLE acs_rel_types ALTER COLUMN object_type_one TYPE varchar(1000);
-- ALTER TABLE acs_rel_types ALTER COLUMN object_type_two TYPE varchar(1000);
-- ALTER TABLE acs_rel_types ALTER COLUMN rel_type TYPE varchar(1000);
ALTER TABLE acs_static_attr_values ALTER COLUMN object_type TYPE varchar(1000);
ALTER TABLE group_type_rels ALTER COLUMN group_type TYPE varchar(1000);
ALTER TABLE group_types ALTER COLUMN group_type TYPE varchar(1000);
ALTER TABLE group_rels ALTER COLUMN rel_type TYPE varchar(1000);
ALTER TABLE group_type_rels ALTER COLUMN rel_type TYPE varchar(1000);
-- ALTER TABLE group_element_index ALTER COLUMN rel_type TYPE varchar(1000);
--
-- Unfortunately, we can't do simply
--
-- ALTER TABLE acs_objects ALTER COLUMN object_type TYPE varchar(1000);
--
-- since many views include the attribute "object_type", including
-- many application packages. The genererally recommended way is to
-- drop and recreate the views, but this is for a kernel upgrade not
-- feasible. Since the length change is not a real type change, we can
-- simply update the the length information in the pg_attribute table.
WITH RECURSIVE dependent_views AS (
SELECT c.oid::REGCLASS AS view_name
FROM pg_class c
WHERE c.relname = 'acs_objects'
UNION ALL
SELECT DISTINCT r.ev_class::REGCLASS AS view_name
FROM pg_depend d
JOIN pg_rewrite r ON (r.oid = d.objid)
JOIN dependent_views ON (dependent_views.view_name = d.refobjid)
WHERE d.refobjsubid != 0
)
UPDATE pg_attribute
SET atttypmod = 1000 + 4
FROM dependent_views
WHERE pg_attribute.attrelid = dependent_views.view_name
AND pg_attribute.attname = 'object_type';
--
-- ALTER TABLE acs_attributes ALTER COLUMN object_type TYPE varchar(1000); --deps
--
WITH RECURSIVE dependent_views AS (
SELECT c.oid::REGCLASS AS view_name
FROM pg_class c
WHERE c.relname = 'acs_attributes'
UNION ALL
SELECT DISTINCT r.ev_class::REGCLASS AS view_name
FROM pg_depend d
JOIN pg_rewrite r ON (r.oid = d.objid)
JOIN dependent_views ON (dependent_views.view_name = d.refobjid)
WHERE d.refobjsubid != 0
)
UPDATE pg_attribute
SET atttypmod = 1000 + 4
FROM dependent_views
WHERE pg_attribute.attrelid = dependent_views.view_name
AND pg_attribute.attname = 'object_type';
--
-- ALTER TABLE acs_rel_types ALTER COLUMN object_type_one TYPE varchar(1000);
-- ALTER TABLE acs_rel_types ALTER COLUMN object_type_two TYPE varchar(1000);
-- ALTER TABLE acs_rel_types ALTER COLUMN rel_type TYPE varchar(1000);
--
WITH RECURSIVE dependent_views AS (
SELECT c.oid::REGCLASS AS view_name
FROM pg_class c
WHERE c.relname = 'acs_rel_types'
UNION ALL
SELECT DISTINCT r.ev_class::REGCLASS AS view_name
FROM pg_depend d
JOIN pg_rewrite r ON (r.oid = d.objid)
JOIN dependent_views ON (dependent_views.view_name = d.refobjid)
WHERE d.refobjsubid != 0
)
UPDATE pg_attribute
SET atttypmod = 1000 + 4
FROM dependent_views
WHERE pg_attribute.attrelid = dependent_views.view_name
AND pg_attribute.attname in ('object_type_one', 'object_type_two', 'rel_type');
---
-- ALTER TABLE group_element_index ALTER COLUMN rel_type TYPE varchar(1000);
--
WITH RECURSIVE dependent_views AS (
SELECT c.oid::REGCLASS AS view_name
FROM pg_class c
WHERE c.relname = 'group_element_index'
UNION ALL
SELECT DISTINCT r.ev_class::REGCLASS AS view_name
FROM pg_depend d
JOIN pg_rewrite r ON (r.oid = d.objid)
JOIN dependent_views ON (dependent_views.view_name = d.refobjid)
WHERE d.refobjsubid != 0
)
UPDATE pg_attribute
SET atttypmod = 1000 + 4
FROM dependent_views
WHERE pg_attribute.attrelid = dependent_views.view_name
AND pg_attribute.attname = 'rel_type';
--
-- procedure acs_group__member_p/3
--
CREATE OR REPLACE FUNCTION acs_group__member_p(
p_party_id integer,
p_group_id integer,
p_cascade_membership boolean
) RETURNS boolean AS $$
DECLARE
BEGIN
if p_cascade_membership then
return count(*) > 0
from group_member_map
where group_id = p_group_id and
member_id = p_party_id;
else
return count(*) > 0
from acs_rels rels, acs_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 = p_group_id
and rels.object_id_two = p_party_id;
end if;
END;
$$ LANGUAGE plpgsql stable;
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