mirror of
https://gitlab.com/davical-project/davical.git
synced 2026-01-27 00:33:34 +00:00
281 lines
9.4 KiB
PL/PgSQL
281 lines
9.4 KiB
PL/PgSQL
-- DAViCal CalDAV Server - Database Schema
|
|
--
|
|
|
|
|
|
-- Given a verbose DAV: or CalDAV: privilege name return the bitmask
|
|
CREATE or REPLACE FUNCTION privilege_to_bits( TEXT ) RETURNS BIT(24) AS $$
|
|
DECLARE
|
|
raw_priv ALIAS FOR $1;
|
|
in_priv TEXT;
|
|
BEGIN
|
|
in_priv := trim(lower(regexp_replace(raw_priv, '^.*:', '')));
|
|
IF in_priv = 'all' THEN
|
|
RETURN ~ 0::BIT(24);
|
|
END IF;
|
|
|
|
RETURN (CASE
|
|
WHEN in_priv = 'read' THEN 4609 -- 1 + 512 + 4096
|
|
WHEN in_priv = 'write' THEN 198 -- 2 + 4 + 64 + 128
|
|
WHEN in_priv = 'write-properties' THEN 2
|
|
WHEN in_priv = 'write-content' THEN 4
|
|
WHEN in_priv = 'unlock' THEN 8
|
|
WHEN in_priv = 'read-acl' THEN 16
|
|
WHEN in_priv = 'read-current-user-privilege-set' THEN 32
|
|
WHEN in_priv = 'bind' THEN 64
|
|
WHEN in_priv = 'unbind' THEN 128
|
|
WHEN in_priv = 'write-acl' THEN 256
|
|
WHEN in_priv = 'read-free-busy' THEN 4608 -- 512 + 4096
|
|
WHEN in_priv = 'schedule-deliver' THEN 7168 -- 1024 + 2048 + 4096
|
|
WHEN in_priv = 'schedule-deliver-invite' THEN 1024
|
|
WHEN in_priv = 'schedule-deliver-reply' THEN 2048
|
|
WHEN in_priv = 'schedule-query-freebusy' THEN 4096
|
|
WHEN in_priv = 'schedule-send' THEN 57344 -- 8192 + 16384 + 32768
|
|
WHEN in_priv = 'schedule-send-invite' THEN 8192
|
|
WHEN in_priv = 'schedule-send-reply' THEN 16384
|
|
WHEN in_priv = 'schedule-send-freebusy' THEN 32768
|
|
ELSE 0 END)::BIT(24);
|
|
END
|
|
$$
|
|
LANGUAGE 'PlPgSQL' IMMUTABLE STRICT;
|
|
|
|
|
|
|
|
-- This sequence is used in a number of places so that any DAV resource will have a unique ID
|
|
CREATE SEQUENCE dav_id_seq;
|
|
|
|
-- Something that can look like a filesystem hierarchy where we store stuff
|
|
CREATE TABLE collection (
|
|
user_no INT references usr(user_no) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
parent_container TEXT,
|
|
dav_name TEXT,
|
|
dav_etag TEXT,
|
|
dav_displayname TEXT,
|
|
is_calendar BOOLEAN,
|
|
created TIMESTAMP WITH TIME ZONE,
|
|
modified TIMESTAMP WITH TIME ZONE,
|
|
public_events_only BOOLEAN NOT NULL DEFAULT FALSE,
|
|
publicly_readable BOOLEAN NOT NULL DEFAULT FALSE,
|
|
collection_id INT8 PRIMARY KEY DEFAULT nextval('dav_id_seq'),
|
|
default_privileges BIT(24) DEFAULT privilege_to_bits('caldav:read-free-busy'),
|
|
is_addressbook BOOLEAN DEFAULT FALSE,
|
|
resourcetypes TEXT DEFAULT '<DAV::collection/>',
|
|
UNIQUE(user_no,dav_name)
|
|
);
|
|
|
|
UPDATE collection SET resourcetypes = '<DAV::collection/><urn:ietf:params:xml:ns:caldav:calendar/>' WHERE is_calendar;
|
|
|
|
|
|
-- The main event. Where we store the things the calendar throws at us.
|
|
CREATE TABLE caldav_data (
|
|
user_no INT references usr(user_no) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
dav_name TEXT,
|
|
dav_etag TEXT,
|
|
created TIMESTAMP WITH TIME ZONE,
|
|
modified TIMESTAMP WITH TIME ZONE,
|
|
caldav_data TEXT,
|
|
caldav_type TEXT,
|
|
logged_user INT references usr(user_no) ON UPDATE CASCADE ON DELETE SET DEFAULT DEFERRABLE,
|
|
dav_id INT8 UNIQUE DEFAULT nextval('dav_id_seq'),
|
|
collection_id INT8 REFERENCES collection(collection_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
|
|
PRIMARY KEY ( user_no, dav_name )
|
|
);
|
|
CREATE INDEX caldav_data_collection_id_fkey ON caldav_data(collection_id);
|
|
|
|
-- Not particularly needed, perhaps, except as a way to collect
|
|
-- a bunch of valid iCalendar time zone specifications... :-)
|
|
CREATE TABLE time_zone (
|
|
tz_id TEXT PRIMARY KEY,
|
|
tz_locn TEXT,
|
|
tz_spec TEXT
|
|
);
|
|
|
|
|
|
-- The parsed calendar item. Here we have pulled those events/todos/journals apart somewhat.
|
|
CREATE TABLE calendar_item (
|
|
user_no INT references usr(user_no) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
dav_name TEXT,
|
|
dav_etag TEXT,
|
|
|
|
-- Extracted vEvent/vTodo data
|
|
uid TEXT,
|
|
created TIMESTAMP,
|
|
last_modified TIMESTAMP,
|
|
dtstamp TIMESTAMP,
|
|
dtstart TIMESTAMP WITH TIME ZONE,
|
|
dtend TIMESTAMP WITH TIME ZONE,
|
|
due TIMESTAMP WITH TIME ZONE,
|
|
summary TEXT,
|
|
location TEXT,
|
|
description TEXT,
|
|
priority INT,
|
|
class TEXT,
|
|
transp TEXT,
|
|
rrule TEXT,
|
|
url TEXT,
|
|
percent_complete NUMERIC(7,2),
|
|
tz_id TEXT REFERENCES time_zone( tz_id ),
|
|
status TEXT,
|
|
completed TIMESTAMP WITH TIME ZONE,
|
|
dav_id INT8 UNIQUE,
|
|
collection_id INT8 REFERENCES collection(collection_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
|
|
-- Cascade updates / deletes from the caldav_data table
|
|
CONSTRAINT caldav_exists FOREIGN KEY ( user_no, dav_name )
|
|
REFERENCES caldav_data ( user_no, dav_name )
|
|
MATCH FULL ON DELETE CASCADE ON UPDATE CASCADE DEFERRABLE,
|
|
|
|
PRIMARY KEY ( user_no, dav_name )
|
|
);
|
|
CREATE INDEX calendar_item_collection_id_fkey ON calendar_item(collection_id);
|
|
|
|
|
|
|
|
-- Each user can be related to each other user. This mechanism can also
|
|
-- be used to define groups of users, since some relationships are transitive.
|
|
CREATE TABLE relationship_type (
|
|
rt_id SERIAL PRIMARY KEY,
|
|
rt_name TEXT,
|
|
rt_togroup BOOLEAN,
|
|
confers TEXT DEFAULT 'RW',
|
|
rt_fromgroup BOOLEAN,
|
|
bit_confers BIT(24) DEFAULT legacy_privilege_to_bits('RW')
|
|
);
|
|
|
|
|
|
CREATE TABLE relationship (
|
|
from_user INT REFERENCES usr (user_no) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
to_user INT REFERENCES usr (user_no) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
rt_id INT REFERENCES relationship_type (rt_id) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
bit_confers BIT(24) DEFAULT legacy_privilege_to_bits('RW'),
|
|
|
|
PRIMARY KEY ( from_user, to_user, rt_id )
|
|
);
|
|
|
|
|
|
CREATE TABLE locks (
|
|
dav_name TEXT,
|
|
opaquelocktoken TEXT UNIQUE NOT NULL,
|
|
type TEXT,
|
|
scope TEXT,
|
|
depth INT,
|
|
owner TEXT,
|
|
timeout INTERVAL,
|
|
start TIMESTAMP DEFAULT current_timestamp
|
|
);
|
|
CREATE INDEX locks_dav_name_idx ON locks(dav_name);
|
|
|
|
|
|
CREATE TABLE property (
|
|
dav_name TEXT,
|
|
property_name TEXT,
|
|
property_value TEXT,
|
|
changed_on TIMESTAMP DEFAULT current_timestamp,
|
|
changed_by INT REFERENCES usr ( user_no ) ON UPDATE CASCADE ON DELETE SET DEFAULT,
|
|
PRIMARY KEY ( dav_name, property_name )
|
|
);
|
|
CREATE INDEX properties_dav_name_idx ON property(dav_name);
|
|
|
|
|
|
CREATE TABLE freebusy_ticket (
|
|
ticket_id TEXT NOT NULL PRIMARY KEY,
|
|
user_no integer NOT NULL REFERENCES usr(user_no) ON UPDATE CASCADE ON DELETE CASCADE,
|
|
created timestamp with time zone DEFAULT current_timestamp NOT NULL
|
|
);
|
|
|
|
|
|
CREATE or REPLACE FUNCTION sync_dav_id ( ) RETURNS TRIGGER AS '
|
|
DECLARE
|
|
BEGIN
|
|
|
|
IF TG_OP = ''DELETE'' THEN
|
|
-- Just let the ON DELETE CASCADE handle this case
|
|
RETURN OLD;
|
|
END IF;
|
|
|
|
IF NEW.dav_id IS NULL THEN
|
|
NEW.dav_id = nextval(''dav_id_seq'');
|
|
END IF;
|
|
|
|
IF TG_OP = ''UPDATE'' THEN
|
|
IF OLD.dav_id = NEW.dav_id THEN
|
|
-- Nothing to do
|
|
RETURN NEW;
|
|
END IF;
|
|
END IF;
|
|
|
|
IF TG_RELNAME = ''caldav_data'' THEN
|
|
UPDATE calendar_item SET dav_id = NEW.dav_id WHERE user_no = NEW.user_no AND dav_name = NEW.dav_name;
|
|
ELSE
|
|
UPDATE caldav_data SET dav_id = NEW.dav_id WHERE user_no = NEW.user_no AND dav_name = NEW.dav_name;
|
|
END IF;
|
|
|
|
RETURN NEW;
|
|
|
|
END
|
|
' LANGUAGE 'plpgsql';
|
|
|
|
CREATE TRIGGER caldav_data_sync_dav_id AFTER INSERT OR UPDATE ON caldav_data
|
|
FOR EACH ROW EXECUTE PROCEDURE sync_dav_id();
|
|
|
|
CREATE TRIGGER calendar_item_sync_dav_id AFTER INSERT OR UPDATE ON calendar_item
|
|
FOR EACH ROW EXECUTE PROCEDURE sync_dav_id();
|
|
|
|
|
|
-- Only needs SELECT access by website.
|
|
CREATE TABLE principal_type (
|
|
principal_type_id SERIAL PRIMARY KEY,
|
|
principal_type_desc TEXT
|
|
);
|
|
|
|
|
|
-- web needs SELECT,INSERT,UPDATE,DELETE
|
|
DROP TABLE principal CASCADE;
|
|
CREATE TABLE principal (
|
|
principal_id DEFAULT nextval('dav_id_seq') PRIMARY KEY,
|
|
type_id INT8 NOT NULL REFERENCES principal_type(principal_type_id) ON UPDATE CASCADE ON DELETE RESTRICT DEFERRABLE,
|
|
user_no INT8 NULL REFERENCES usr(user_no) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
displayname TEXT,
|
|
active BOOLEAN,
|
|
default_privileges BIT(24)
|
|
);
|
|
|
|
|
|
|
|
-- Allowing identification of group members.
|
|
CREATE TABLE group_member (
|
|
group_id INT8 REFERENCES principal(principal_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
member_id INT8 REFERENCES principal(principal_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE
|
|
);
|
|
CREATE UNIQUE INDEX group_member_pk ON group_member(group_id,member_id);
|
|
CREATE INDEX group_member_sk ON group_member(member_id);
|
|
|
|
|
|
CREATE TABLE grants (
|
|
by_principal INT8 REFERENCES principal(principal_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
dav_name TEXT,
|
|
to_principal INT8 REFERENCES principal(principal_id) ON UPDATE CASCADE ON DELETE CASCADE DEFERRABLE,
|
|
privileges BIT(24),
|
|
is_group BOOLEAN,
|
|
PRIMARY KEY (dav_name, to_principal)
|
|
) WITHOUT OIDS;
|
|
|
|
|
|
CREATE TABLE sync_tokens (
|
|
sync_token SERIAL PRIMARY KEY,
|
|
collection_id INT8 REFERENCES collection(collection_id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
modification_time TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp
|
|
);
|
|
|
|
CREATE TABLE sync_changes (
|
|
sync_time TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp,
|
|
collection_id INT8 REFERENCES collection(collection_id) ON DELETE CASCADE ON UPDATE CASCADE,
|
|
sync_status INT,
|
|
dav_id INT8, -- can't REFERENCES calendar_item(dav_id) ON DELETE SET NULL ON UPDATE RESTRICT
|
|
dav_name TEXT
|
|
);
|
|
CREATE INDEX sync_processing_index ON sync_changes( collection_id, dav_id, sync_time );
|
|
|
|
|
|
SELECT new_db_revision(1,2,7, 'Juillet' );
|