mirror of
https://gitlab.com/davical-project/davical.git
synced 2026-01-27 00:33:34 +00:00
Windows support for database creation by Dávid Takács
This commit is contained in:
parent
2e5f82c0ef
commit
48853d4668
96
dba/windows/awl-tables.sql
Normal file
96
dba/windows/awl-tables.sql
Normal file
@ -0,0 +1,96 @@
|
||||
-- Tables needed for AWL Libraries
|
||||
|
||||
BEGIN;
|
||||
|
||||
CREATE TABLE supported_locales (
|
||||
locale TEXT PRIMARY KEY,
|
||||
locale_name_en TEXT,
|
||||
locale_name_locale TEXT
|
||||
);
|
||||
|
||||
-- This is the table of users for the system
|
||||
CREATE TABLE usr (
|
||||
user_no SERIAL PRIMARY KEY,
|
||||
active BOOLEAN DEFAULT TRUE,
|
||||
email_ok TIMESTAMPTZ,
|
||||
joined TIMESTAMPTZ DEFAULT current_timestamp,
|
||||
updated TIMESTAMPTZ,
|
||||
last_used TIMESTAMPTZ,
|
||||
username TEXT NOT NULL, -- Note UNIQUE INDEX below constains case-insensitive uniqueness
|
||||
password TEXT,
|
||||
fullname TEXT,
|
||||
email TEXT,
|
||||
config_data TEXT,
|
||||
date_format_type TEXT DEFAULT 'E', -- default to english date format dd/mm/yyyy
|
||||
locale TEXT
|
||||
);
|
||||
CREATE FUNCTION max_usr() RETURNS INT4 AS 'SELECT max(user_no) FROM usr' LANGUAGE 'sql';
|
||||
CREATE UNIQUE INDEX usr_sk1_unique_username ON usr ( lower(username) );
|
||||
|
||||
CREATE TABLE usr_setting (
|
||||
user_no INT4 REFERENCES usr ( user_no ),
|
||||
setting_name TEXT,
|
||||
setting_value TEXT,
|
||||
PRIMARY KEY ( user_no, setting_name )
|
||||
);
|
||||
|
||||
CREATE FUNCTION get_usr_setting(INT4,TEXT)
|
||||
RETURNS TEXT
|
||||
AS 'SELECT setting_value FROM usr_setting
|
||||
WHERE usr_setting.user_no = $1
|
||||
AND usr_setting.setting_name = $2 ' LANGUAGE 'sql';
|
||||
|
||||
CREATE TABLE roles (
|
||||
role_no SERIAL PRIMARY KEY,
|
||||
role_name TEXT
|
||||
);
|
||||
CREATE FUNCTION max_roles() RETURNS INT4 AS 'SELECT max(role_no) FROM roles' LANGUAGE 'sql';
|
||||
|
||||
|
||||
CREATE TABLE role_member (
|
||||
role_no INT4 REFERENCES roles ( role_no ),
|
||||
user_no INT4 REFERENCES usr ( user_no )
|
||||
);
|
||||
|
||||
|
||||
CREATE TABLE session (
|
||||
session_id SERIAL PRIMARY KEY,
|
||||
user_no INT4 REFERENCES usr ( user_no ),
|
||||
session_start TIMESTAMPTZ DEFAULT current_timestamp,
|
||||
session_end TIMESTAMPTZ DEFAULT current_timestamp,
|
||||
session_key TEXT,
|
||||
session_config TEXT
|
||||
);
|
||||
CREATE FUNCTION max_session() RETURNS INT4 AS 'SELECT max(session_id) FROM session' LANGUAGE 'sql';
|
||||
|
||||
CREATE TABLE tmp_password (
|
||||
user_no INT4 REFERENCES usr ( user_no ),
|
||||
password TEXT,
|
||||
valid_until TIMESTAMPTZ DEFAULT (current_timestamp + '1 day'::interval)
|
||||
);
|
||||
COMMIT;
|
||||
|
||||
BEGIN;
|
||||
GRANT SELECT,INSERT,UPDATE ON
|
||||
usr
|
||||
, usr_setting
|
||||
, roles
|
||||
, role_member
|
||||
, session
|
||||
, tmp_password
|
||||
TO general;
|
||||
GRANT SELECT,UPDATE ON
|
||||
usr_user_no_seq
|
||||
, session_session_id_seq
|
||||
TO general;
|
||||
|
||||
GRANT SELECT ON
|
||||
supported_locales
|
||||
TO general;
|
||||
|
||||
GRANT DELETE ON
|
||||
tmp_password
|
||||
, role_member
|
||||
TO general;
|
||||
|
||||
COMMIT;
|
||||
77
dba/windows/create-database.bat
Normal file
77
dba/windows/create-database.bat
Normal file
@ -0,0 +1,77 @@
|
||||
@echo off
|
||||
rem Build the RSCDS database
|
||||
|
||||
setlocal
|
||||
|
||||
if db%1 EQU db (
|
||||
echo Usage: create-database dbnameprefix [adminpassword [pguser]]
|
||||
exit /B 1
|
||||
)
|
||||
set DBNAME=%1-rscds
|
||||
set ADMINPW=%2
|
||||
|
||||
set DBADIR=%CD%
|
||||
|
||||
set PGDIR=%PGLOCALEDIR%\..\..\bin
|
||||
IF usr%3 NEQ usr ( set USERNAME=%3 )
|
||||
|
||||
rem FIXME: Need to check that the database was actually created.
|
||||
%PGDIR%\createdb -E UTF8 -T template0 -U %USERNAME% %DBNAME%
|
||||
if %ERRORLEVEL% NEQ 0 (
|
||||
echo Unable to create database
|
||||
exit /B 2
|
||||
)
|
||||
|
||||
rem This will fail if the language already exists, but it should not
|
||||
rem because we created from template0.
|
||||
%PGDIR%\createlang -U %USERNAME% plpgsql %DBNAME%
|
||||
|
||||
rem Test if egrep is available
|
||||
rem You can download egrep.exe for Windows e.g. from UnxUtils: http://unxutils.sourceforge.net/):
|
||||
egrep 2>NULL
|
||||
if ERRORLEVEL 3 (
|
||||
rem No egrep
|
||||
%PGDIR%\psql -q -f %DBADIR%/rscds.sql %DBNAME% 2>&1 -U %USERNAME%
|
||||
) ELSE (
|
||||
rem egrep is available
|
||||
%PGDIR%\psql -q -f %DBADIR%/rscds.sql %DBNAME% 2>&1 -U %USERNAME% | egrep -v "(^CREATE |^GRANT|^BEGIN|^COMMIT| NOTICE: )"
|
||||
)
|
||||
del NULL
|
||||
%PGDIR%\psql -q -f %DBADIR%/grants.sql %DBNAME% 2>&1 -U %USERNAME% | egrep -v "(^GRANT)"
|
||||
|
||||
%PGDIR%\psql -q -f %DBADIR%/caldav_functions.sql %DBNAME% -U %USERNAME%
|
||||
|
||||
%PGDIR%\psql -q -f %DBADIR%/base-data.sql %DBNAME% -U %USERNAME%
|
||||
|
||||
rem We can override the admin password generation for regression testing predictability
|
||||
rem if [ %ADMINPW}" = "" ] ; then
|
||||
rem #
|
||||
rem # Generate a random administrative password. If pwgen is available we'll use that,
|
||||
rem # otherwise try and hack something up using a few standard utilities
|
||||
rem ADMINPW="`pwgen -Bcny 2>/dev/null | tr \"\\\'\" '^='`"
|
||||
rem fi
|
||||
rem
|
||||
rem if [ "$ADMINPW" = "" ] ; then
|
||||
rem # OK. They didn't supply one, and pwgen didn't work, so we hack something
|
||||
rem # together from /dev/random ...
|
||||
rem ADMINPW="`dd if=/dev/urandom bs=512 count=1 2>/dev/null | tr -c -d "[:alnum:]" | cut -c2-9`"
|
||||
rem fi
|
||||
rem
|
||||
rem # Right. We're getting desperate now. We'll have to use a default password
|
||||
rem # and hope that they change it to something more sensible.
|
||||
IF pw%ADMINPW% EQU pw ( set ADMINPW=please change this password )
|
||||
rem fi
|
||||
|
||||
%PGDIR%\psql -q -c "UPDATE usr SET password = '**%ADMINPW%' WHERE user_no = 1;" %DBNAME% -U %USERNAME%
|
||||
|
||||
echo The password for the 'admin' user has been set to "%ADMINPW%"
|
||||
|
||||
rem The supported locales are in a separate file to make them easier to upgrade
|
||||
%PGDIR%\psql -q -f %DBADIR%/supported_locales.sql %DBNAME% -U %USERNAME%
|
||||
|
||||
echo DONE
|
||||
|
||||
:END
|
||||
|
||||
endlocal
|
||||
|
||||
135
dba/windows/rscds.sql
Normal file
135
dba/windows/rscds.sql
Normal file
@ -0,0 +1,135 @@
|
||||
-- Really Simple CalDAV Store - Database Schema
|
||||
--
|
||||
|
||||
-- Use the usr, group and schema management stufffrom libawl-php
|
||||
\i awl-tables.sql
|
||||
\i schema-management.sql
|
||||
|
||||
-- The main event. Where we store the things the calendar throws at us.
|
||||
CREATE TABLE caldav_data (
|
||||
user_no INT references usr(user_no),
|
||||
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),
|
||||
|
||||
PRIMARY KEY ( user_no, dav_name )
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON caldav_data TO general;
|
||||
|
||||
-- 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
|
||||
);
|
||||
GRANT SELECT,INSERT ON time_zone TO general;
|
||||
|
||||
-- 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),
|
||||
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,
|
||||
|
||||
-- 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
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON calendar_item TO general;
|
||||
|
||||
|
||||
-- Something that can look like a filesystem hierarchy where we store stuff
|
||||
CREATE TABLE collection (
|
||||
user_no INT references usr(user_no),
|
||||
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,
|
||||
|
||||
PRIMARY KEY ( user_no, dav_name )
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON collection TO general;
|
||||
|
||||
-- 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
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON relationship_type TO general;
|
||||
GRANT SELECT,UPDATE ON relationship_type_rt_id_seq TO general;
|
||||
|
||||
CREATE TABLE relationship (
|
||||
from_user INT REFERENCES usr (user_no) ON UPDATE CASCADE,
|
||||
to_user INT REFERENCES usr (user_no) ON UPDATE CASCADE,
|
||||
rt_id INT REFERENCES relationship_type (rt_id) ON UPDATE CASCADE,
|
||||
|
||||
PRIMARY KEY ( from_user, to_user, rt_id )
|
||||
);
|
||||
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON relationship TO general;
|
||||
|
||||
|
||||
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);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON locks TO general;
|
||||
|
||||
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 ),
|
||||
PRIMARY KEY ( dav_name, property_name )
|
||||
);
|
||||
|
||||
CREATE INDEX properties_dav_name_idx ON property(dav_name);
|
||||
GRANT SELECT,INSERT,UPDATE,DELETE ON property TO general;
|
||||
|
||||
|
||||
SELECT new_db_revision(1,1,7, 'July' );
|
||||
59
dba/windows/schema-management.sql
Normal file
59
dba/windows/schema-management.sql
Normal file
@ -0,0 +1,59 @@
|
||||
-- SQL file for AWL tables
|
||||
|
||||
-- Table for holding the schema version so we can be more structured in future
|
||||
CREATE TABLE awl_db_revision (
|
||||
schema_id INT4,
|
||||
schema_major INT4,
|
||||
schema_minor INT4,
|
||||
schema_patch INT4,
|
||||
schema_name TEXT,
|
||||
applied_on TIMESTAMP WITH TIME ZONE DEFAULT current_timestamp
|
||||
);
|
||||
GRANT SELECT ON awl_db_revision TO general;
|
||||
|
||||
CREATE or REPLACE FUNCTION check_db_revision( INT, INT, INT ) RETURNS BOOLEAN AS '
|
||||
DECLARE
|
||||
major ALIAS FOR $1;
|
||||
minor ALIAS FOR $2;
|
||||
patch ALIAS FOR $3;
|
||||
matching INT;
|
||||
BEGIN
|
||||
SELECT COUNT(*) INTO matching FROM awl_db_revision
|
||||
WHERE schema_major = major AND schema_minor = minor AND schema_patch = patch;
|
||||
IF matching != 1 THEN
|
||||
RAISE EXCEPTION ''Database has not been upgraded to %.%.%'', major, minor, patch;
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
SELECT COUNT(*) INTO matching FROM awl_db_revision
|
||||
WHERE (schema_major = major AND schema_minor = minor AND schema_patch > patch)
|
||||
OR (schema_major = major AND schema_minor > minor)
|
||||
OR (schema_major > major)
|
||||
;
|
||||
IF matching >= 1 THEN
|
||||
RAISE EXCEPTION ''Database revisions after %.%.% have already been applied.'', major, minor, patch;
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
RETURN TRUE;
|
||||
END;
|
||||
' LANGUAGE 'plpgsql';
|
||||
|
||||
-- The schema_id should always be incremented. The major / minor / patch level should
|
||||
-- be incremented as seems appropriate...
|
||||
CREATE or REPLACE FUNCTION new_db_revision( INT, INT, INT, TEXT ) RETURNS BOOLEAN AS '
|
||||
DECLARE
|
||||
major ALIAS FOR $1;
|
||||
minor ALIAS FOR $2;
|
||||
patch ALIAS FOR $3;
|
||||
blurb ALIAS FOR $4;
|
||||
new_id INT;
|
||||
BEGIN
|
||||
SELECT MAX(schema_id) + 1 INTO new_id FROM awl_db_revision;
|
||||
IF NOT FOUND OR new_id IS NULL THEN
|
||||
new_id := 1;
|
||||
END IF;
|
||||
INSERT INTO awl_db_revision (schema_id, schema_major, schema_minor, schema_patch, schema_name)
|
||||
VALUES( new_id, major, minor, patch, blurb );
|
||||
RETURN TRUE;
|
||||
END;
|
||||
' LANGUAGE 'plpgsql';
|
||||
SELECT new_db_revision(1,1,0, 'Dawn' );
|
||||
Loading…
x
Reference in New Issue
Block a user