From 4fbb683af55bb7f1c3d914465d00ba714b9b5384 Mon Sep 17 00:00:00 2001 From: Andrew McMillan Date: Thu, 24 Jan 2008 23:26:42 +1300 Subject: [PATCH] Move the appuser permission grants out of the database definition so we can support alternative names for the application DB user. --- dba/appuser_permissions.txt | 48 +++++++++++++++++++ dba/davical.sql | 92 ++++++++++++++++++++++++------------- dba/update-rscds-database | 67 +++++++++++++++++++++++++-- 3 files changed, 172 insertions(+), 35 deletions(-) create mode 100644 dba/appuser_permissions.txt diff --git a/dba/appuser_permissions.txt b/dba/appuser_permissions.txt new file mode 100644 index 00000000..5c8d5b4d --- /dev/null +++ b/dba/appuser_permissions.txt @@ -0,0 +1,48 @@ +# +# This file is used by update-rscds-database to set the correct +# permissions for the application user. In newer installations +# the application user will probably be called app_davical (and +# the administrative user will be called dba_davical) but in +# older installations the application user was called 'general' +# and the administrative user was probably 'postgres'. +# +# See the wiki topic 'Database/Users' for more discussion. +# +# This file includes lines like: +# GRANT SELECT,... +# which define what gets granted to the following lines like: +# ON table1, table2, sequence1, function 3, view4, ... +# no user-serviceable parts inside, all whitespace is ignored, +# your mileage should not vary :-) +# + +GRANT SELECT,INSERT,UPDATE,DELETE + ON collection + ON caldav_data + ON calendar_item + ON relationship + ON locks + ON property + ON freebusy_ticket + ON usr + ON usr_setting + ON roles + ON role_member + ON session + ON tmp_password + +GRANT SELECT,UPDATE + ON caldav_data_dav_id_seq + ON relationship_type_rt_id_seq + ON dav_id_seq + ON usr_user_no_seq + ON roles_role_no_seq + ON session_session_id_seq + +GRANT SELECT,INSERT + ON time_zone + +GRANT SELECT + ON supported_locales + ON awl_db_revision + ON relationship_type diff --git a/dba/davical.sql b/dba/davical.sql index b8dc8a0a..27ba688a 100644 --- a/dba/davical.sql +++ b/dba/davical.sql @@ -1,6 +1,23 @@ -- Really Simple CalDAV Store - Database Schema -- +-- 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, + + PRIMARY KEY ( user_no, dav_name ) +); + + -- 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, @@ -11,11 +28,11 @@ CREATE TABLE caldav_data ( caldav_data TEXT, caldav_type TEXT, logged_user INT references usr(user_no), + dav_id SERIAL UNIQUE, 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... :-) @@ -24,7 +41,7 @@ CREATE TABLE time_zone ( 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 ( @@ -51,6 +68,7 @@ CREATE TABLE calendar_item ( percent_complete NUMERIC(7,2), tz_id TEXT REFERENCES time_zone( tz_id ), status TEXT, + dav_id INT8 UNIQUE, -- Cascade updates / deletes from the caldav_data table CONSTRAINT caldav_exists FOREIGN KEY ( user_no, dav_name ) @@ -60,25 +78,6 @@ CREATE TABLE calendar_item ( PRIMARY KEY ( user_no, dav_name ) ); -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) 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, - - 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. @@ -90,8 +89,6 @@ CREATE TABLE relationship_type ( 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, @@ -101,8 +98,6 @@ CREATE TABLE relationship ( PRIMARY KEY ( from_user, to_user, rt_id ) ); -GRANT SELECT,INSERT,UPDATE,DELETE ON relationship TO general; - CREATE TABLE locks ( dav_name TEXT, @@ -114,9 +109,8 @@ CREATE TABLE locks ( 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, @@ -126,9 +120,8 @@ CREATE TABLE property ( 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; + CREATE TABLE freebusy_ticket ( ticket_id TEXT NOT NULL PRIMARY KEY, @@ -136,6 +129,43 @@ CREATE TABLE freebusy_ticket ( created timestamp with time zone DEFAULT current_timestamp NOT NULL ); -GRANT INSERT,SELECT,UPDATE,DELETE ON TABLE freebusy_ticket TO general; -SELECT new_db_revision(1,1,11, 'November' ); +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(''caldav_data_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(); + + +SELECT new_db_revision(1,1,12, 'December' ); diff --git a/dba/update-rscds-database b/dba/update-rscds-database index d00cf691..14ee22a1 100755 --- a/dba/update-rscds-database +++ b/dba/update-rscds-database @@ -1,6 +1,6 @@ #!/usr/bin/perl -w # -# Update the RSCDS database by repeatedly applying patches to it +# Update the DAViCal database by repeatedly applying patches to it # in the correct order. # @@ -12,11 +12,12 @@ use Getopt::Long qw(:config permute); # allow mixed args. # Options variables my $debug = 0; -my $dbname = "rscds"; +my $dbname = "davical"; my $dbport = 5432; my $dbuser = ""; my $dbpass = ""; my $dbhost = ""; +my $appuser = "general"; my $helpmeplease = 0; my $dbadir = $0; @@ -30,6 +31,7 @@ GetOptions ('debug!' => \$debug, 'dbpass=s' => \$dbpass, 'dbport=s' => \$dbport, 'dbhost=s' => \$dbhost, + 'appuser=s' => \$appuser, 'help' => \$helpmeplease ); show_usage() if ( $helpmeplease ); @@ -94,6 +96,10 @@ print "Supported locales updated.\n"; apply_sql_file( $dbadir, "caldav_functions.sql" ); print "CalDAV functions updated.\n"; +# Ensure the permissions are up to date +apply_permissions( $dbadir, "appuser_permissions.txt" ); +print "Database permissions updated.\n"; + # The End! exit 0; @@ -198,6 +204,10 @@ sub apply_patch { ############################################################ # Apply SQL File +# Note that this stuffs the password into an environment +# variable, which isn't ideal. If you use a .pgpass you +# can bypass that issue, but you still need it on the command +# line for this program until I get a patch from someone. ############################################################ sub apply_sql_file { @@ -218,6 +228,48 @@ sub apply_sql_file { } + +############################################################ +# Apply database permissions from file +############################################################ +sub apply_permissions { + + my $sqldir = shift; + my $permsfile = shift; + + open PERMS, '<', $sqldir."/".$permsfile; + my $dbh = DBI->connect($dsn, $dbuser, $dbpass, { AutoCommit => 1 } ) or die "Can't connect to database $dbname"; + + my $sql; + my $current_grant; + + while( ) { + next if ( /^\s*(#|--)/ ); + + /^\s*GRANT\s+(\S.*)\s*$/i && do { + $current_grant = $1; + }; + + /^\s*ON\s+(\S.*)\s*$/i && do { + defined($current_grant) or die "No GRANT before ON in $permsfile\n"; + my $doohickeys = $1; + + $sql = sprintf( "REVOKE ALL ON %s FROM %s, general", $doohickeys, $appuser ); + print $sql, "\n" if ( $debug ); + $dbh->do($sql); + + $sql = sprintf( "GRANT %s on %s to %s", $current_grant, $doohickeys, $appuser ); + print $sql, "\n" if ( $debug ); + $dbh->do($sql); + }; + + } + close(PERMS); + $dbh->disconnect; +} + + + ############################################################ # Tell the nice user how we do things. Short and sweet. ############################################################ @@ -232,9 +284,16 @@ Options are: --dbuser Connect to the database as this user. --dbport Connect to the database on this port. --dbhost Connect to the database on this host. + --appuser The username which the application uses for it's database + connection. -The program will apply patches to the database which have -not yet been applied. +The program will apply any patches to the database which have +not yet been applied, run any desired data patch scripts and set +the correct minimum permissions for the web application user. + +Rather than providing a password on the command-line it is recommended +that you use a .pgpass file in your home directory to hold the database +password. This file must be mode 600 to work. OPTHELP exit 0;