[Mpuls-commits] r4517 - in base/trunk: . mpulsweb mpulsweb/commands mpulsweb/commands/db mpulsweb/commands/db/scripts mpulsweb/commands/db/scripts/install mpulsweb.egg-info

scm-commit@wald.intevation.org scm-commit at wald.intevation.org
Mon Jan 24 22:43:25 CET 2011


Author: torsten
Date: 2011-01-24 22:43:23 +0100 (Mon, 24 Jan 2011)
New Revision: 4517

Added:
   base/trunk/mpulsweb/commands/
   base/trunk/mpulsweb/commands/__init__.py
   base/trunk/mpulsweb/commands/db/
   base/trunk/mpulsweb/commands/db/__init__.py
   base/trunk/mpulsweb/commands/db/common.py
   base/trunk/mpulsweb/commands/db/scripts/
   base/trunk/mpulsweb/commands/db/scripts/install/
   base/trunk/mpulsweb/commands/db/scripts/install/00_preconditions.sql
   base/trunk/mpulsweb/commands/db/scripts/install/01_user.sql
   base/trunk/mpulsweb/commands/db/scripts/install/02_datamodel.sql
   base/trunk/mpulsweb/commands/db/scripts/install/03_configuration.sql
   base/trunk/mpulsweb/commands/db/scripts/install/04_documents.sql
   base/trunk/mpulsweb/commands/db/scripts/install/05_appointments.sql
   base/trunk/mpulsweb/commands/db/scripts/install/06_logbook.sql
   base/trunk/mpulsweb/commands/db/scripts/install/07_news.sql
   base/trunk/mpulsweb/commands/db/scripts/install/08_tags.sql
   base/trunk/mpulsweb/commands/db/scripts/install/09_helpers.sql
   base/trunk/mpulsweb/commands/db/scripts/mpuls-create-db.sql
   base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt
   base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt.old
   base/trunk/mpulsweb/commands/db/scripts/mpuls-init-cluster.sql
   base/trunk/mpulsweb/commands/db/scripts/mpuls-init-db.sql
Modified:
   base/trunk/ChangeLog
   base/trunk/mpulsweb.egg-info/PKG-INFO
   base/trunk/mpulsweb.egg-info/SOURCES.txt
   base/trunk/mpulsweb.egg-info/entry_points.txt
   base/trunk/mpulsweb.egg-info/requires.txt
   base/trunk/setup.py
Log:
Added paster subcommands to setup a new mpulscluster. Added commands to create
and delete base database.


Modified: base/trunk/ChangeLog
===================================================================
--- base/trunk/ChangeLog	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/ChangeLog	2011-01-24 21:43:23 UTC (rev 4517)
@@ -1,3 +1,36 @@
+2011-01-24  Torsten Irlaender <torsten at intevation.de>
+
+	* mpulsweb/commands,
+	  mpulsweb/commands/db,
+	  mpulsweb/commands/db/common.py,
+	  mpulsweb/commands/db/__init__.py,
+	  mpulsweb/commands/db/scripts,
+	  mpulsweb/commands/db/scripts/mpuls-create-db.sql,
+	  mpulsweb/commands/db/scripts/mpuls-init-db.sql,
+	  mpulsweb/commands/db/scripts/mpuls-create-tables.txt.old,
+	  mpulsweb/commands/db/scripts/install,
+	  mpulsweb/commands/db/scripts/install/06_logbook.sql,
+	  mpulsweb/commands/db/scripts/install/07_news.sql,
+	  mpulsweb/commands/db/scripts/install/04_documents.sql,
+	  mpulsweb/commands/db/scripts/install/05_appointments.sql,
+	  mpulsweb/commands/db/scripts/install/08_tags.sql,
+	  mpulsweb/commands/db/scripts/install/03_configuration.sql,
+	  mpulsweb/commands/db/scripts/install/09_helpers.sql,
+	  mpulsweb/commands/db/scripts/install/02_datamodel.sql,
+	  mpulsweb/commands/db/scripts/install/01_user.sql,
+	  mpulsweb/commands/db/scripts/install/00_preconditions.sql,
+	  mpulsweb/commands/db/scripts/mpuls-create-tables.txt,
+	  mpulsweb/commands/db/scripts/mpuls-init-cluster.sql,
+	  mpulsweb/commands/__init__.py: Added new commands and init-scripts
+	  to setup a new cluster and create and drop databases within the new
+	  cluster
+	* setup.py,
+	  mpulsweb.egg-info/SOURCES.txt,
+	  mpulsweb.egg-info/PKG-INFO,
+	  mpulsweb.egg-info/entry_points.txt,
+	  mpulsweb.egg-info/requires.txt: Register new commands as paster
+	  subcommand.
+
 2011-01-21  Roland Geider <roland.geider at intevation.de>
 
 	* mpulsweb/public/styles/all.css: issue1404: differenciate the submit

Added: base/trunk/mpulsweb/commands/__init__.py
===================================================================

Added: base/trunk/mpulsweb/commands/db/__init__.py
===================================================================

Added: base/trunk/mpulsweb/commands/db/common.py
===================================================================
--- base/trunk/mpulsweb/commands/db/common.py	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/common.py	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,382 @@
+# -*- coding: utf-8 -*-
+import os
+import re
+import pylons
+import tempfile
+from paste.script.command import Command
+import shlex, subprocess
+from string import Template
+
+DIRS = [os.path.join(os.path.dirname(os.path.abspath(__file__)), 'scripts')]
+
+def get_path(filename, dir=None):
+    #print  pylons.config.get('pylons.paths').get('static_files')
+    for ROOT in DIRS[::-1]:
+        if dir:
+            path = os.path.join(ROOT, dir, filename)
+        else:
+            path = os.path.join(ROOT, filename)
+        if os.path.exists(path):
+            return path
+        path = None
+    return None 
+
+def exec_command(cmd_line, stderr=None, stdout=None, stdin=None):
+    args = shlex.split(cmd_line)
+    retcode = 1
+
+    if isinstance(stdout, str):
+        try:
+            stdout = open(stdout)
+        except Exception, e:
+            print "exception: %s" % e
+    if isinstance(stdin, str):
+        try:
+            stdin = open(stdin)
+        except Exception, e:
+            print "exception: %s" % e
+    if isinstance(stderr, str):
+        try:
+            stderr = open(stderr)
+        except Exception, e:
+            print "exception: %s" % e
+
+    try:
+        retcode = subprocess.call(args, stderr=stderr, stdout=stdout, stdin=stdin)
+    except Exception, e:
+        print "exception: %s" % e
+    return int(retcode) == 0 
+
+
+def check_connection(options, args=None):
+    # Just connect to the database. Imideatly cloes connection
+    cmd_line = "psql --host=%s --port=%s --username=%s -c '\q'" % (options.get('host'), 
+                                                      options.get('port'), 
+                                                      options.get('user'))
+    args = shlex.split(cmd_line)
+    retcode = subprocess.check_call(args)
+    return int(retcode) == 0 
+
+def check_mpulscluster(options, args=None):
+    # Just connect to the database. Imideatly cloes connection
+    cmd_line = "psql --host=%s --port=%s --username=%s -c '\q' mpuls_maintenance" % (options.get('host'), 
+                                                      options.get('port'), 
+                                                      options.get('user'))
+    return exec_command(cmd_line)
+
+def check_mpulsdb(options, args=None):
+    # Just connect to the database. Imideatly cloes connection
+    dbname = "ka_%s_db" % args[0] 
+    cmd_line = "psql --host=%s --port=%s --username=%s -c '\q' %s" % (options.get('host'), 
+                                                      options.get('port'), 
+                                                      options.get('user'),
+                                                      dbname)
+    return exec_command(cmd_line)
+
+def init_cluster(options):
+    # Just connect to the database. Imideatly cloes connection
+    cmd_line = "psql --host=%s --port=%s --username=%s -c '\i %s'" % (options.get('host'), 
+                                                      options.get('port'), 
+                                                      options.get('user'),
+                                                      get_path('mpuls-init-cluster.sql'))
+    return exec_command(cmd_line)
+
+def create_db(options, dbname):
+    # Just connect to the database. Imideatly cloes connection
+    d = {'db_name':dbname}
+    print "Creating db %s ... " % dbname,
+    sql_tmpl = Template(open(get_path('mpuls-create-db.sql')).read())
+    sql = sql_tmpl.substitute(d)
+    cmd_line = "psql --host=%s --port=%s --username=%s -t mpuls_maintenance -c '%s';" % (options.get('host'), 
+                                                    options.get('port'), 
+                                                    options.get('user'),
+                                                    sql)
+    ret = exec_command(cmd_line, stdout="/dev/null")
+    if ret:
+        print "OK"
+        return ret
+    else:
+        print "Failed"
+        return ret
+
+def create_tables(options, dbname):
+    # Just connect to the database. Imideatly cloes connection
+    r = re.compile('ERROR')
+    d = {'db_name':dbname,
+         'cm_group':'ka_%s_cm' % dbname,
+         'admin_group':'ka_%s_admin' % dbname,
+         'adm_ka_owner':'ka_%s_adm' % dbname
+         }
+    
+    sql_l = []
+    vars = """
+     SET ROLE ka_%(db_name)s_adm;
+     \set cm_group 'ka_%(db_name)s_cm'
+     \set admin_group 'ka_%(db_name)s_admin'
+     \set adm_ka_owner 'ka_%(db_name)s_adm'
+     \set db_name 'ka_%(db_name)s_db'
+    """ % d
+    sql_l.append(vars)
+    print "Creating tables in %s ... " % dbname,
+    try:
+        scripts = open(get_path('mpuls-create-tables.txt'))
+        for script in scripts.readlines():
+            try:
+                outfile = tempfile.TemporaryFile()
+                infile = tempfile.TemporaryFile()
+                sql_l.append('\i %s' % get_path(script.strip(), 'install'))
+                infile.write("\n".join(sql_l))
+                infile.seek(0)
+                cmd_line = "psql --host=%s --port=%s --username=%s ka_%s_db" % (options.get('host'), 
+                                                                options.get('port'), 
+                                                                options.get('user'),
+                                                                dbname
+                                                                )
+
+                ret = exec_command(cmd_line, stdin=infile, stdout='/dev/null', stderr=outfile)
+                outfile.seek(0)
+                errors = outfile.read()
+                if r.search(errors):
+                    print errors
+                    ret = False
+                    break
+                sql_l.pop()
+            except Exception, e:
+                print "Exception: in file %s %s" % (script, e)
+                return False
+            finally:
+                if infile:
+                    infile.close()
+                if outfile:
+                    outfile.close()
+    except Exception, e:
+        print "Exception: %s" % e
+        return False
+    finally:
+        if scripts:
+            scripts.close()
+    if ret:
+        print "OK"
+        return ret
+    else:
+        print "Failed"
+        return ret
+
+def drop_db(options, dbname):
+    # 1. Drop database
+    dbnamel = "ka_%s_db" % dbname
+    print "Dropping db %s ... " % dbnamel,
+    cmd_line = "dropdb --host=%s --port=%s --username=%s %s" % (options.get('host'), 
+                                                    options.get('port'), 
+                                                    options.get('user'),
+                                                    dbnamel)
+    retcode = exec_command(cmd_line)
+    if not retcode: return retcode
+    # 2. Drop users
+    cmd_line = "psql --host=%s --port=%s --username=%s -c 'select rolname from pg_roles'" % (options.get('host'), 
+                                                    options.get('port'), 
+                                                    options.get('user'))
+    users = tempfile.TemporaryFile()
+    ret = exec_command(cmd_line, stdout=users)
+    r = re.compile('.*ka_%s_.*' % dbname) 
+    users.seek(0)
+    if ret:
+        print "Ok"
+        for l in users.readlines():
+            if r.match(l): 
+                ret = drop_user(options, l.strip())
+                if not ret:
+                    break
+        return ret
+
+    else:
+        print "Failed"
+        return ret
+
+
+def drop_user(options, username):
+    print "Dropping user %s ... " % username,
+    cmd_line = "dropuser --host=%s --port=%s --username=%s %s" % (options.get('host'), 
+                                                    options.get('port'), 
+                                                    options.get('user'),
+                                                    username)
+    ret = exec_command(cmd_line)
+    if ret:
+        print "Ok"
+        return ret
+    else:
+        print "Failed"
+        return ret
+
+def init_db(options, dbname):
+    # Just connect to the database. Imideatly cloes connection
+    d = {'db_name':dbname}
+    print "Initiate db %s ... " % dbname,
+    sql_tmpl = Template(open(get_path('mpuls-init-db.sql')).read())
+    sql = sql_tmpl.substitute(d)
+    cmd_line = """psql --host=%s --port=%s --username=%s -t mpuls_maintenance -c "%s";""" % (options.get('host'), 
+                                                    options.get('port'), 
+                                                    options.get('user'),
+                                                    sql)
+    pw = None
+    tmp = tempfile.TemporaryFile()
+    try:
+        pw = open('passwords.txt', 'a')
+        ret = exec_command(cmd_line, stdout=tmp)
+        tmp.seek(0)
+        pw.write("%s    %s\n" % (dbname, tmp.read()))
+    except Exception, e:
+        print "exception: %s" % e
+    finally:
+        if pw:
+            pw.close
+
+    if ret:
+        print "Ok"
+        return ret
+    else:
+        print "Failed"
+        return ret
+
+class DBCommand(Command):
+        # Parser configuration
+        summary = "Will create and init a new database"
+        usage = ""
+        group_name = "mpulsweb"
+
+        parser = Command.standard_parser(verbose=False)
+        checks = [check_connection]
+
+        def __init__(self, name):
+            Command.__init__(self, name)
+            self.__add_options()
+
+        def __add_options(self):
+            self.parser.add_option('--user', 
+                              default='postgres', 
+                              help='Connect to the database with the given user [default: %default]')
+            self.parser.add_option('--password', 
+                              default=None, 
+                              help='Connect to the database with the given password [default: %default]')
+            self.parser.add_option('--host', 
+                              default='localhost', 
+                              help='Connect to the database on the the given host [default: %default]')
+            self.parser.add_option('--port', 
+                              default='5432',
+                              help='Connect to the database on the the given port [default: %default]')
+            self.parser.add_option('--script-dir', 
+                              default=None,
+                              help='Define an additional directory for db-scripts [default: %default]')
+
+        def command(self):
+            print self.parser.format_help()
+
+class ClusterInit(DBCommand):
+
+        # Parser configuration
+        summary = "Will init a database cluster for the use with mpuls"
+        usage = ""
+        group_name = "mpulsweb"
+
+        def __init__(self, name):
+            DBCommand.__init__(self, name)
+
+        def command(self):
+                import pprint
+                if len(self.args) != 0:
+                    print self.parser.format_help()
+                else:
+                    options = vars(self.options) 
+                    try:
+                        for check in self.checks:
+                            OK = check(options)
+                            if not OK: break
+                        if OK:
+                            if not check_mpulscluster(options):
+                                init_cluster(options)
+                            else:
+                                print u"Cluster wurde bereits für mpuls initialisiert. Continue with 'db-create'-command"
+                    except Exception, e:
+                        print e.message
+
+class DBCreate(DBCommand):
+        # Parser configuration
+        summary = "Will create new database"
+        usage = "dbname"
+        group_name = "mpulsweb"
+
+        def __init__(self, name):
+            DBCommand.__init__(self, name)
+
+        def command(self):
+                import pprint
+                self.checks.append(check_mpulscluster)
+                if len(self.args) != 1:
+                    print self.parser.format_help()
+                else:
+                    options = vars(self.options) 
+                    if options.get('script_dir'):
+                        DIRS.append(options.get('script_dir'))
+                    try:
+                        for check in self.checks:
+                            OK = check(options)
+                            if not OK: break
+                        if OK:
+                            if create_db(options, self.args[0]):
+                                if init_db(options, self.args[0]):
+                                    create_tables(options, self.args[0])
+                    except Exception, e:
+                        print e.message
+
+class DBDrop(DBCommand):
+        # Parser configuration
+        summary = "Will drop a given database"
+        usage = "dbname"
+        group_name = "mpulsweb"
+
+        def __init__(self, name):
+            DBCommand.__init__(self, name)
+
+        def command(self):
+                import pprint
+                self.checks.append(check_mpulscluster)
+                self.checks.append(check_mpulsdb)
+                if len(self.args) != 1:
+                    print self.parser.format_help()
+                else:
+                    options = vars(self.options) 
+                    try:
+                        for check in self.checks:
+                            OK = check(options, self.args)
+                            if not OK: break
+                        if OK:
+                            drop_db(options, self.args[0])
+                            #init_db(options, self.args[0])
+                    except Exception, e:
+                        print e.message
+
+class DBUpdate(DBCommand):
+        # Parser configuration
+        summary = "Will update a given database"
+        usage = "dbname"
+        group_name = "mpulsweb"
+
+        def command(self):
+                import pprint
+
+                if len(self.args) != 1:
+                    print self.parser.format_help()
+                else:
+                    options = vars(self.options)
+                    if options.get('script_dir'):
+                        DIRS.append(options.get('script_dir'))
+                    try:
+                        # 1. Check connection.
+                        check_connection(options)
+                        # 2. Check if there are the mpuls templates.
+                        # 3. Check if there is already a databate with the name.
+                        print "Creating DB: '%s' on host: '%s' port: '%s' ..." % (
+                            self.args[0], options.get('host'), options.get('port'))
+                    except Exception, e:
+                        print e.msg
+

Added: base/trunk/mpulsweb/commands/db/scripts/install/00_preconditions.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/00_preconditions.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/00_preconditions.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,164 @@
+SET ROLE :adm_ka_owner;
+
+BEGIN;
+
+-- Allow users to create temporary tables (needed for evaluations)
+GRANT TEMP ON DATABASE :db_name TO PUBLIC;
+
+--
+-- Init logging of DB updates.
+--
+CREATE TABLE db_history (
+        id SERIAL PRIMARY KEY, 
+        beschreibung VARCHAR(80), 
+        zeitpunkt TIMESTAMP);
+REVOKE ALL ON db_history FROM public;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('00_preconditions.sql', current_timestamp);
+
+CREATE TABLE dbinfo (
+    id INTEGER PRIMARY KEY NOT NULL,
+    key   VARCHAR(128) NOT NULL,
+    value VARCHAR(256) 
+);
+
+INSERT INTO dbinfo (id, key, value) VALUES (1, 'version', CURRENT_DATE);
+INSERT INTO dbinfo (id, key, value) VALUES (2, 'datadump', NULL);
+
+GRANT SELECT ON dbinfo TO PUBLIC;
+
+--
+-- anonymized_uuids
+-- Liste von UUIDs, die bereits anonymisiert wurden. Die UUIDs
+-- in den Akten selbst werden beim Anonymisieren aus
+-- datenschutzrechtlichen Gruenden geloescht.
+--
+CREATE TABLE anonymized_uuids (
+	id      serial   PRIMARY KEY,
+    uuid_id CHAR(36) UNIQUE NOT NULL
+);
+REVOKE ALL ON db_history FROM public;
+
+--
+-- Testet, ob eine UUID schon anonmisiert wurde.
+--
+CREATE OR REPLACE FUNCTION is_uuid_anonymized(nuuid char(36))
+    RETURNS BOOL AS
+$$
+DECLARE 
+    anon BOOL;
+BEGIN
+    IF nuuid is NULL THEN
+        RETURN TRUE;
+    END IF;
+    SELECT INTO anon TRUE FROM anonymized_uuids WHERE uuid_id = nuuid;
+    IF anon THEN
+        RETURN TRUE;
+    END IF;
+    RETURN FALSE;
+END;
+$$ LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER;
+
+REVOKE ALL ON FUNCTION is_uuid_anonymized(char(36)) FROM public;
+GRANT EXECUTE ON FUNCTION is_uuid_anonymized(char(36)) TO GROUP :admin_group;
+GRANT EXECUTE ON FUNCTION is_uuid_anonymized(char(36)) TO GROUP :cm_group;
+
+--
+-- Wenn eine Akte anonymisiert ist, hat sie keine UUID mehr. Folglich
+-- Kann man aus der anonymized_uuids auch nichts mehr loeschen.
+-- Falls sich dort trotzdem ein gleicher Eintrag finden sollte, ist
+-- dies eine potentielle Quelle fuer eine Inkonsistenz. 
+--
+CREATE OR REPLACE FUNCTION delete_anonymized_uuid() RETURNS TRIGGER AS $$
+BEGIN
+    -- Diese _sollte_ nichts loeschen!
+    DELETE FROM anonymized_uuids WHERE uuid_id = OLD.uuid_id;
+    RETURN OLD;
+END;
+$$ LANGUAGE plpgsql;
+
+-- PL/Python ist eine 'untrusted' Sprache
+SET ROLE postgres;
+
+-- Generiert eine UUID
+--
+CREATE OR REPLACE FUNCTION generate_uuidgen()
+RETURNS   text AS
+$BODY$
+    from commands import getstatusoutput
+    from random   import randint
+    try:
+        result = getstatusoutput("/usr/bin/uuid -v4")
+        if result[0] != 0: raise Exception()
+        return result[1].strip()
+    except:
+        count = 500
+        while count > 0:
+            nid = "%08x-%04x-%04x-%04x-%012x" % (
+                randint(0, 1 <<  8*4),
+                randint(0, 1 <<  4*4),
+                randint(0, 1 <<  4*4),
+                randint(0, 1 <<  4*4),
+                randint(0, 1 << 12*4))
+            if len(nid) == 36:
+                return nid
+            count -= 1
+        raise Exception("UUID generator failed")
+$BODY$
+LANGUAGE 'plpythonu' VOLATILE;
+
+REVOKE ALL ON FUNCTION generate_uuidgen() FROM public;
+GRANT EXECUTE ON FUNCTION generate_uuidgen() TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION generate_uuidgen() TO GROUP :admin_group;
+ALTER FUNCTION generate_uuidgen() OWNER TO :adm_ka_owner;
+
+-- Ab hier als :adm_ka_owner
+SET ROLE :adm_ka_owner;
+
+--
+-- Setzt in der Tabelle 't_name' in der Spalte mit der
+-- ID 'id' das Feld 'uuid_id' mit einer UUID.
+-- Bei Verletzung des Unique-Constraints wird bis
+-- zu 500 mal neu gewuerfelt.
+--
+CREATE OR REPLACE FUNCTION set_uuid(t_name text, id int) 
+RETURNS void AS 
+$$
+DECLARE
+    xuuid_id char(36);
+BEGIN
+    FOR i IN 0..500 LOOP
+        SELECT INTO xuuid_id generate_uuidgen();
+        BEGIN
+            EXECUTE 'UPDATE '           || t_name   || 
+                    ' SET uuid_id = ''' || xuuid_id ||
+                    ''' WHERE id = '    || id;
+        EXCEPTION WHEN unique_violation THEN
+            CONTINUE;
+        END;
+        RETURN;
+    END LOOP;
+    RAISE EXCEPTION 'set_uuid failed';
+END;
+$$ LANGUAGE plpgsql;
+REVOKE ALL ON FUNCTION set_uuid(text, int) FROM public;
+
+--
+-- TRIGGERS --
+--
+CREATE OR REPLACE FUNCTION mpuls_log() RETURNS TRIGGER AS $$
+BEGIN
+    IF TG_OP = 'DELETE' THEN
+        RAISE LOG '% on % (id: %) by %', TG_OP, TG_TABLE_NAME, OLD.id, session_user;
+        RETURN OLD;
+    ELSE
+        RAISE LOG '% on % (id: %) by %', TG_OP, TG_TABLE_NAME, NEW.id, session_user;
+        RETURN NEW;
+    END IF;
+END;
+$$ LANGUAGE plpgsql;
+
+
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/01_user.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/01_user.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/01_user.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,459 @@
+SET ROLE postgres;
+
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('02_user.sql', current_timestamp);
+
+ALTER FUNCTION mpuls_revoke_connect( varchar, varchar ) OWNER TO :adm_ka_owner;
+GRANT EXECUTE ON FUNCTION  mpuls_revoke_connect( varchar, varchar ) 
+    TO GROUP mpuls_role_adm;
+
+REVOKE ALL ON SCHEMA public FROM PUBLIC;
+GRANT USAGE ON SCHEMA public TO :cm_group;
+GRANT USAGE ON SCHEMA public TO :admin_group;
+GRANT USAGE ON SCHEMA public TO mpuls_role_adm;
+GRANT ALL ON SCHEMA public TO :adm_ka_owner;
+
+COMMIT;
+
+SET ROLE :adm_ka_owner;
+
+BEGIN;
+
+-- ka_benutzergruppe_tbl
+-- Tabelle fuer die Benutzergruppen. Jeder Benutzer erhaelt eine
+-- Benutzergruppe in der er exklusiv Mitglied ist. 
+-- Weitere Benutzergruppen können angelegt werden, die weitere Nutzer
+-- enthalten können
+
+CREATE TABLE ka_benutzergruppe_tbl
+(
+	id serial NOT NULL,
+	name varchar(128) NOT NULL,
+	CONSTRAINT ka_benutzergruppe_tbl_pkey PRIMARY KEY (id)
+);
+
+-- Benutzertabelle
+-- Diese Tabelle enthält erweiterte Angaben zu den Nutzern der KA Datenbank.
+-- Das Feld 'login' enthält hier den vollen Login-Namen, so wie er clusterweit
+-- in der Datenbank bekannt ist (ka_<agentur_<loginname>)
+-- 
+CREATE TABLE ka_benutzer_tbl
+(
+	id serial NOT NULL,
+	login varchar(64) NOT NULL,
+	vorname varchar(64),
+	nachname varchar(64),
+	telefon varchar(32),
+	raumnummer varchar(16),
+	filiale varchar(64),
+	aktiviert bool DEFAULT true,
+	passwort_aendern bool DEFAULT true,
+	last_login timestamp,
+	gid       int4 REFERENCES ka_benutzergruppe_tbl(id) ON DELETE CASCADE,
+	vertreter int4 REFERENCES ka_benutzergruppe_tbl(id) ON DELETE SET DEFAULT,
+	CONSTRAINT ka_benutzer_tbl_pkey PRIMARY KEY (id)
+); 
+
+GRANT SELECT ON ka_benutzer_tbl TO GROUP :cm_group;
+GRANT SELECT ON ka_benutzer_tbl TO GROUP :admin_group;
+GRANT UPDATE ON ka_benutzer_tbl TO GROUP :admin_group;
+
+--
+-- Benutzer-Fallakte Transitionstabelle 
+-- Diese Tabelle verbindet Nutzer mit Fallakten, und legt auf diese Weise
+-- fest welche Benutzer ausser dem initialen Bearbeiter oder dem KA-Admin 
+-- Zugriff auf die Fallakte haben.
+-- 
+
+CREATE TABLE nm_benutzer_master_tbl (
+    id serial PRIMARY KEY,
+    benutzer_id int4,
+    master_id int4
+);
+
+GRANT SELECT ON ka_benutzer_tbl TO GROUP :cm_group;
+GRANT SELECT ON ka_benutzer_tbl TO GROUP :admin_group;
+
+-- ka_nm_benutzer_gruppe_tbl
+-- Tabelle zur Zuordnung zwischen Benutzern und Benutzergruppen.
+CREATE TABLE nm_benutzer_gruppe_tbl
+(
+	id serial NOT NULL,
+	gruppe_id int4 REFERENCES ka_benutzergruppe_tbl(id) ON DELETE CASCADE,
+	benutzer_id int4 REFERENCES ka_benutzer_tbl(id) ON DELETE CASCADE,
+	CONSTRAINT nm_benutzer_gruppe_tbl_pkey PRIMARY KEY (id)
+);
+
+--
+-- getuserid()
+-- holt id des current_user aus der ka_benutzer_tbl
+--
+CREATE OR REPLACE FUNCTION getuserid() RETURNS integer
+    LANGUAGE 'plpgsql' STABLE
+    AS $$
+DECLARE
+myid integer;
+BEGIN
+SELECT INTO myid id FROM ka_benutzer_tbl WHERE login = session_user;
+RETURN myid;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION getuserid() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION getuserid() TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION getuserid() TO GROUP :admin_group;
+
+-- ------------------------------------------------------------------------
+-- Anlegen einer Rolle in der DB einer KA:
+-- - Ueber mpuls_create_role() Datenbank-Rolle anlegen und 
+-- - dann Eintragungen in ka_benutzer_tbl machen.
+CREATE OR REPLACE FUNCTION ka_create_role (
+        agency          varchar(52),
+        grouprole       varchar(64),
+        loginname       varchar(64),
+        firstname       varchar(64),
+        surname         varchar(64),
+        phone           varchar(64),
+        room            varchar(64),
+        branchoffice    varchar(64),
+        activated       boolean,
+        setpassword     boolean
+    ) RETURNS varchar(9) 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    newrole    RECORD;
+    groupid    integer;
+    userid     integer;
+BEGIN
+    SELECT INTO newrole * FROM mpuls_create_role(loginname, grouprole, agency)
+        AS (db_name varchar(64), db_user varchar(64), pw varchar(9));
+    EXECUTE 'GRANT CONNECT ON DATABASE ' || newrole.db_name 
+                || ' TO ' || newrole.db_user; 
+    INSERT INTO ka_benutzer_tbl ( login, vorname, nachname,
+        telefon, raumnummer, filiale,
+        aktiviert, passwort_aendern, gid) 
+        VALUES
+        (newrole.db_user, firstname, surname,
+        phone, room, branchoffice,
+        activated, setpassword, NULL);
+    SELECT INTO userid currval('ka_benutzer_tbl_id_seq');
+    SELECT INTO groupid create_benutzergruppe_ds(surname ||', '|| firstname ||' ('||loginname||')');
+    UPDATE ka_benutzer_tbl SET gid = groupid WHERE id = userid;
+    INSERT INTO nm_benutzer_gruppe_tbl (benutzer_id, gruppe_id) VALUES (userid, groupid);
+
+    RETURN newrole.pw::varchar(9);
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION ka_create_role(varchar, varchar, varchar, 
+    varchar, varchar, varchar, varchar, varchar, boolean, boolean) 
+        FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION ka_create_role(varchar, varchar, varchar, 
+    varchar, varchar, varchar, varchar, varchar, boolean, boolean) 
+        TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION ka_delete_role (
+        loginname       varchar(64),
+        agency          varchar(52)
+    ) RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    db_user  varchar(128);
+    groupid   integer;
+BEGIN
+    db_user := quote_ident('ka_' || agency || '_' || loginname);
+    SELECT INTO groupid gid FROM ka_benutzer_tbl WHERE login = db_user;
+    DELETE FROM ka_benutzer_tbl WHERE login = db_user;
+    DELETE FROM ka_benutzergruppe_tbl WHERE id = groupid;
+    PERFORM mpuls_drop_role(loginname, agency);
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION ka_delete_role(varchar, varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION ka_delete_role(varchar, varchar) 
+            TO GROUP :admin_group;
+
+
+-- Funktionen zu Erstellen und Loeschen neuer Eintraeger in der
+-- Benutzergruppen Tabelle
+
+CREATE OR REPLACE FUNCTION create_benutzergruppe_ds(gname varchar) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO ka_benutzergruppe_tbl (name) VALUES (gname);
+    RETURN currval('ka_benutzergruppe_tbl_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_benutzergruppe_ds( varchar ) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_benutzergruppe_ds( varchar ) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION delete_benutzergruppe_ds(gid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+BEGIN
+    DELETE FROM ka_benutzergruppe_tbl WHERE id = gid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_benutzergruppe_ds( integer ) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_benutzergruppe_ds( integer ) TO GROUP :admin_group;
+
+--
+-- Voreinstellung Vertretungsregeln setzen
+--
+CREATE OR REPLACE FUNCTION ka_set_standin (standin_id integer, user_id integer)
+    RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    UPDATE ka_benutzer_tbl_view set vertreter = standin_id WHERE id = user_id; 
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION ka_set_standin(integer, integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION ka_set_standin ( integer, integer ) TO :cm_group;
+
+
+--
+-- Funktion um die Flagge zurueckzusetzten, dass der Benutzer sein Passwort bei
+-- der Neuanmeldung neu setzen muss. Die Funktion muss auch fuer die Benutzer
+-- zugaenglich sein.
+-- 
+CREATE OR REPLACE FUNCTION ka_unset_passrefresh_flag ( userlogin varchar ) 
+    RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    UPDATE ka_benutzer_tbl_view set passwort_aendern = False 
+            WHERE login = userlogin; 
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION ka_unset_passrefresh_flag(varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION ka_unset_passrefresh_flag ( userlogin varchar ) 
+                TO :admin_group;
+GRANT EXECUTE ON FUNCTION ka_unset_passrefresh_flag ( userlogin varchar ) 
+                TO :cm_group;
+
+-- 
+-- Funktion zum Setzen des Benutzerpassworts
+--
+
+CREATE OR REPLACE FUNCTION ka_set_password(loginname varchar, pw varchar)
+    RETURNS text 
+    LANGUAGE 'plpgsql'
+    AS $$
+BEGIN
+    EXECUTE 'ALTER USER ' || loginname || ' WITH PASSWORD ' 
+              || quote_literal(pw);
+    EXECUTE ka_unset_passrefresh_flag(loginname);
+          RETURN pw::text;
+    RETURN ''::text;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION ka_set_password(varchar, varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION ka_set_password(varchar, varchar) 
+                TO :admin_group;
+GRANT EXECUTE ON FUNCTION ka_set_password(varchar, varchar)    
+                TO :cm_group;
+
+
+
+CREATE OR REPLACE FUNCTION getrole( user_id integer ) RETURNS varchar 
+    LANGUAGE 'plpgsql' STABLE SECURITY DEFINER 
+    AS $$
+DECLARE
+    role varchar;
+    oid integer;
+BEGIN
+    SELECT p.usesysid INTO oid FROM pg_user p JOIN ka_benutzer_tbl b 
+        ON b.login = p.usename 
+        WHERE b.id = user_id; 
+    SELECT groname INTO role FROM pg_group WHERE oid = ANY (grolist);
+    RETURN role;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION getrole(user_id integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION getrole( integer ) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION getrole( integer ) TO GROUP :admin_group;
+
+--
+-- getuserid()
+-- holt id des current_user aus der ka_benutzer_tbl
+--
+-- Funktion wurde in die 00precond.sql verschoben
+
+--
+-- getoid()
+-- OID des current_user
+--
+CREATE OR REPLACE FUNCTION getoid() RETURNS integer
+    LANGUAGE 'plpgsql' STABLE
+    AS $$
+DECLARE
+    myoid OID;
+BEGIN
+    SELECT INTO myoid oid FROM pg_roles WHERE rolname = current_user;
+    RETURN myoid;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION getoid() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION getoid() TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION getoid() TO GROUP :admin_group;
+
+--
+-- isEditorOrStandin(integer)
+-- Liefert TRUE wenn der Benutzer fuer die Fallakte 
+-- a) Bearbeiter oder
+-- b) Vertreter ist
+-- Sonst FALSE
+--
+
+CREATE OR REPLACE FUNCTION isEditorOrStandin(mid integer)
+    RETURNS boolean 
+    LANGUAGE 'plpgsql' STABLE
+    AS $$
+DECLARE
+    bid integer;
+    isAllowed integer;
+BEGIN
+    SELECT bearbeiter_id into bid from master_tbl_view WHERE id = mid;
+    IF bid = getuserid() THEN
+        RETURN TRUE;
+    ELSE 
+        SELECT INTO isAllowed benutzer_id FROM 
+        nm_benutzer_master_tbl_view 
+        WHERE master_id = mid 
+        AND benutzer_id IN (
+                SELECT gruppe_id FROM nm_benutzer_gruppe_tbl_view 
+                WHERE benutzer_id = getuserid()
+                );
+    END IF;
+    RETURN FOUND;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION isEditororstandin(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION isEditorOrStandin(integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION isEditorOrStandin(integer) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION getrole( user_id integer ) RETURNS varchar 
+    LANGUAGE 'plpgsql' STABLE SECURITY DEFINER 
+    AS $$
+DECLARE
+    role varchar;
+    oid integer;
+BEGIN
+    SELECT p.usesysid INTO oid FROM pg_user p JOIN ka_benutzer_tbl b 
+        ON b.login = p.usename 
+        WHERE b.id = user_id; 
+    SELECT groname INTO role FROM pg_group WHERE oid = ANY (grolist);
+    RETURN role;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION getrole(user_id integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION getrole( integer ) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION getrole( integer ) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION set_last_logintime(userid integer) 
+    RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    UPDATE ka_benutzer_tbl_view SET last_login = now() WHERE id = userid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION set_last_logintime(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION set_last_logintime(integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION set_last_logintime(integer) TO GROUP :admin_group;
+
+-- 
+-- Sicht auf die Benutzerdatenbank
+--
+
+CREATE OR REPLACE VIEW ka_benutzer_tbl_view AS 
+SELECT ka_benutzer_tbl.id, ka_benutzer_tbl.vorname, ka_benutzer_tbl.nachname,
+ka_benutzer_tbl.telefon, ka_benutzer_tbl.aktiviert,
+ka_benutzer_tbl.passwort_aendern, ka_benutzer_tbl.login,
+ka_benutzer_tbl.raumnummer, ka_benutzer_tbl.filiale, p.usesysid,
+ka_benutzer_tbl.vertreter, getrole(ka_benutzer_tbl.id) as rolle,
+ka_benutzer_tbl.gid,
+ka_benutzer_tbl.last_login
+FROM ka_benutzer_tbl JOIN pg_user p
+ON ka_benutzer_tbl.login = p.usename;
+
+CREATE OR REPLACE RULE ka_benutzer_update_rule AS ON UPDATE TO ka_benutzer_tbl_view 
+	DO INSTEAD  UPDATE ka_benutzer_tbl SET 
+	vorname = new.vorname, 
+	nachname = new.nachname, 
+	telefon = new.telefon, 
+	aktiviert = new.aktiviert, 
+	raumnummer = new.raumnummer, 
+	filiale = new.filiale, 
+	passwort_aendern = new.passwort_aendern, 
+	vertreter = new.vertreter,
+	gid = new.gid,
+	last_login = new.last_login
+	WHERE ka_benutzer_tbl.id = new.id;
+
+GRANT SELECT ON ka_benutzer_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_benutzer_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_benutzer_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE RULE ka_benutzer_delete_rule AS ON DELETE TO ka_benutzer_tbl_view 
+    DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_benutzer_insert_rule AS ON INSERT TO ka_benutzer_tbl_view
+    DO INSTEAD NOTHING;
+
+-- Sichten auf die Benutzergruppe
+
+CREATE OR REPLACE VIEW ka_benutzergruppe_tbl_view AS 
+SELECT g.id, coalesce(b.nachname ||', '|| b.vorname, g.name) AS name FROM ka_benutzer_tbl b RIGHT JOIN ka_benutzergruppe_tbl g ON g.id = b.gid;
+
+CREATE OR REPLACE RULE ka_benutzergruppe_delete_rule AS ON DELETE TO 
+ka_benutzergruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_benutzergruppe_insert_rule AS ON INSERT TO 
+ka_benutzergruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_benutzergruppe_update_rule AS ON UPDATE TO ka_benutzergruppe_tbl_view 
+	DO INSTEAD  UPDATE ka_benutzergruppe_tbl SET 
+	name = new.name 
+	WHERE ka_benutzergruppe_tbl.id = new.id;
+
+GRANT SELECT ON ka_benutzergruppe_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_benutzergruppe_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_benutzergruppe_tbl_view TO GROUP :admin_group;
+
+--
+-- TRIGGERS
+--
+-- ka_benutzer_tbl
+CREATE TRIGGER t_ka_benutzer_tbl_insert AFTER
+    INSERT ON ka_benutzer_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_benutzer_tbl_update AFTER
+    UPDATE ON ka_benutzer_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_benutzer_tbl_delete AFTER
+    DELETE ON ka_benutzer_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/02_datamodel.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/02_datamodel.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/02_datamodel.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,764 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('03_datamodel.sql', current_timestamp);
+
+--
+-- CREATE TABLES
+--
+
+CREATE TABLE phase_tbl (
+    id SERIAL PRIMARY KEY NOT NULL,
+    value VARCHAR(24) NOT NULL
+);
+
+CREATE TABLE master_tbl (
+    id SERIAL PRIMARY KEY NOT NULL,
+    uuid_id CHAR(36),
+    bearbeiter_id int NOT NULL,
+    einwilligung INTEGER DEFAULT -1,
+    phase INTEGER DEFAULT -1,
+    UNIQUE (uuid_id),
+    FOREIGN KEY (phase) REFERENCES phase_tbl (id)
+);
+
+-- Benutzer Fallakten Transitionstabelle
+ALTER TABLE nm_benutzer_master_tbl ADD CONSTRAINT has_group_fk FOREIGN KEY
+(benutzer_id) REFERENCES ka_benutzergruppe_tbl (id) ON DELETE CASCADE;
+
+ALTER TABLE nm_benutzer_master_tbl ADD CONSTRAINT has_master_fk FOREIGN KEY
+(master_id) REFERENCES master_tbl (id) ON DELETE CASCADE;
+
+-- Jede Fallakte muss einen Bearbeiter haben.
+ALTER TABLE master_tbl ADD CONSTRAINT has_bearbeiter_id_fk FOREIGN KEY
+(bearbeiter_id) REFERENCES ka_benutzer_tbl;
+
+CREATE TABLE ka_status_tbl
+(
+	id serial NOT NULL,
+	master_id int4 REFERENCES master_tbl(id) ON DELETE CASCADE,
+	status    int4,
+	zugriff   timestamp,
+	erstellt  timestamp DEFAULT now(),
+	anonymisiert timestamp,
+	CONSTRAINT ka_status_tbl_pkey PRIMARY KEY (id)
+);
+
+-- ------ This is static code and therefore may be put into a separate file. -------
+
+-- Used to track the structure changes of a case
+-- DROP TABLE case_structure CASCADE;
+
+CREATE TABLE case_structure (
+    id        SERIAL PRIMARY KEY NOT NULL,
+    master_id int4 NOT NULL REFERENCES master_tbl(id) ON DELETE CASCADE,
+    modified  boolean,
+    cache     TEXT
+);
+
+-- each time a new case is created create a new entry in the strcuture table
+
+-- DROP TRIGGER case_insert_trigger ON master_tbl;
+-- DROP FUNCTION case_insert_func();
+
+CREATE OR REPLACE FUNCTION case_insert_func() RETURNS TRIGGER AS $$
+BEGIN
+    INSERT INTO case_structure (master_id, modified) VALUES (NEW.id, true);
+    RETURN NEW;
+END;
+$$ LANGUAGE plpgsql;
+
+CREATE TRIGGER case_insert_trigger AFTER INSERT ON master_tbl
+FOR EACH ROW EXECUTE PROCEDURE case_insert_func();
+
+-- ------ end of static code -------
+-- PLPython is an untrusted language. -> Need to be postgres.
+SET ROLE postgres;
+
+-- DROP FUNCTION compute_case_structure(int4);
+CREATE OR REPLACE FUNCTION compute_case_structure(case_id int4) RETURNS TEXT
+AS $$
+
+class Node(object):
+
+    def __init__(self, name, id=None, children=[]):
+        self.name = name
+        self.id = id
+        self.children = children
+
+    def to_json(self, out):
+        out.append('{"name":"%s","id":%d' % (self.name, self.id))
+        if self.children:
+            out.append(',"children":[')
+            first = True
+            for child in self.children:
+                if first:
+                    first = False
+                else:
+                    out.append(",")
+                child.to_json(out)
+            out.append("]")
+        out.append("}")
+
+    def recursive_build(self, mid, children):
+        select = "SELECT id FROM %s WHERE master_id = %d" % (self.name, mid)
+        ids = [r['id'] for r in plpy.execute(select)]
+        for id in ids:
+            sub_children = []
+            node = Node(self.name, id, sub_children)
+            for child in self.children:
+                child.recursive_build(id, sub_children)
+            children.append(node)
+
+TREE_STRUCTURE = Node('master_tbl', children = [])
+
+
+children = []
+tree = Node(TREE_STRUCTURE.name, case_id, children)
+for child in TREE_STRUCTURE.children:
+    child.recursive_build(case_id, children)
+out = []
+tree.to_json(out)
+return "".join(out)
+
+$$ LANGUAGE plpythonu EXTERNAL SECURITY DEFINER;
+ALTER FUNCTION compute_case_structure(int4) OWNER TO :adm_ka_owner;
+
+-- DROP FUNCTION get_case_structure(int4);
+CREATE OR REPLACE FUNCTION get_case_structure(case_id int4) RETURNS TEXT AS $$
+
+r = plpy.execute("SELECT modified, cache FROM case_structure "
+                 "WHERE master_id = %d" % case_id, 1)
+
+if not r:
+    return ""
+r = r[0]
+
+if r['modified']: # need refresh
+    structure = plpy.execute("SELECT compute_case_structure(%d) as s;"
+                             % case_id, 1)[0]["s"]
+    plan = plpy.prepare("UPDATE case_structure SET modified = false, "
+                        "cache = $1 WHERE master_id = $2", ["text", "int4"])
+    plpy.execute(plan, [structure, case_id])
+    return structure
+
+return r['cache']
+
+$$ LANGUAGE plpythonu EXTERNAL SECURITY DEFINER;
+ALTER FUNCTION get_case_structure(int4) OWNER TO :adm_ka_owner;
+
+-- Continue as db-owner from here
+SET ROLE :adm_ka_owner;
+
+CREATE OR REPLACE FUNCTION create_master_tbl(nuuid char(36))
+    RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER AS
+$$
+DECLARE
+    standin integer;
+    rid     integer;
+BEGIN
+    rid := create_master_ds(nuuid);
+    IF nuuid IS NULL THEN
+    END IF;
+    RETURN rid;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION create_master_tbl(char(36)) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_master_tbl(char(36))
+    TO GROUP :cm_group;
+
+CREATE OR REPLACE FUNCTION delete_master_tbl(mid integer) RETURNS void
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    st integer;
+BEGIN
+    SELECT INTO st s.status FROM master_tbl m JOIN ka_status_tbl s
+        ON s.master_id = m.id WHERE m.id = mid;
+
+    IF NOT st in (3, 5) THEN
+        RAISE EXCEPTION 'case is not deletable';
+    END IF;
+
+    DELETE FROM master_tbl WHERE id = mid;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION delete_master_tbl(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_master_tbl(integer)
+    TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION create_status_ds(mid integer)
+    RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE SECURITY DEFINER 
+    AS $$
+BEGIN
+    INSERT INTO ka_status_tbl (master_id, zugriff, status) 
+            VALUES (mid, now(), 1);
+END;
+$$;
+
+REVOKE ALL ON FUNCTION create_status_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_status_ds(integer) TO GROUP :cm_group;
+
+
+INSERT INTO phase_tbl (id, value) VALUES (-1, 'Keine Angabe');
+
+--
+-- GRANTS ON TABLES
+--
+GRANT SELECT ON phase_tbl TO GROUP :cm_group;
+GRANT SELECT ON phase_tbl TO GROUP :admin_group;
+--
+--
+-- views for master table and repeat groups
+--
+CREATE OR REPLACE VIEW master_tbl_view
+AS SELECT master_tbl.* FROM master_tbl
+WHERE
+    master_tbl.bearbeiter_id = getuserid()
+    OR master_tbl.id IN (
+        SELECT nm.master_id from nm_benutzer_master_tbl nm
+        WHERE nm.benutzer_id IN (
+            SELECT nm2.gruppe_id from nm_benutzer_gruppe_tbl nm2 
+            WHERE nm2.benutzer_id = getuserid()
+        )
+    )
+    OR pg_has_role('admin','MEMBER');
+
+CREATE OR REPLACE RULE master_tbl_update_rule AS ON UPDATE TO master_tbl_view
+DO INSTEAD UPDATE master_tbl SET
+    phase = NEW.phase,
+    einwilligung = NEW.einwilligung
+WHERE id = NEW.id;
+
+CREATE OR REPLACE RULE master_tbl_delete_rule AS ON DELETE TO master_tbl_view
+    DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE master_tbl_insert_rule AS ON INSERT TO master_tbl_view
+    DO INSTEAD NOTHING;
+
+GRANT SELECT ON master_tbl_view TO GROUP :cm_group;
+GRANT UPDATE ON master_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON master_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE  VIEW master_tbl_eval_total_view AS
+    SELECT m.* FROM master_tbl m JOIN ka_status_tbl s
+        ON m.id = s.master_id
+        WHERE
+            s.status <> 3 AND
+            (m.bearbeiter_id = (getuserid())::integer)
+            OR pg_has_role('admin','MEMBER');
+
+GRANT SELECT ON master_tbl_eval_total_view TO :cm_group;
+GRANT SELECT ON master_tbl_eval_total_view TO :admin_group;
+
+-- --
+-- -- Name: master_tbl_eval_incm_view; Type: VIEW; Schema: public; Owner: postgres
+-- --
+-- 
+-- CREATE OR REPLACE  VIEW master_tbl_eval_incm_view AS
+--     SELECT * FROM master_tbl_eval_total_view
+--         WHERE phase IN (2,3,4,5);
+-- 
+-- GRANT SELECT ON public.master_tbl_eval_incm_view TO :cm_group;
+-- GRANT SELECT ON public.master_tbl_eval_incm_view TO :admin_group;
+-- 
+-- CREATE OR REPLACE  VIEW master_tbl_incm_view AS
+--     SELECT * FROM master_tbl_view
+--         WHERE phase IN (2,3,4,5);
+-- 
+-- GRANT SELECT ON public.master_tbl_incm_view TO :cm_group;
+-- GRANT SELECT ON public.master_tbl_incm_view TO :admin_group;
+
+CREATE OR REPLACE VIEW master_tbl_anonym_view
+AS SELECT
+    id,
+    uuid_id,
+    bearbeiter_id,
+    phase 
+    FROM master_tbl_view;
+
+CREATE OR REPLACE RULE master_tbl_anonym_delete_rule AS ON DELETE TO master_tbl_anonym_view
+    DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE master_tbl_anonym_insert_rule AS ON INSERT TO master_tbl_anonym_view
+    DO INSTEAD NOTHING;
+
+GRANT SELECT ON master_tbl_anonym_view TO GROUP :cm_group;
+GRANT SELECT ON master_tbl_anonym_view TO GROUP :admin_group;
+
+--
+-- Function to anonymize a case and all of its repeat groups
+--
+CREATE OR REPLACE FUNCTION anonymize_case(mid int)
+RETURNS void AS
+$$
+BEGIN
+    PERFORM anonymize_uuid(mid);
+    -- anonymize master table
+    UPDATE master_tbl_view SET
+    	id = id
+    WHERE id = mid;
+END;
+$$ LANGUAGE plpgsql VOLATILE SECURITY DEFINER;
+
+REVOKE ALL ON FUNCTION anonymize_case(int) FROM public;
+GRANT EXECUTE ON FUNCTION anonymize_case(int) TO GROUP :admin_group;
+
+--
+-- Funktionen zum Anlegen neuer (Teile von) Fallakten
+-- Diese sind nur fuer die Gruppe CM_KA aufrufbar (Admin_KA darf keine neuen 
+-- Akten anlegen) und laufen mit den Berechtigungen des zentralen
+-- administrativen Benutzers der KA
+CREATE OR REPLACE FUNCTION create_master_ds(nuuid char(36)) 
+    RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER AS 
+$$
+DECLARE
+    standin integer;
+    mid     integer;
+BEGIN
+    INSERT INTO master_tbl (bearbeiter_id) VALUES (getuserid());
+    SELECT INTO standin vertreter from ka_benutzer_tbl WHERE id = getuserid();
+
+    IF standin IS NOT NULL THEN 
+        INSERT INTO nm_benutzer_master_tbl(benutzer_id, master_id) 
+                VALUES (standin, currval('master_tbl_id_seq'));
+    END IF;
+
+    SELECT INTO mid currval('master_tbl_id_seq'); 
+
+    IF nuuid IS NOT NULL THEN
+        UPDATE master_tbl SET uuid_id = nuuid WHERE id = mid;
+    ELSE
+        PERFORM set_uuid('master_tbl', mid);
+    END IF;
+
+    PERFORM create_status_ds(mid);
+    RETURN mid;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION create_master_ds(char(36)) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_master_ds(char(36))
+    TO GROUP :cm_group;
+
+--
+-- Funktionen zum Loeschen einer Fallakte inklusive aller angehaengten 
+-- Unterstuetzungsangebote, Dateien Termine etc.
+-- Diese sind nur fuer die Gruppe ADMIN_KA aufrufbar (CM_KA sollen keine Akten
+-- loeschen koennen) und laufen mit den Berechtigungen des zentralen
+-- administrativen Benutzers der KA
+
+CREATE OR REPLACE FUNCTION delete_master_ds(mid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    st integer;
+BEGIN
+    SELECT INTO st s.status FROM master_tbl m JOIN ka_status_tbl s
+        ON s.master_id = m.id WHERE m.id = mid;
+
+    IF NOT st in (3, 5) THEN
+        RAISE EXCEPTION 'case is not deletable';
+    END IF;
+
+    DELETE FROM master_tbl WHERE id = mid;
+END;
+$$ ;
+
+REVOKE ALL    ON FUNCTION delete_master_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_master_ds(integer) TO GROUP :admin_group;
+
+--
+-- Funktionen zum Hinzufuegen und Loeschen der Benutzer in die
+-- Benutzer-Fallakten Transitionstabelle, sowie zum Setzen des Bearbeiters
+-- einer Fallakte.
+--
+
+CREATE OR REPLACE FUNCTION create_nm_benutzer_master_ds ( userid integer, 
+    masterid integer ) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO nm_benutzer_master_tbl (benutzer_id, master_id) 
+        VALUES (userid, masterid);
+    RETURN currval('nm_benutzer_master_tbl_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_nm_benutzer_master_ds(integer, integer) 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_nm_benutzer_master_ds(integer, integer) 
+                TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION create_nm_benutzer_master_ds(integer, integer) 
+                TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION delete_nm_benutzer_master_ds ( userid integer,
+    masterid integer ) RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM nm_benutzer_master_tbl 
+            WHERE master_id = masterid AND benutzer_id = userid; 
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_nm_benutzer_master_ds(integer, integer) 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_nm_benutzer_master_ds(integer, integer) 
+                TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION delete_nm_benutzer_master_ds(integer, integer) 
+                TO GROUP :admin_group;
+
+-- Funktionen zu Erstellen und Loeschen neuer Eintraeger in der
+-- nm_benutzer_gruppe Tabelle
+
+CREATE OR REPLACE FUNCTION create_nm_benutzer_gruppe_ds(bid integer, gid integer) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO nm_benutzer_gruppe_tbl (benutzer_id, gruppe_id) VALUES (bid, gid);
+    RETURN currval('nm_benutzer_gruppe_tbl_id_seq');
+END;
+$$ ;
+REVOKE ALL ON FUNCTION create_nm_benutzer_gruppe_ds( integer, integer ) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_nm_benutzer_gruppe_ds( integer, integer ) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION delete_nm_benutzer_gruppe_ds( bid integer, gid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM nm_benutzer_gruppe_tbl WHERE gruppe_id = gid AND benutzer_id = bid;
+END;
+$$ ;
+REVOKE ALL ON FUNCTION delete_nm_benutzer_gruppe_ds( integer, integer ) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_nm_benutzer_gruppe_ds( integer, integer ) TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION set_case_editor (userid integer, masterid integer) 
+    RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    UPDATE master_tbl set bearbeiter_id = userid WHERE id = masterid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION set_case_editor(integer, integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION set_case_editor(integer, integer) 
+                TO GROUP :admin_group;
+
+--
+-- isEditorOrStandin(integer)
+-- Liefert TRUE wenn der Benutzer fuer die Fallakte 
+-- a) Bearbeiter oder
+-- b) Vertreter ist
+-- Sonst FALSE
+--
+
+CREATE OR REPLACE FUNCTION isEditorOrStandin(mid integer)
+    RETURNS boolean 
+    LANGUAGE 'plpgsql' STABLE
+    AS $$
+DECLARE
+    bid integer;
+    isAllowed integer;
+BEGIN
+    SELECT bearbeiter_id into bid from master_tbl_view WHERE id = mid;
+    IF bid = getuserid() THEN
+        RETURN TRUE;
+    ELSE 
+        SELECT INTO isAllowed benutzer_id FROM 
+        nm_benutzer_master_tbl_view 
+        WHERE master_id = mid 
+        AND benutzer_id IN (
+                SELECT gruppe_id FROM nm_benutzer_gruppe_tbl_view 
+                WHERE benutzer_id = getuserid()
+                );
+    END IF;
+    RETURN FOUND;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION isEditororstandin(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION isEditorOrStandin(integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION isEditorOrStandin(integer) TO GROUP :admin_group;
+
+-- Funktionen zum Setzen der Einverstaendniserkärung 
+CREATE OR REPLACE FUNCTION set_ee_status(mid integer, status integer) 
+    RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER AS 
+$$
+BEGIN
+    UPDATE master_tbl_view SET einwilligung = status WHERE id = mid;
+END;
+$$;
+
+REVOKE ALL     ON FUNCTION set_ee_status(integer, integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION set_ee_status(integer, integer) TO GROUP :cm_group;
+GRANT  EXECUTE ON FUNCTION set_ee_status(integer, integer) TO GROUP :admin_group;
+
+--
+-- Loescht die UUID in einer Akte und traegt sie in die Liste der
+-- anonymisierten UUIDs ein.
+--
+CREATE OR REPLACE FUNCTION anonymize_uuid(mid int)
+RETURNS void AS
+$$
+DECLARE
+    nuuid char(36);
+BEGIN
+    SELECT INTO nuuid uuid_id FROM master_tbl_view WHERE id = mid;
+    IF NOT is_uuid_anonymized(nuuid) THEN
+        INSERT INTO anonymized_uuids (uuid_id) VALUES (nuuid);
+    END IF;
+    UPDATE master_tbl SET uuid_id = NULL WHERE id = mid;
+END;
+$$ LANGUAGE 'plpgsql' VOLATILE SECURITY DEFINER;
+
+REVOKE ALL ON FUNCTION anonymize_uuid(int) FROM public;
+GRANT EXECUTE ON FUNCTION anonymize_uuid(int) TO GROUP :admin_group;
+
+--
+-- VIEWS
+--
+
+-- 
+-- Sicht auf die Benutzer-Fallakte Transitionstabelle
+--
+
+CREATE OR REPLACE VIEW nm_benutzer_master_tbl_view AS 
+SELECT nm_benutzer_master_tbl.id, nm_benutzer_master_tbl.benutzer_id,
+nm_benutzer_master_tbl.master_id 
+FROM nm_benutzer_master_tbl;
+
+GRANT SELECT ON nm_benutzer_master_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON nm_benutzer_master_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE RULE nm_benutzer_master_delete_rule AS ON DELETE TO 
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_master_insert_rule AS ON INSERT TO
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_master_update_rule AS ON UPDATE TO
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+-- 
+-- Sicht auf die Benutzer-Gruppen Transitionstabelle
+--
+
+CREATE OR REPLACE VIEW nm_benutzer_gruppe_tbl_view AS 
+SELECT nm_benutzer_gruppe_tbl.id, nm_benutzer_gruppe_tbl.benutzer_id,
+nm_benutzer_gruppe_tbl.gruppe_id 
+FROM nm_benutzer_gruppe_tbl;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_delete_rule AS ON DELETE TO 
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_insert_rule AS ON INSERT TO
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_update_rule AS ON UPDATE TO
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+GRANT SELECT ON nm_benutzer_gruppe_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON nm_benutzer_gruppe_tbl_view TO GROUP :admin_group;
+
+-- 
+-- Sicht auf die Benutzer-Fallakte Transitionstabelle
+--
+
+CREATE OR REPLACE VIEW nm_benutzer_master_tbl_view AS 
+SELECT nm_benutzer_master_tbl.id, nm_benutzer_master_tbl.benutzer_id,
+nm_benutzer_master_tbl.master_id 
+FROM nm_benutzer_master_tbl;
+
+GRANT SELECT ON nm_benutzer_master_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON nm_benutzer_master_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE RULE nm_benutzer_master_delete_rule AS ON DELETE TO 
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_master_insert_rule AS ON INSERT TO
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_master_update_rule AS ON UPDATE TO
+nm_benutzer_master_tbl_view DO INSTEAD NOTHING;
+
+-- 
+-- Sicht auf die Benutzer-Gruppen Transitionstabelle
+--
+
+CREATE OR REPLACE VIEW nm_benutzer_gruppe_tbl_view AS 
+SELECT nm_benutzer_gruppe_tbl.id, nm_benutzer_gruppe_tbl.benutzer_id,
+nm_benutzer_gruppe_tbl.gruppe_id 
+FROM nm_benutzer_gruppe_tbl;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_delete_rule AS ON DELETE TO 
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_insert_rule AS ON INSERT TO
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE nm_benutzer_gruppe_update_rule AS ON UPDATE TO
+nm_benutzer_gruppe_tbl_view DO INSTEAD NOTHING;
+
+GRANT SELECT ON nm_benutzer_gruppe_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON nm_benutzer_gruppe_tbl_view TO GROUP :admin_group;
+
+-- Sicht auf die KA Status Tabelle 
+
+CREATE OR REPLACE VIEW ka_status_tbl_view AS 
+SELECT
+	ka_status_tbl.id,
+	ka_status_tbl.master_id,
+	ka_status_tbl.status, 
+	ka_status_tbl.zugriff,
+	ka_status_tbl.erstellt,
+	ka_status_tbl.anonymisiert
+FROM ka_status_tbl;
+
+CREATE OR REPLACE RULE ka_status_delete_rule AS ON DELETE TO 
+ka_status_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_status_insert_rule AS ON INSERT TO 
+ka_status_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_status_update_rule AS ON UPDATE TO ka_status_tbl_view 
+	DO INSTEAD UPDATE ka_status_tbl SET
+	status  = new.status,
+	zugriff = new.zugriff,
+	anonymisiert = new.anonymisiert
+WHERE id = new.id;
+
+GRANT SELECT ON ka_status_tbl_view TO GROUP :cm_group;
+GRANT UPDATE ON ka_status_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_status_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_status_tbl_view TO GROUP :admin_group;
+
+
+-- 
+-- TRIGGERS
+--
+
+--
+-- Automatisches Setzen eines Zeitstempels in der ka_status_tbl
+-- Diese Trigger sorgen dafür, dass bei jeder Bearbeitung der Fallakten der
+-- Zeitpunkt der Bearbeitung gespeichert wird.
+--
+CREATE OR REPLACE FUNCTION set_lastaccess_time( masterid integer ) 
+RETURNS void AS 
+$$
+BEGIN
+    UPDATE ka_status_tbl_view set zugriff = now() WHERE master_id = masterid;  
+END;
+$$ LANGUAGE plpgsql VOLATILE;
+
+CREATE OR REPLACE FUNCTION master_lastaccess_log() RETURNS trigger AS $master_lastaccess_log$
+BEGIN
+    EXECUTE set_lastaccess_time(NEW.id);
+    RETURN NEW;
+END;
+$master_lastaccess_log$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION status_lastaccess_log() RETURNS trigger AS $status_lastaccess_log$
+BEGIN
+IF NEW.status <> OLD.status AND OLD.zugriff IS NOT NULL THEN
+    EXECUTE set_lastaccess_time(NEW.master_id);
+END IF;
+RETURN NEW;
+END;
+$status_lastaccess_log$ LANGUAGE plpgsql;
+
+CREATE OR REPLACE FUNCTION rg_lastaccess_log() RETURNS trigger AS $rg_lastaccess_log$
+BEGIN
+IF TG_OP = 'DELETE' THEN
+    EXECUTE set_lastaccess_time(OLD.master_id);
+    RETURN OLD;
+ELSE
+    EXECUTE set_lastaccess_time(NEW.master_id);
+    RETURN NEW;
+END IF;
+END;
+$rg_lastaccess_log$ LANGUAGE plpgsql;
+
+-- Trigger, der nach Uebertragung der Fallakte an einen anderen
+-- Bearbeiter den alten und neuen Bearbeiter eintraegt in das Logbuch eintraegt.
+--
+CREATE OR REPLACE FUNCTION master_ds_editor_changed() RETURNS trigger AS $master_ds_editor_changed$
+DECLARE
+    lid      integer;
+    old_user RECORD;
+    new_user RECORD;
+BEGIN
+    IF OLD.bearbeiter_id <> NEW.bearbeiter_id THEN
+
+        SELECT INTO old_user * FROM ka_benutzer_tbl WHERE id = OLD.bearbeiter_id;
+        SELECT INTO new_user * FROM ka_benutzer_tbl WHERE id = NEW.bearbeiter_id;
+
+        SELECT INTO lid create_logbuch_ds(NEW.id, NULL);
+
+        UPDATE ka_logbuch_tbl_view
+            SET art = 0, 
+            notiz = 'Fallakte übertragen von ' 
+                    || coalesce(old_user.nachname, '-/-') || ', '
+                    || coalesce(old_user.vorname,  '-/-') || ' an '
+                    || coalesce(new_user.nachname, '-/-') || ', '
+                    || coalesce(new_user.vorname,  '-/-')
+        WHERE
+            id = lid;
+    END IF;
+    RETURN NEW;
+END;
+$master_ds_editor_changed$ LANGUAGE plpgsql;
+
+
+CREATE TRIGGER t_delete_anonymized_uuid 
+    AFTER DELETE ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE delete_anonymized_uuid();
+
+CREATE TRIGGER t_master_tbl_insert AFTER
+    INSERT ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log(); 
+
+CREATE TRIGGER t_master_tbl_update AFTER
+    UPDATE ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_master_tbl_delete AFTER
+    DELETE ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t1_master_tbl_update AFTER
+    UPDATE ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE master_lastaccess_log();
+
+CREATE TRIGGER t1_nm_benutzer_master_tbl_insert AFTER
+    INSERT ON nm_benutzer_master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_nm_benutzer_master_tbl_update AFTER
+    UPDATE ON nm_benutzer_master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_nm_benutzer_master_tbl_delete AFTER
+    DELETE ON nm_benutzer_master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_status_tbl_update AFTER
+    UPDATE ON ka_status_tbl
+    FOR EACH ROW EXECUTE PROCEDURE status_lastaccess_log();
+
+CREATE TRIGGER master_ds_editor_changed_trigger AFTER
+    UPDATE ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE master_ds_editor_changed();
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/03_configuration.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/03_configuration.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/03_configuration.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,86 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('04_configuration.sql', current_timestamp);
+
+CREATE TABLE ka_konfiguration_tbl
+(
+	id serial NOT NULL,
+	bez varchar(64) NOT NULL,
+	wert text,
+	CONSTRAINT ka_konfiguration_tbl_pkey PRIMARY KEY (id)
+);
+
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('fkz', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('ka_name', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('ka_adresse', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('ee_formular', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('fp_formular', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('ud_formular', '');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('anon_transfer', 'on');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('max_speicherdauer', '365');
+INSERT INTO ka_konfiguration_tbl (bez, wert) VALUES ('jmdstrukur_permission_userid', '');
+
+--
+-- Funktionen zum Erstellen und Loeschen von Konfigurationen 
+--
+
+CREATE OR REPLACE FUNCTION create_konfiguration_ds(_bez varchar, _wert varchar) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO ka_konfiguration_tbl(bez, wert) VALUES (_bez, _wert);
+    RETURN currval('ka_konfiguration_tbl_id_seq');
+END;
+$$ ;
+
+CREATE OR REPLACE FUNCTION delete_konfiguration_ds(kid integer ) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM ka_konfiguration_tbl WHERE id = kid;
+END;
+$$ ;
+
+-- Sicht auf die KA Konfigurations Tabelle 
+
+CREATE OR REPLACE VIEW ka_konfiguration_tbl_view AS 
+SELECT ka_konfiguration_tbl.id, ka_konfiguration_tbl.bez,
+ka_konfiguration_tbl.wert FROM ka_konfiguration_tbl;
+
+CREATE OR REPLACE RULE ka_konfiguration_delete_rule AS ON DELETE TO 
+ka_konfiguration_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_konfiguration_insert_rule AS ON INSERT TO 
+ka_konfiguration_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_konfiguration_update_rule AS ON UPDATE TO ka_konfiguration_tbl_view 
+	DO INSTEAD UPDATE ka_konfiguration_tbl SET
+	wert = new.wert
+	WHERE bez = new.bez;
+
+GRANT SELECT ON ka_konfiguration_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_konfiguration_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_konfiguration_tbl_view TO GROUP :admin_group;
+
+-- 
+-- TRIGGERS
+--
+
+-- ka_konfiguration_tbl
+CREATE TRIGGER t_ka_konfiguration_tbl_insert AFTER
+    INSERT ON ka_konfiguration_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_konfiguration_tbl_update AFTER
+    UPDATE ON ka_konfiguration_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_konfiguration_tbl_delete AFTER
+    DELETE ON ka_konfiguration_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/04_documents.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/04_documents.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/04_documents.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,215 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('05_documents.sql', current_timestamp);
+
+CREATE TABLE ka_dokumente_tbl
+(
+	id serial NOT NULL,
+    	uuid_id CHAR(36) UNIQUE,
+	master_id int4 REFERENCES master_tbl(id) ON DELETE CASCADE,
+	groesse int4,
+	mime varchar(64),
+	daten bytea, 
+	name varchar(128),
+	CONSTRAINT ka_dokumente_tbl_pkey PRIMARY KEY (id)
+);
+
+--
+-- Funktionen zum Erstellen von Dokumenten
+--
+CREATE OR REPLACE FUNCTION create_fall_dokument_ds(mid integer, nuuid char(36), filename varchar) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE 
+	did integer;
+	rid integer;
+BEGIN
+    IF NOT isEditorOrStandin(mid) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+
+    SELECT INTO did id from ka_dokumente_tbl WHERE name = filename AND mid = master_id;
+    IF NOT FOUND THEN
+    	INSERT INTO ka_dokumente_tbl(master_id) VALUES (mid);
+    	SELECT INTO rid currval('ka_dokumente_tbl_id_seq');
+    ELSE 
+        RETURN did;
+    END IF;
+
+    IF nuuid IS NOT NULL THEN
+        UPDATE ka_dokumente_tbl 
+        SET    uuid_id = nuuid 
+        WHERE  id = rid;
+    ELSE
+        PERFORM set_uuid('ka_dokumente_tbl', rid);
+    END IF;
+    RETURN rid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_fall_dokument_ds(integer, char(36), varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_fall_dokument_ds( integer, char(36), varchar) TO GROUP :cm_group;
+
+
+CREATE OR REPLACE FUNCTION delete_fall_dokument_ds(did integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    mid integer;
+BEGIN
+    SELECT INTO mid master_id FROM ka_dokumente_tbl WHERE id = did;
+    IF NOT isEditorOrStandin(mid) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+    DELETE FROM ka_dokumente_tbl WHERE id = did;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_fall_dokument_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_fall_dokument_ds(integer) 
+                TO GROUP :cm_group;
+
+--
+-- Funktion, die alle Anhaenge zu einem gegebenen Fall loescht
+--
+CREATE OR REPLACE FUNCTION delete_all_fall_dokumente(mid integer) 
+RETURNS void 
+LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+AS $$
+BEGIN
+    DELETE FROM ka_dokumente_tbl WHERE master_id = mid;
+END;
+$$;
+
+REVOKE ALL     ON FUNCTION delete_all_fall_dokumente(integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION delete_all_fall_dokumente(integer) TO GROUP :admin_group;
+
+-- Globale Dokumente 
+
+CREATE OR REPLACE FUNCTION create_global_dokument_ds(filename varchar) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    did integer;
+BEGIN
+    SELECT INTO did id from ka_dokumente_tbl WHERE name = filename and master_id IS NULL;
+    IF  NOT FOUND THEN
+    	INSERT INTO ka_dokumente_tbl (master_id) VALUES (NULL);
+    	RETURN currval('ka_dokumente_tbl_id_seq');
+    ELSE
+        RETURN did;
+    END IF;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_global_dokument_ds(varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_global_dokument_ds(varchar) TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION delete_global_dokument_ds(did integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM ka_dokumente_tbl WHERE id = did;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_global_dokument_ds(did integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_global_dokument_ds( integer ) 
+            TO GROUP :admin_group;
+
+-- 
+-- Sicht auf die Dokumenten Tabelle 
+--
+
+CREATE OR REPLACE VIEW ka_global_dokumente_tbl_view AS 
+SELECT ka_dokumente_tbl.id, ka_dokumente_tbl.master_id,
+ka_dokumente_tbl.groesse, ka_dokumente_tbl.mime, ka_dokumente_tbl.daten, ka_dokumente_tbl.name 
+FROM ka_dokumente_tbl WHERE ka_dokumente_tbl.master_id is NULL;
+
+CREATE OR REPLACE RULE ka_global_dokumente_delete_rule AS ON DELETE TO 
+ka_global_dokumente_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_global_dokumente_insert_rule AS ON INSERT TO 
+ka_global_dokumente_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_global_dokumente_update_rule AS ON UPDATE TO ka_global_dokumente_tbl_view 
+	DO INSTEAD  UPDATE ka_dokumente_tbl SET 
+	groesse = new.groesse, 
+	mime = new.mime, 
+	daten = new.daten, 
+	name = new.name 
+	WHERE ka_dokumente_tbl.id = new.id;
+
+GRANT SELECT ON ka_global_dokumente_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_global_dokumente_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_global_dokumente_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE VIEW ka_fall_dokumente_tbl_view AS 
+SELECT ka_dokumente_tbl.id, ka_dokumente_tbl.uuid_id, ka_dokumente_tbl.master_id,
+ka_dokumente_tbl.groesse, ka_dokumente_tbl.mime, ka_dokumente_tbl.daten,
+ka_dokumente_tbl.name FROM ka_dokumente_tbl 
+INNER JOIN master_tbl ON
+ka_dokumente_tbl.master_id = master_tbl.id 
+WHERE master_tbl.bearbeiter_id = getuserid()
+    OR master_tbl.id IN (
+        SELECT nm.master_id from nm_benutzer_master_tbl nm
+        WHERE nm.benutzer_id IN (
+	    SELECT nm2.gruppe_id from nm_benutzer_gruppe_tbl nm2 
+	    WHERE nm2.benutzer_id = getuserid()
+	)
+    )
+    OR pg_has_role('admin','MEMBER');
+
+CREATE OR REPLACE RULE ka_fall_dokumente_delete_rule AS ON DELETE TO 
+ka_fall_dokumente_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_fall_dokumente_insert_rule AS ON INSERT TO 
+ka_fall_dokumente_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_fall_dokumente_update_rule AS ON UPDATE TO ka_fall_dokumente_tbl_view 
+	DO INSTEAD  UPDATE ka_dokumente_tbl SET 
+	groesse = new.groesse, 
+	mime = new.mime, 
+	daten = new.daten, 
+	name = new.name 
+	WHERE ka_dokumente_tbl.id = new.id;
+
+GRANT SELECT ON ka_fall_dokumente_tbl_view TO GROUP :cm_group;
+GRANT UPDATE ON ka_fall_dokumente_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_fall_dokumente_tbl_view TO GROUP :admin_group;
+
+--
+-- TRIGGERS
+--
+
+-- ka_dokumente_tbl
+CREATE TRIGGER t_ka_dokumente_tbl_insert AFTER
+    INSERT ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_dokumente_tbl_update AFTER
+    UPDATE ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_dokumente_tbl_delete AFTER
+    DELETE ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t1_ka_dokumente_tbl_insert AFTER
+    INSERT ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_dokumente_tbl_update AFTER
+    UPDATE ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_dokumente_tbl_delete AFTER
+    DELETE ON ka_dokumente_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/05_appointments.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/05_appointments.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/05_appointments.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,221 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('06_appointments.sql', current_timestamp);
+
+-- Speichert grundlegende Angaben zu einem Termin. Weitergehende Angaben
+-- sollten in einer extra Tabelle gespeichert werden.
+CREATE TABLE ka_termine_tbl
+(
+	id serial NOT NULL,
+	master_id int4 REFERENCES master_tbl(id) ON DELETE CASCADE,
+	sdatum timestamp,
+	edatum timestamp,
+	name varchar(128),
+	beschreibung text,
+	art int4 DEFAULT 0, 
+	CONSTRAINT ka_termine_tbl_pkey PRIMARY KEY (id)
+);
+
+--
+-- Funktionen zum Erstellen und Löschen von Terminen
+--
+
+CREATE OR REPLACE FUNCTION create_fall_termin_ds(mid integer) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    IF NOT isEditorOrStandin(mid) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+    INSERT INTO ka_termine_tbl(master_id) VALUES (mid);
+    RETURN currval('ka_termine_tbl_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_fall_termin_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_fall_termin_ds( integer ) 
+                TO GROUP :cm_group;
+
+
+CREATE OR REPLACE FUNCTION delete_fall_termin_ds(tid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    mid integer;
+BEGIN
+    SELECT INTO mid master_id FROM ka_termine_tbl WHERE id = tid;
+    IF NOT isEditorOrStandin(mid) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+    DELETE FROM ka_termine_tbl WHERE id = tid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_fall_termin_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_fall_termin_ds(integer) 
+                TO GROUP :cm_group;
+
+--
+-- Funktion, die alle Termine zu einem gegebenen Fall loescht
+--
+CREATE OR REPLACE FUNCTION delete_all_fall_termine(mid integer) 
+RETURNS void 
+LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+AS $$
+BEGIN
+    DELETE FROM ka_termine_tbl WHERE master_id = mid;
+END;
+$$;
+
+REVOKE ALL     ON FUNCTION delete_all_fall_termine(integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION delete_all_fall_termine(integer) TO GROUP :admin_group;
+
+-- Globale Dokumente 
+
+CREATE OR REPLACE FUNCTION create_global_termin_ds() RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO ka_termine_tbl (master_id) VALUES (NULL);
+    RETURN currval('ka_termine_tbl_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_global_termin_ds() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_global_termin_ds() TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION delete_global_termin_ds(tid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM ka_termine_tbl WHERE id = tid;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_global_termin_ds(tid integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_global_termin_ds( integer ) 
+            TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION getlastcaseappointment(mid int4)
+	RETURNS "timestamp" AS
+$BODY$
+DECLARE
+	maxdate timestamp;
+BEGIN
+	SELECT INTO maxdate max(date::timestamp) FROM (
+	SELECT zugriff as date from 
+	ka_status_tbl_view
+	WHERE master_id = mid
+	UNION
+	SELECT max(sdatum) as date from 
+	ka_fall_termine_tbl_view
+	WHERE master_id = mid
+	UNION
+	SELECT max(edatum) as date from 
+	ka_fall_termine_tbl_view
+	WHERE master_id = mid
+	) as test;
+	RETURN maxdate;
+END;
+$BODY$ LANGUAGE 'plpgsql' VOLATILE;
+REVOKE ALL ON FUNCTION getlastcaseappointment(int) FROM public;
+GRANT EXECUTE ON FUNCTION getlastcaseappointment(int)  TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION getlastcaseappointment(int)  TO GROUP :admin_group;
+
+-- 
+-- Sicht auf die Termine Tabelle 
+--
+
+CREATE OR REPLACE VIEW ka_global_termine_tbl_view AS 
+SELECT ka_termine_tbl.id, ka_termine_tbl.master_id, ka_termine_tbl.sdatum, 
+ka_termine_tbl.edatum, ka_termine_tbl.name, ka_termine_tbl.beschreibung, ka_termine_tbl.art
+FROM ka_termine_tbl WHERE ka_termine_tbl.master_id is NULL;
+
+CREATE OR REPLACE RULE ka_global_termine_delete_rule AS ON DELETE TO 
+ka_global_termine_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_global_termine_insert_rule AS ON INSERT TO 
+ka_global_termine_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_global_termine_update_rule AS ON UPDATE TO ka_global_termine_tbl_view 
+	DO INSTEAD  UPDATE ka_termine_tbl SET 
+	sdatum = new.sdatum, 
+	edatum = new.edatum, 
+	name = new.name,
+	beschreibung = new.beschreibung,
+	art = new.art
+	WHERE ka_termine_tbl.id = new.id;
+
+GRANT SELECT ON ka_global_termine_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_global_termine_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_global_termine_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE VIEW ka_fall_termine_tbl_view AS 
+SELECT ka_termine_tbl.id, ka_termine_tbl.master_id,
+ka_termine_tbl.sdatum, ka_termine_tbl.edatum,
+ka_termine_tbl.name, ka_termine_tbl.beschreibung, ka_termine_tbl.art FROM ka_termine_tbl 
+INNER JOIN master_tbl ON
+ka_termine_tbl.master_id = master_tbl.id 
+WHERE master_tbl.bearbeiter_id = getuserid()
+    OR master_tbl.id IN (
+        SELECT nm.master_id from nm_benutzer_master_tbl nm
+        WHERE nm.benutzer_id IN (
+	    SELECT nm2.gruppe_id from nm_benutzer_gruppe_tbl nm2 
+	    WHERE nm2.benutzer_id = getuserid()
+	)
+    )
+    OR pg_has_role('admin','MEMBER');
+
+CREATE OR REPLACE RULE ka_fall_termine_delete_rule AS ON DELETE TO 
+ka_fall_termine_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_fall_termine_insert_rule AS ON INSERT TO 
+ka_fall_termine_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_fall_termine_update_rule AS ON UPDATE TO ka_fall_termine_tbl_view 
+	DO INSTEAD  UPDATE ka_termine_tbl SET 
+	sdatum = new.sdatum, 
+	edatum = new.edatum, 
+	name = new.name,
+	beschreibung = new.beschreibung,
+	art = new.art
+	WHERE ka_termine_tbl.id = new.id;
+
+GRANT SELECT ON ka_fall_termine_tbl_view TO GROUP :cm_group;
+GRANT UPDATE ON ka_fall_termine_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_fall_termine_tbl_view TO GROUP :admin_group;
+
+-- 
+-- TRIGGERS
+--
+-- ka_termine_tbl
+CREATE TRIGGER t_ka_termine_tbl_insert AFTER
+    INSERT ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_termine_tbl_update AFTER
+    UPDATE ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_termine_tbl_delete AFTER
+    DELETE ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t1_ka_termine_tbl_insert AFTER
+    INSERT ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_termine_tbl_update AFTER
+    UPDATE ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_termine_tbl_delete AFTER
+    DELETE ON ka_termine_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/06_logbook.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/06_logbook.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/06_logbook.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,255 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('07_logbook.sql', current_timestamp);
+
+-- ka_logbuch_art_tbl
+--
+-- Speichert die verschiedenen Arten von Logbuch-Eintraegen
+--
+
+CREATE TABLE ka_logbuch_art_tbl (
+    id         SERIAL NOT NULL,
+    beschreibung VARCHAR(256),
+    CONSTRAINT ka_logbuch_art_tbl_pkey PRIMARY KEY (id)
+);
+
+GRANT SELECT ON ka_logbuch_art_tbl TO GROUP :cm_group;
+GRANT SELECT ON ka_logbuch_art_tbl TO GROUP :admin_group;
+
+INSERT INTO ka_logbuch_art_tbl (id, beschreibung) VALUES  (-2, 'Sonstige Angaben');
+INSERT INTO ka_logbuch_art_tbl (id, beschreibung) VALUES  (-1, 'Keine Angabe');
+INSERT INTO ka_logbuch_art_tbl (id, beschreibung) VALUES  (0, 'Automatischer Eintrag');
+
+CREATE TABLE ka_logbuch_typ_tbl (
+    id         SERIAL NOT NULL,
+    beschreibung VARCHAR(256),
+    CONSTRAINT ka_logbuch_typ_tbl_pkey PRIMARY KEY (id)
+);
+
+GRANT SELECT ON ka_logbuch_typ_tbl TO GROUP :cm_group;
+GRANT SELECT ON ka_logbuch_typ_tbl TO GROUP :admin_group;
+
+INSERT INTO ka_logbuch_typ_tbl (id, beschreibung) VALUES (-1, 'Keine Angabe');
+
+-- ka_logbuch_tbl
+--
+-- Verwaltet Logbucheintraege zu Fallakten
+--
+
+CREATE TABLE ka_logbuch_tbl (
+    id         SERIAL NOT NULL,
+    master_id  int4 REFERENCES master_tbl(id)         ON DELETE CASCADE,
+    uuid_id    CHAR(36),
+    datum      TIMESTAMP,
+    bearbeiter VARCHAR(256),
+    art        int4 REFERENCES ka_logbuch_art_tbl(id) ON DELETE SET DEFAULT,
+    typ        int4 REFERENCES ka_logbuch_typ_tbl(id) ON DELETE SET DEFAULT,
+    kurz_notiz VARCHAR(256),
+    notiz      text,
+    dauer      interval,
+    UNIQUE (uuid_id),
+    CONSTRAINT ka_logbuch_tbl_pkey PRIMARY KEY (id)
+);
+
+
+--
+-- Funktionen zum Anlegen und Loeschen von Logbucheintraegen
+--
+CREATE OR REPLACE FUNCTION create_logbuch_ds(mid integer, nuuid CHAR(36)) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+AS $$
+DECLARE
+    lid integer;
+    editor_name varchar;
+BEGIN
+    IF NOT (isEditorOrStandin(mid) OR pg_has_role('admin','MEMBER')) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+
+    SELECT INTO editor_name nachname || ', ' || vorname from ka_benutzer_tbl WHERE id = getuserid();
+    INSERT INTO ka_logbuch_tbl(master_id, datum, bearbeiter) VALUES (mid, now(), editor_name);
+
+    SELECT INTO lid currval('ka_logbuch_tbl_id_seq');
+
+    IF nuuid IS NOT NULL THEN
+        UPDATE ka_logbuch_tbl SET uuid_id = nuuid WHERE id = lid;
+    ELSE
+        PERFORM set_uuid('ka_logbuch_tbl', lid);
+    END IF;
+
+    RETURN lid;
+END;
+$$;
+
+REVOKE ALL    ON FUNCTION create_logbuch_ds(integer, CHAR(36)) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_logbuch_ds(integer, CHAR(36)) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION create_logbuch_ds(integer, CHAR(36)) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION delete_logbuch_ds(tid integer) RETURNS void 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+DECLARE
+    mid integer;
+BEGIN
+    SELECT INTO mid master_id FROM ka_logbuch_tbl WHERE id = tid;
+    IF NOT isEditorOrStandin(mid) THEN
+        RAISE EXCEPTION 'DS ID not session_user ID';
+    END IF;
+    DELETE FROM ka_logbuch_tbl WHERE id = tid;
+END;
+$$ ;
+
+REVOKE ALL    ON FUNCTION delete_logbuch_ds(integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_logbuch_ds(integer) TO GROUP :cm_group;
+
+
+CREATE OR REPLACE FUNCTION delete_all_logbuch(mid integer) 
+RETURNS void 
+LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+AS $$
+BEGIN
+    DELETE FROM ka_logbuch_tbl WHERE master_id = mid;
+END;
+$$;
+
+REVOKE ALL     ON FUNCTION delete_all_logbuch(integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION delete_all_logbuch(integer) TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION anonymize_logbuch(mid integer) 
+RETURNS void 
+LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+AS $$
+BEGIN
+    -- DELETE FROM ka_logbuch_tbl WHERE master_id = mid;
+    UPDATE ka_logbuch_tbl SET
+        uuid_id    = NULL,
+        bearbeiter = md5(lower(trim(both ' ' from coalesce(bearbeiter, '')))),
+        kurz_notiz = NULL,
+        notiz      = NULL
+    WHERE master_id = mid;
+END;
+$$;
+
+REVOKE ALL     ON FUNCTION anonymize_logbuch(integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION anonymize_logbuch(integer) TO GROUP :admin_group;
+
+
+-- Wrapper Funktion die alle noetigen Funktionen zum Anonymisieren einer
+-- Fallakte aufruft.
+CREATE OR REPLACE FUNCTION anonymize_case_wrapper(mid integer)
+RETURNS void AS
+$$
+BEGIN
+	PERFORM anonymize_case(mid);
+	PERFORM delete_all_fall_dokumente(mid);
+	PERFORM delete_all_fall_termine(mid);
+	PERFORM anonymize_logbuch(mid);
+END;
+$$ LANGUAGE plpgsql VOLATILE SECURITY DEFINER;
+
+REVOKE ALL     ON FUNCTION anonymize_case_wrapper(integer) FROM PUBLIC;
+GRANT  EXECUTE ON FUNCTION anonymize_case_wrapper(integer) TO GROUP :admin_group;
+
+--
+-- Views auf dem Logbuch
+--
+
+CREATE OR REPLACE VIEW ka_logbuch_tbl_view 
+    AS SELECT
+        ka_logbuch_tbl.id         AS id,
+        ka_logbuch_tbl.uuid_id    AS uuid_id,
+        ka_logbuch_tbl.master_id  AS master_id,
+        ka_logbuch_tbl.datum      AS datum,
+        ka_logbuch_tbl.bearbeiter AS bearbeiter,
+        ka_logbuch_tbl.art        AS art,
+        ka_logbuch_tbl.typ        AS typ,
+        ka_logbuch_tbl.kurz_notiz AS kurz_notiz,
+        ka_logbuch_tbl.notiz      AS notiz,
+        ka_logbuch_tbl.dauer      AS dauer
+    FROM ka_logbuch_tbl
+    INNER JOIN master_tbl ON
+        ka_logbuch_tbl.master_id = master_tbl.id
+    WHERE
+        master_tbl.bearbeiter_id = getuserid()
+        OR master_tbl.id IN (
+            SELECT nm.master_id FROM nm_benutzer_master_tbl nm
+            WHERE nm.benutzer_id IN (
+                SELECT nm2.gruppe_id FROM nm_benutzer_gruppe_tbl nm2 
+                WHERE nm2.benutzer_id = getuserid())
+        )
+        OR pg_has_role('admin','MEMBER');
+
+CREATE OR REPLACE RULE ka_logbuch_update_rule
+    AS ON UPDATE TO ka_logbuch_tbl_view 
+	DO INSTEAD
+        UPDATE ka_logbuch_tbl SET
+            datum      = new.datum,
+            bearbeiter = new.bearbeiter,
+            art        = new.art,
+            typ        = new.typ,
+            kurz_notiz = new.kurz_notiz,
+            notiz      = new.notiz,
+            dauer      = new.dauer
+	    WHERE ka_logbuch_tbl.id = new.id;
+
+CREATE OR REPLACE RULE ka_logbuch_delete_rule 
+    AS ON DELETE TO  ka_logbuch_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_logbuch_insert_rule
+    AS ON INSERT TO ka_logbuch_tbl_view DO INSTEAD NOTHING;
+
+GRANT SELECT ON ka_logbuch_tbl_view TO GROUP :cm_group;
+GRANT UPDATE ON ka_logbuch_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_logbuch_tbl_view TO GROUP :admin_group;
+
+-- 
+-- TRIGGERS
+-- 
+
+CREATE OR REPLACE FUNCTION master_ds_created_logbook() RETURNS trigger AS $master_ds_created_logbook$
+DECLARE
+    lid integer;
+BEGIN
+    SELECT INTO lid create_logbuch_ds(NEW.id, NULL);
+    UPDATE ka_logbuch_tbl_view
+        SET art = 0, typ = -1, notiz = 'Fallakte angelegt.'
+    WHERE
+        id = lid;
+    RETURN NEW;
+END;
+$master_ds_created_logbook$ LANGUAGE plpgsql;
+
+CREATE TRIGGER master_ds_created_logbook_trigger AFTER
+    INSERT ON master_tbl
+    FOR EACH ROW EXECUTE PROCEDURE master_ds_created_logbook();
+
+
+-- ka_logbuch_tbl
+CREATE TRIGGER t_ka_logbuch_tbl_insert AFTER
+    INSERT ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_logbuch_tbl_update AFTER
+    UPDATE ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t_ka_logbuch_tbl_delete AFTER
+    DELETE ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE mpuls_log();
+
+CREATE TRIGGER t1_ka_logbuch_tbl_insert AFTER
+    INSERT ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_logbuch_tbl_update AFTER
+    UPDATE ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+CREATE TRIGGER t1_ka_logbuch_tbl_delete AFTER
+    DELETE ON ka_logbuch_tbl
+    FOR EACH ROW EXECUTE PROCEDURE rg_lastaccess_log();
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/07_news.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/07_news.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/07_news.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,105 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('08_news.sql', current_timestamp);
+
+CREATE TABLE ka_nachrichten_art_tbl (
+    id         SERIAL NOT NULL,
+    beschreibung VARCHAR(128),
+    CONSTRAINT ka_nachrichten_art_tbl_pkey PRIMARY KEY (id)
+);
+
+INSERT INTO ka_nachrichten_art_tbl (id, beschreibung) VALUES ( -2, 'Sonstiges');
+INSERT INTO ka_nachrichten_art_tbl (id, beschreibung) VALUES ( -1, 'Keine Angabe');
+INSERT INTO ka_nachrichten_art_tbl (id, beschreibung) VALUES (  0, 'Systemnachricht');
+
+CREATE TABLE ka_nachrichten_tbl (
+    id         SERIAL NOT NULL,
+    datum      TIMESTAMP,
+    art        int4 REFERENCES ka_nachrichten_art_tbl(id) ON DELETE SET DEFAULT,
+    titel      VARCHAR(128),
+    nachricht  text,
+    CONSTRAINT ka_nachrichten_tbl_pkey PRIMARY KEY (id)
+);
+
+CREATE TABLE nm_benutzer_nachrichten_tbl 
+(
+	id serial NOT NULL,
+	benutzer_id int4 REFERENCES ka_benutzer_tbl(id) ON DELETE CASCADE,
+	nachrichten_id int4 REFERENCES ka_nachrichten_tbl(id) ON DELETE CASCADE,
+	gelesen timestamp DEFAULT now(),
+	CONSTRAINT nm_benutzer_news_pkey PRIMARY KEY (id)
+);
+
+CREATE OR REPLACE FUNCTION markNewsAsRead( user_id integer, news_id integer) RETURNS VOID 
+    LANGUAGE 'plpgsql' SECURITY DEFINER 
+    AS $$
+BEGIN
+    INSERT INTO nm_benutzer_nachrichten_tbl (benutzer_id, nachrichten_id) VALUES (user_id, news_id);
+END;
+$$;
+
+REVOKE ALL ON FUNCTION markNewsAsRead(user_id integer, news_id integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION markNewsAsRead(user_id integer, news_id integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION markNewsAsRead(user_id integer, news_id integer) TO GROUP :admin_group;
+
+--
+-- Views auf die Nachrichten
+--
+
+CREATE OR REPLACE VIEW ka_nachrichten_art_tbl_view 
+    AS SELECT
+        a.id           AS id,
+        a.beschreibung AS beschreibung
+    FROM ka_nachrichten_art_tbl a;
+
+CREATE OR REPLACE RULE ka_nachrichten_art_update_rule 
+    AS ON UPDATE TO ka_nachrichten_art_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_nachrichten_art_delete_rule 
+    AS ON DELETE TO ka_nachrichten_art_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_nachrichten_art_insert_rule
+    AS ON INSERT TO ka_nachrichten_art_tbl_view DO INSTEAD NOTHING;
+
+GRANT SELECT ON ka_nachrichten_art_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_nachrichten_art_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE VIEW ka_nachrichten_tbl_view 
+    AS SELECT
+        n.id           AS id,
+        n.datum        AS datum,
+        n.art          AS art,
+        a.beschreibung AS art_beschreibung,
+        n.titel        AS titel,
+        n.nachricht    AS nachricht
+    FROM ka_nachrichten_tbl n JOIN ka_nachrichten_art_tbl a
+    ON n.art = a.id;
+
+CREATE OR REPLACE RULE ka_nachrichten_update_rule
+    AS ON UPDATE TO ka_nachrichten_tbl_view 
+	DO INSTEAD
+        UPDATE ka_nachrichten_tbl SET
+            art        = new.art,
+            titel      = new.titel,
+            nachricht  = new.nachricht
+	    WHERE ka_nachrichten_tbl.id = new.id;
+
+CREATE OR REPLACE RULE ka_nachrichten_delete_rule 
+    AS ON DELETE TO  ka_nachrichten_tbl_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE ka_nachrichten_insert_rule
+    AS ON INSERT TO ka_nachrichten_tbl_view DO INSTEAD NOTHING;
+
+GRANT SELECT ON ka_nachrichten_tbl_view TO GROUP :cm_group;
+GRANT SELECT ON ka_nachrichten_tbl_view TO GROUP :admin_group;
+GRANT UPDATE ON ka_nachrichten_tbl_view TO GROUP :admin_group;
+
+CREATE OR REPLACE  VIEW nm_benutzer_nachrichten_tbl_view AS
+    SELECT id, benutzer_id, nachrichten_id, gelesen FROM nm_benutzer_nachrichten_tbl; 
+
+GRANT SELECT ON nm_benutzer_nachrichten_tbl_view TO :cm_group;
+GRANT SELECT ON nm_benutzer_nachrichten_tbl_view TO :admin_group;
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/08_tags.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/08_tags.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/08_tags.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,169 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('09_tags.sql', current_timestamp);
+
+CREATE TABLE tags (
+    id          SERIAL PRIMARY KEY,
+    label       VARCHAR(256) NOT NULL,
+    description TEXT,
+    systemtag   BOOLEAN DEFAULT TRUE
+);
+
+CREATE TABLE nm_tags_cases ( 
+    id SERIAL PRIMARY KEY,
+    master_id   integer NOT NULL REFERENCES master_tbl(id) ON DELETE CASCADE,
+    tag_id    integer NOT NULL REFERENCES tags(id)       ON DELETE CASCADE,
+    created   TIMESTAMP DEFAULT now(),
+    UNIQUE (master_id, tag_id)
+);
+
+DELETE FROM tags;
+INSERT INTO tags (id, label, description) VALUES (0, 'Alle', 'Jede Fallakte hat einen Tag');
+
+-- Move tags serial: userdefined tags start at 10000
+ALTER SEQUENCE tags_id_seq RESTART 10000;
+
+-- Tags
+CREATE OR REPLACE FUNCTION create_nm_tag_case_ds ( tagid integer, 
+    masterid integer ) RETURNS integer
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    INSERT INTO nm_tags_cases (tag_id, master_id) 
+        VALUES (tagid, masterid);
+    RETURN currval('nm_tags_cases_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_nm_tag_case_ds(integer, integer) 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_nm_tag_case_ds(integer, integer) 
+                TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION create_nm_tag_case_ds(integer, integer) 
+                TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION delete_nm_tag_case_ds ( tagid integer,
+    masterid integer ) RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM nm_tags_cases 
+            WHERE master_id = masterid AND tag_id = tagid; 
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_nm_tag_case_ds(integer, integer) 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_nm_tag_case_ds(integer, integer) 
+                TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION delete_nm_tag_case_ds(integer, integer) 
+                TO GROUP :admin_group;
+
+
+CREATE OR REPLACE FUNCTION delete_tag_ds ( tagid integer) RETURNS VOID 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+    DELETE FROM tags WHERE id = tagid; 
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION delete_tag_ds(integer) 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION delete_tag_ds(integer) 
+                TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION create_tag_ds () RETURNS INTEGER 
+    LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+    AS $$
+BEGIN
+     INSERT INTO tags (label, description) 
+         VALUES ('', NULL);
+     RETURN currval('tags_id_seq');
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION create_tag_ds() 
+                FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION create_tag_ds() 
+                TO GROUP :admin_group;
+
+
+-- Da Tagging nicht mehr auf der Datenbank durchgeführt wird ist diese
+-- Funktion deaktiviert.
+
+-- SET ROLE postgres;
+-- 
+-- CREATE OR REPLACE FUNCTION check_case(ds_id integer) RETURNS void 
+-- AS $$
+-- import socket
+-- 
+-- UNIX_SOCKET = "/tmp/tagd-socket"
+-- 
+-- db = plpy.execute("SELECT current_database() as db")[0]["db"]
+-- 
+-- s = None
+-- try:
+--     try:
+--         s = socket.socket(socket.AF_UNIX, socket.SOCK_STREAM)
+--         s.connect(UNIX_SOCKET)
+--         s.send("%s %d\n" % (db, ds_id))
+--     except:
+--         plpy.warning('Can not connect tagd socket')
+-- finally:
+--     if s:
+--         try: s.close()
+--         except: pass
+--           
+-- $$ LANGUAGE plpythonu;
+-- 
+-- SET ROLE :adm_ka_owner;
+
+-- Tags
+
+CREATE OR REPLACE VIEW tags_view 
+    AS SELECT
+        id,
+        label,
+        description,
+        systemtag
+    FROM tags;
+
+CREATE OR REPLACE RULE tags_update_rule
+    AS ON UPDATE TO tags_view 
+	DO INSTEAD
+        UPDATE tags SET
+            label      = new.label,
+            description = new.description,
+            systemtag = new.systemtag
+	    WHERE tags.id = new.id;
+
+CREATE OR REPLACE RULE tags_delete_rule 
+    AS ON DELETE TO  tags_view DO INSTEAD NOTHING;
+
+CREATE OR REPLACE RULE tags_insert_rule
+    AS ON INSERT TO tags_view DO INSTEAD NOTHING;
+
+
+GRANT SELECT ON tags_view TO GROUP :cm_group;
+GRANT UPDATE ON tags_view TO GROUP :cm_group;
+GRANT SELECT ON tags_view TO GROUP :admin_group;
+GRANT UPDATE ON tags_view TO GROUP :admin_group;
+
+CREATE OR REPLACE VIEW nm_tags_cases_view 
+    AS SELECT
+        id,
+        master_id as case_id,
+        tag_id,
+        created 
+    FROM nm_tags_cases;
+
+GRANT SELECT ON nm_tags_cases_view TO GROUP :cm_group;
+GRANT UPDATE ON nm_tags_cases_view TO GROUP :cm_group;
+GRANT SELECT ON nm_tags_cases_view TO GROUP :admin_group;
+GRANT UPDATE ON nm_tags_cases_view TO GROUP :admin_group;
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/install/09_helpers.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/install/09_helpers.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/install/09_helpers.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,193 @@
+SET ROLE :adm_ka_owner;
+BEGIN;
+
+INSERT INTO db_history (beschreibung, zeitpunkt) 
+	VALUES ('01_helpers.sql', current_timestamp);
+
+-- Author: Torsten Irlaender
+-- Funktionen, die für die Anonymisierung der Fallakten genutzt werden.
+
+CREATE OR REPLACE FUNCTION shorten_value(myvalue varchar, len integer) 
+RETURNS varchar 
+LANGUAGE 'plpgsql' STABLE AS 
+$$
+BEGIN
+    return substring(myvalue, 1, len);
+END;
+$$;
+
+REVOKE ALL ON FUNCTION shorten_value(varchar, integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION shorten_value(varchar, integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION shorten_value(varchar, integer) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION hash_value(myvalue varchar, myvalue2 varchar) 
+RETURNS varchar 
+LANGUAGE 'plpgsql' STABLE AS 
+$$
+BEGIN
+    return md5(coalesce(myvalue, '') || coalesce(myvalue2, ''));
+END;
+$$;
+
+REVOKE ALL ON FUNCTION hash_value(varchar, varchar) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION hash_value(varchar, varchar) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION hash_value(varchar, varchar) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION get_age(myvalue date) 
+RETURNS date 
+LANGUAGE 'plpgsql' STABLE AS 
+$$
+BEGIN
+    return date_trunc('year', myvalue::timestamp);
+END;
+$$;
+
+REVOKE ALL ON FUNCTION get_age(date) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION get_age(date) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION get_age(date) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION check_bool(myvalue integer, mybool integer) 
+RETURNS integer 
+LANGUAGE 'plpgsql' STABLE AS 
+$$
+BEGIN
+    IF mybool = 1 THEN
+        return myvalue;
+    ELSE
+        return NULL::integer;
+    END IF;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION check_bool(integer, integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION check_bool(integer, integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION check_bool(integer, integer) TO GROUP :admin_group;
+
+CREATE OR REPLACE FUNCTION check_bool(myvalue varchar, mybool integer) 
+RETURNS varchar 
+LANGUAGE 'plpgsql' STABLE AS 
+$$
+BEGIN
+    IF mybool = 1 THEN
+        return myvalue;
+    ELSE
+        return NULL::varchar;
+    END IF;
+END;
+$$;
+
+REVOKE ALL ON FUNCTION check_bool(varchar, integer) FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION check_bool(varchar, integer) TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION check_bool(varchar, integer) TO GROUP :admin_group;
+
+-- ----------------------------------------------------------------------------
+-- 
+-- Haeufige Abfragen, die sowohl von der Gruppe CM_KA, als auch Admin_KA
+-- ausgefuehrt werden koennen.
+-- 
+
+--
+-- gettotal()
+-- Anzahl aller Faelle des Fallmanagers oder der KA (wenn Admin)
+--
+CREATE OR REPLACE FUNCTION gettotal() RETURNS integer
+    LANGUAGE 'plpgsql' 
+    AS $$
+DECLARE 
+    total int4;
+BEGIN
+    SELECT INTO total count(id) FROM master_tbl_eval_total_view;
+    RETURN total;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION gettotal() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION gettotal() TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION gettotal() TO GROUP :admin_group;
+
+
+--
+-- gettotalcm()
+-- Anzahl aller Faelle des Fallmanagers oder der KA (wenn Admin),
+-- die sich im Case-Management befinden.
+--
+CREATE OR REPLACE FUNCTION gettotalcm() RETURNS integer
+    LANGUAGE 'plpgsql' 
+    AS $$
+DECLARE
+    total_cm int4;
+BEGIN
+    SELECT INTO total_cm count(id) FROM master_tbl_eval_incm_view;
+    RETURN total_cm;
+END;
+$$ ;
+
+REVOKE ALL ON FUNCTION gettotalcm() FROM PUBLIC;
+GRANT EXECUTE ON FUNCTION gettotalcm() TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION gettotalcm() TO GROUP :admin_group;
+
+-- 
+-- get_masterid_from_uuid(myrel varchar, uuid char) 
+-- Author: Torsten Irlaender 
+--
+-- Gibt die master id des datensatzes mit der übergebenen uuid in der
+-- angegebenen realtion wieder. Wenn ein solcher datensatz nicht existiert, wird
+-- NULL zurueck gegeben.
+--
+
+CREATE OR REPLACE FUNCTION get_masterid_from_uuid(myrel varchar(128), uuid char(36))
+    RETURNS integer AS
+$$
+DECLARE
+    myid integer;
+BEGIN
+    IF myrel = 'master' THEN
+        SELECT INTO myid id from master_tbl WHERE uuid_id = uuid;
+    ELSIF myrel = 'logbuch' THEN
+        SELECT INTO myid master_id from ka_logbuch_tbl WHERE uuid_id = uuid;
+    ELSIF myrel = 'dokumente' THEN
+        SELECT INTO myid master_id from ka_dokumente_tbl WHERE uuid_id = uuid;
+    END IF;
+    RETURN myid;
+END;
+$$ LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER;
+REVOKE ALL ON FUNCTION get_masterid_from_uuid(varchar, char) FROM public;
+GRANT EXECUTE ON FUNCTION get_masterid_from_uuid(varchar, char)  TO GROUP :cm_group;
+GRANT EXECUTE ON FUNCTION get_masterid_from_uuid(varchar, char)  TO GROUP :admin_group;
+
+-- Funktion wird offenbar nirgens mehr aufgerufen.
+-- -- Funktion get_default_value() gibt zu einer
+-- -- gegebenen Relation und Spalte den Default-Wert zurueck gibt.
+-- 
+-- CREATE OR REPLACE FUNCTION get_default_value(relation_name text, attribute_name text)
+-- RETURNS text 
+-- LANGUAGE plpgsql STABLE AS
+-- $$
+-- DECLARE
+--     has_def bool;
+--     def     text;
+-- BEGIN
+--     SELECT INTO has_def a.atthasdef FROM pg_class c 
+--     JOIN pg_attribute a ON c.oid = a.attrelid
+--     WHERE c.relname = relation_name AND a.attname = attribute_name;
+-- 
+--     IF has_def IS NULL OR NOT has_def THEN
+--         RETURN NULL;
+--     END IF;
+-- 
+--     SELECT INTO def pg_get_expr(i.adbin, i.oid) FROM 
+--     (SELECT c.oid, adnum, r.adbin
+--         FROM pg_class c 
+--         JOIN pg_attrdef r ON r.adrelid = c.oid
+--         WHERE c.relname = relation_name) i
+--         INNER JOIN pg_attribute p ON attrelid = i.oid AND i.adnum = p.attnum
+--         WHERE p.attname = attribute_name;
+--     RETURN def;
+-- END;
+-- $$;
+-- 
+-- REVOKE ALL ON FUNCTION get_default_value(text, text) FROM public;
+-- GRANT EXECUTE ON FUNCTION get_default_value(text, text) TO GROUP :cm_group;
+-- GRANT EXECUTE ON FUNCTION get_default_value(text, text) TO GROUP :admin_group;
+
+COMMIT;

Added: base/trunk/mpulsweb/commands/db/scripts/mpuls-create-db.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/mpuls-create-db.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/mpuls-create-db.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1 @@
+CREATE DATABASE ka_${db_name}_db WITH TEMPLATE = mpuls_template;

Added: base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,10 @@
+00_preconditions.sql
+01_user.sql
+02_datamodel.sql
+03_configuration.sql
+04_documents.sql
+05_appointments.sql
+06_logbook.sql
+07_news.sql
+08_tags.sql
+09_helpers.sql

Added: base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt.old
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt.old	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/mpuls-create-tables.txt.old	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,9 @@
+old/00precond.sql
+old/01tmpl.sql
+old/02tables.sql
+old/03functions.sql
+old/04views.sql
+old/05cascades.sql
+old/06contraints.sql
+old/07logging.sql
+old/08rgroup.sql

Added: base/trunk/mpulsweb/commands/db/scripts/mpuls-init-cluster.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/mpuls-init-cluster.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/mpuls-init-cluster.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1,352 @@
+-- 
+-- Anlegen eines WASKA-Datenbankclusters unter PostgreSQL
+--
+-- Autor: Frank Koormann <frank at intevation.de>
+-- Stand: 2008-01-09
+--
+-- Notwendige Anpassungen: 
+--
+
+-- TODO:
+-- - Löschen einer Datenbank.
+-- 
+
+\connect postgres postgres
+
+-- ------------------------------------------------------------------------
+-- Anlegen der Basisrolen und Wartungsdatenbank
+--
+
+-- Generische Rolle WASKA-Admin, Verwaltungsrollen erben diese Rolle, um 
+-- Zugang zur Wartungsdatenbank zu bekommen.
+-- 01.11.2007: Brauchen wir die noch?
+CREATE ROLE mpuls_admin NOLOGIN
+    NOSUPERUSER NOINHERIT NOCREATEDB NOCREATEROLE;
+
+-- Eine extra Rolle, die Rollen/Benutzer anlegen/verwalten darf. Diese Rolle
+-- definiert später die Funktionen zur Verwaltung der Benutzer, die über
+-- "SECURITY DEFINER" dann mit erhöhten Rechten laufen.
+CREATE ROLE mpuls_role_adm NOLOGIN
+    NOSUPERUSER NOINHERIT NOCREATEDB CREATEROLE;
+
+-- Rolle PT-DLR, Verwaltung des Clusters:
+-- - Anlegen von KA_DBs
+-- - Löschen von KA_DBs
+CREATE ROLE pt_dlr NOLOGIN
+    NOSUPERUSER INHERIT CREATEDB NOCREATEROLE;
+GRANT mpuls_admin TO pt_dlr; 
+GRANT mpuls_role_adm TO pt_dlr; 
+
+-- Rolle Admin-KA, Elternrolle für die Rollen in den einzelnen KA zur 
+-- Verwaltung einer KA_DB:
+-- - Anlegen von Nutzern in einer KA
+-- - Löschen von Nutzern in einer KA
+-- - Passworte von Nutzern zurücksetzen.
+CREATE ROLE admin NOLOGIN
+    NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE;
+GRANT mpuls_admin TO admin;
+
+-- Wartungsdatenbank
+CREATE database mpuls_maintenance WITH TEMPLATE = template0 ENCODING = 'UTF8';
+REVOKE ALL ON DATABASE mpuls_maintenance FROM public;
+GRANT CONNECT ON DATABASE mpuls_maintenance TO mpuls_admin;
+
+-- ------------------------------------------------------------------------
+-- Anlegen der Funktionen in der Wartungsdatenbank
+--
+
+\connect mpuls_maintenance postgres
+CREATE LANGUAGE plpgsql;
+CREATE PROCEDURAL LANGUAGE 'plpythonu' HANDLER plpython_call_handler;
+
+-- Passwortgenerator variabler Länge. Nutzt pwgen, um konforme Passworte zu
+-- generieren
+CREATE OR REPLACE FUNCTION mpuls_passgen(pw_length int) RETURNS text 
+  LANGUAGE 'plpythonu' VOLATILE
+  AS $$
+    from os import popen
+    from random import sample 
+    pw = None
+    try:
+      try:
+        pw = popen("/usr/bin/pwgen --ambiguous --numerals --symbols %s"
+                    % pw_length)
+        return pw.readline().strip()
+      except:
+        pop = [chr(c) for c in range(33,127+1)]
+        return "".join(sample(pop, pw_length)) 
+    finally:
+      if pw:
+        try: pw.close()
+        except: pass
+$$;
+
+ALTER FUNCTION mpuls_passgen(int) OWNER TO pt_dlr;
+REVOKE ALL ON FUNCTION mpuls_passgen(int) FROM public;
+
+SET ROLE pt_dlr;
+
+\connect mpuls_maintenance postgres
+-- mpuls_init_database( agentur ) returns text
+-- Initialisieren einer Datenbank, mit entsprechenden Rollen für die KA und
+-- Login-Rolle 'ka_<agentur>_adm'. Rückgabewert ist das initiale Passwort der
+-- Login-Rolle 'ka_<NAME AGENTUR>_adm'. Diese Funktion steht der Rolle "PT-DLR"
+-- zur Verfügung.
+-- 
+-- Die Datenbank muss vorher angelegt sein, entsprechend muss auch die
+-- Prüfung auf korrekten Namen vorher stattfinden. (CREATE DATABASE kann
+-- nicht in einem Skript aufgerufen werden)
+CREATE OR REPLACE FUNCTION mpuls_init_database (
+        agency varchar(52)
+  ) RETURNS text LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+  AS $$
+  DECLARE
+    db_name   varchar(64);
+    adm_group varchar(64);
+    adm_user  varchar(64);
+    cm_group  varchar(64);
+    pb_group  varchar(64);
+    pw        varchar(13);
+  BEGIN
+    -- Gruppen fuer die KA
+    adm_group := quote_ident('ka_' || agency || '_admin');
+    cm_group :=  quote_ident('ka_' || agency || '_cm');
+    pb_group :=  quote_ident('ka_' || agency || '_pb');
+    EXECUTE 'CREATE ROLE ' || adm_group
+        || ' NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE';
+    EXECUTE 'GRANT admin TO ' || adm_group;
+    EXECUTE 'CREATE ROLE ' || cm_group
+        || ' NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE';
+    EXECUTE 'CREATE ROLE ' || pb_group
+        || ' NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE';
+    EXECUTE 'GRANT ' || adm_group || ' TO ' || pb_group;
+
+    -- Administratives Konto (Besitzer der DB) einrichten
+    db_name := quote_ident('ka_' || agency || '_db');
+    adm_user := quote_ident('ka_' || agency || '_adm');
+    pw := mpuls_passgen(12);
+    EXECUTE 'CREATE ROLE ' || adm_user
+        || ' LOGIN NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE'
+        || ' PASSWORD ' || quote_literal(pw);
+    EXECUTE 'REVOKE ALL ON DATABASE ' || db_name || ' FROM PUBLIC';
+    EXECUTE 'ALTER DATABASE ' || db_name
+            || ' OWNER TO ' || adm_user;
+    EXECUTE 'GRANT ' || adm_group || ' TO ' || adm_user;
+
+    RETURN pw::text;
+  END;
+$$ ;
+REVOKE ALL ON FUNCTION mpuls_init_database( varchar ) FROM public;
+GRANT EXECUTE ON FUNCTION mpuls_init_database( varchar ) TO pt_dlr;
+
+-- Löschen einer Datenbank für KA-DB
+-- - Löschen aller Konten für KA (stehen in Tabelle der KA)
+-- - Löschen des administrativen Kontos
+-- - Löschen der Gruppen für KA
+-- - Löschen der Datenbank
+
+-- -----------------------------------------------------------------------
+-- Template-Datenbank für Kompetenzagenturen
+CREATE DATABASE mpuls_template WITH TEMPLATE = template0 ENCODING = 'UTF8';
+REVOKE ALL ON DATABASE mpuls_template FROM public;
+\connect mpuls_template postgres
+CREATE LANGUAGE plpgsql;
+CREATE PROCEDURAL LANGUAGE 'plpythonu' HANDLER plpython_call_handler;
+
+-- Passwortgenerator variabler Länge
+-- Passwortgenerator variabler Länge. Nutzt pwgen, um konforme Passworte zu
+-- generieren
+CREATE OR REPLACE FUNCTION mpuls_passgen(pw_length int) RETURNS text 
+  LANGUAGE 'plpythonu' VOLATILE
+  AS $$
+    from os import popen
+    from random import sample 
+    pw = None
+    try:
+      try:
+        pw = popen("/usr/bin/pwgen --ambiguous --numerals --symbols %s"
+                    % pw_length)
+        return pw.readline().strip()
+      except:
+      	pop = [chr(c) for c in range(33,127+1)]
+        return "".join(sample(pop, pw_length)) 
+    finally:
+      if pw:
+        try: pw.close()
+        except: pass
+$$;
+
+ALTER FUNCTION mpuls_passgen(int) OWNER TO mpuls_role_adm;
+REVOKE ALL ON FUNCTION mpuls_passgen(int) FROM public;
+
+
+-- Funktionen zur Benutzerverwaltung mit Rechten der Rolle mpuls_role_adm
+-- anlegen (und später ausführen).
+SET ROLE mpuls_role_adm;
+
+
+-- mpuls_create_role( nutzer, gruppenrolle, agentur ) returns text 
+-- Anlegen einer Login-Rolle 'ka_<agentur>_<nutzer>' in der gruppenrolle:
+-- 'CM-KA' oder 'Admin-KA'. Es wird anhand der Namensräume überprüft, ob die
+-- aufrufende Rolle berechtigt ist, für die angegebene KA Nutzer anzulegen.
+-- Rückgabewert ist die Loginrolle und das initiale Passwort.
+CREATE OR REPLACE FUNCTION mpuls_create_role (
+        username varchar(64),
+        grouprole varchar(64), 
+        agency varchar(52)
+  ) RETURNS RECORD LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+  AS $$
+  DECLARE 
+    db_name  varchar(64);
+    db_user  varchar(128);
+    db_group varchar(64);
+    pb_group varchar(64);
+    pw       varchar(9);
+    result   RECORD;
+  BEGIN
+    -- IF position(quote_literal(agency) in session_user) != 4
+    IF position(agency in session_user) != 4
+    THEN
+      RAISE EXCEPTION 
+          'Permission denied to create role %s in agency % by %.',
+          quote_literal(username), quote_literal(agency), session_user;
+    ELSE
+      db_name := quote_ident('ka_' || agency || '_db');
+      db_user := quote_ident('ka_' || agency || '_' || username);
+      IF lower(grouprole) = 'admin' THEN
+        db_group := quote_ident('ka_' || agency || '_admin');
+      ELSIF lower(grouprole) = 'pb' THEN
+        db_group := quote_ident('ka_' || agency || '_pb');
+      ELSE
+        db_group := quote_ident('ka_' || agency || '_cm');
+      END IF;
+      pw := mpuls_passgen(8);
+      EXECUTE 'CREATE ROLE ' || db_user 
+          || ' LOGIN NOSUPERUSER INHERIT NOCREATEDB NOCREATEROLE'
+          || ' PASSWORD ' || quote_literal(pw);
+      EXECUTE 'GRANT ' || db_group || ' TO ' || db_user;
+      SELECT INTO result db_name::varchar(64), db_user::varchar(64), pw::varchar(9);
+      RETURN result;
+    END IF;
+
+  END;
+$$ ;
+REVOKE ALL ON FUNCTION mpuls_create_role( varchar, varchar, varchar ) 
+    FROM public;
+GRANT EXECUTE ON FUNCTION mpuls_create_role( varchar, varchar, varchar ) 
+    TO admin;
+
+-- mpuls_revoke_connect( nutzer, agentur ) returns boolean
+-- Zurückziehen der CONNECT-Berechtigung des Nutzers für die DB der Agentur.
+-- Es wird anhand der Namensräume überprüft, ob die aufrufende Rolle 
+-- berechtigt ist, für die angegebene KA Berechtigungen zurückzuziehen.
+-- OWNER muss beim Anlegen der Datenbank auf den DB-Owner umgesetzt werden:
+-- ALTER FUNCTION mpuls_revoke_role(varchar, varchar) OWNER TO ka_:FKZ:_adm;
+CREATE OR REPLACE FUNCTION mpuls_revoke_connect (
+        username varchar(64),
+        agency varchar(52)
+  ) RETURNS boolean LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+  AS $$
+  DECLARE 
+    db_name  varchar(64);
+    db_user  varchar(128);
+  BEGIN
+    -- IF position(quote_literal(agency) in session_user) != 4
+    IF position(agency in session_user) != 4
+    THEN
+      RAISE EXCEPTION 
+          'Permission denied to drop role % in agency % by %.',
+          quote_literal(username), quote_literal(agency), session_user;
+    ELSE
+      db_name := quote_ident('ka_' || agency || '_db');
+      db_user := quote_ident('ka_' || agency || '_' || username);
+      EXECUTE 'REVOKE CONNECT ON DATABASE ' || db_name
+          || ' FROM ' || db_user ;
+      RETURN true;
+    END IF;
+    RETURN false;
+  END;
+$$ ;
+REVOKE ALL ON FUNCTION mpuls_revoke_connect( varchar, varchar ) FROM public;
+GRANT EXECUTE ON FUNCTION mpuls_revoke_connect( varchar, varchar ) TO mpuls_role_adm;
+
+
+-- mpuls_drop_role( nutzer, agentur ) returns boolean 
+-- Löschen der Login-Rolle
+-- 'ka_<agentur>_<nutzer>'. Es wird anhand der Namensräume überprüft, ob die
+-- aufrufende Rolle berechtigt ist, für die angegebene KA Nutzer zu Löschen.
+CREATE OR REPLACE FUNCTION mpuls_drop_role (
+        username varchar(64),
+        agency varchar(52)
+  ) RETURNS boolean LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+  AS $$
+  DECLARE 
+    db_user       varchar(128);
+    status_revoke boolean;
+  BEGIN
+    -- IF position(quote_literal(agency) in session_user) != 4
+    IF position(agency in session_user) != 4
+    THEN
+      RAISE EXCEPTION 
+          'Permission denied to drop role % in agency % by %.',
+          quote_literal(username), quote_literal(agency), session_user;
+    ELSE
+      db_user := quote_ident('ka_' || agency || '_' || username);
+      SELECT mpuls_revoke_connect(username, agency) INTO status_revoke;
+      IF status_revoke
+      THEN
+        EXECUTE 'DROP ROLE ' || db_user ;
+        RETURN true;
+      END IF;
+    END IF;
+    RETURN false;
+  END;
+$$ ;
+REVOKE ALL ON FUNCTION mpuls_drop_role( varchar, varchar ) FROM public;
+GRANT EXECUTE ON FUNCTION mpuls_drop_role( varchar, varchar ) 
+    TO admin;
+
+-- mpuls_reset_password ( nutzer, agentur ) returns text 
+-- Setzen eines neuen Passworts für die Login-Rolle 'ka_<agentur>_<nutzer>'. 
+-- Es wird anhand der Namensräume überprüft, ob die aufrufende Rolle 
+-- berechtigt ist, für die angegebene KA Nutzerpassworte zurückzusetzen. 
+-- Rückgabewert ist das neue Passwort der Login-Rolle.
+CREATE OR REPLACE FUNCTION mpuls_reset_password (
+        name varchar(64),
+        agency varchar(52)
+  ) RETURNS text LANGUAGE 'plpgsql' VOLATILE EXTERNAL SECURITY DEFINER
+  AS $$
+  DECLARE 
+    db_name  varchar(64);
+    db_user  varchar(128);
+    pw       varchar(9);
+  BEGIN
+    -- IF position(quote_literal(agency) in session_user) != 4
+    IF position(agency in session_user) != 4
+    THEN
+      RAISE EXCEPTION 
+          'Permission denied to reset password for role % in agency % by %.',
+          quote_literal(name), quote_literal(agency), session_user;
+    ELSE
+      db_name := quote_ident('ka_' || agency || '_db');
+      db_user := quote_ident('ka_' || agency || '_' || name);
+      pw := mpuls_passgen(8);
+      EXECUTE 'ALTER USER ' || db_user || ' WITH PASSWORD ' 
+          || quote_literal(pw);
+      RETURN pw::text;
+    END IF;
+    RETURN ''::text;
+  END;
+$$ ;
+REVOKE ALL ON FUNCTION mpuls_reset_password( varchar, varchar ) FROM public;
+GRANT EXECUTE ON FUNCTION mpuls_reset_password( varchar, varchar ) 
+    TO admin;
+
+-- Make the database a template database.
+\connect mpuls_maintenance postgres
+UPDATE pg_database SET datistemplate = true WHERE datname = 'mpuls_template';
+UPDATE pg_database SET datallowconn = false WHERE datname = 'mpuls_template';
+
+--
+-- ENDE Initialisierung des WASKA-Clusters
+-- ------------------------------------------------------------------------

Added: base/trunk/mpulsweb/commands/db/scripts/mpuls-init-db.sql
===================================================================
--- base/trunk/mpulsweb/commands/db/scripts/mpuls-init-db.sql	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb/commands/db/scripts/mpuls-init-db.sql	2011-01-24 21:43:23 UTC (rev 4517)
@@ -0,0 +1 @@
+SELECT mpuls_init_database('${db_name}');

Modified: base/trunk/mpulsweb.egg-info/PKG-INFO
===================================================================
--- base/trunk/mpulsweb.egg-info/PKG-INFO	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb.egg-info/PKG-INFO	2011-01-24 21:43:23 UTC (rev 4517)
@@ -1,6 +1,6 @@
 Metadata-Version: 1.0
 Name: mpulsweb
-Version: 2.0.0-predev-r3049
+Version: 2.0.0-predev-r4515
 Summary: mpuls ist ein Web-Applikations-Rahmen zur Verwaltung                  von elektronischen Fallakten (Schwerpunkt Sozialinformatik)
 Home-page: http://wald.intevation.org/projects/mpuls/
 Author: Intevation GmbH

Modified: base/trunk/mpulsweb.egg-info/SOURCES.txt
===================================================================
--- base/trunk/mpulsweb.egg-info/SOURCES.txt	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb.egg-info/SOURCES.txt	2011-01-24 21:43:23 UTC (rev 4517)
@@ -5,6 +5,7 @@
 MANIFEST.in
 README.txt
 default_config.json
+default_dblist.json
 default_dbmapping.json
 default_tagging.xml
 development.ini
@@ -26,6 +27,9 @@
 mpulsweb.egg-info/paster_plugins.txt
 mpulsweb.egg-info/requires.txt
 mpulsweb.egg-info/top_level.txt
+mpulsweb/commands/__init__.py
+mpulsweb/commands/db/__init__.py
+mpulsweb/commands/db/common.py
 mpulsweb/config/__init__.py
 mpulsweb/config/environment.py
 mpulsweb/config/importer.py
@@ -44,6 +48,7 @@
 mpulsweb/controllers/document.py
 mpulsweb/controllers/error.py
 mpulsweb/controllers/evaluate.py
+mpulsweb/controllers/evaluation_overview.py
 mpulsweb/controllers/formularpage.py
 mpulsweb/controllers/help.py
 mpulsweb/controllers/info.py
@@ -73,12 +78,15 @@
 mpulsweb/lib/renderer.py
 mpulsweb/lib/search.py
 mpulsweb/lib/security.py
+mpulsweb/lib/session.py
 mpulsweb/lib/timelog.py
 mpulsweb/lib/translation.py
 mpulsweb/lib/validators.py
 mpulsweb/lib/helper/__init__.py
+mpulsweb/lib/helper/case.py
 mpulsweb/lib/helper/filters.py
 mpulsweb/model/__init__.py
+mpulsweb/model/agency.py
 mpulsweb/model/agencysettings.py
 mpulsweb/model/annotations.py
 mpulsweb/model/appointment.py
@@ -89,8 +97,10 @@
 mpulsweb/model/phase.py
 mpulsweb/model/statement.py
 mpulsweb/model/user.py
+mpulsweb/public/formed/laender.xml
+mpulsweb/public/formed/sprachen.xml
 mpulsweb/public/formed/staatsangehoerigkeit.xml
-mpulsweb/public/images/kompetenz3.ico
+mpulsweb/public/images/mpuls.ico
 mpulsweb/public/images/icons/admin_grey_tag.gif
 mpulsweb/public/images/icons/anonymise_active_22.png
 mpulsweb/public/images/icons/anonymise_inactive_22.png
@@ -127,6 +137,16 @@
 mpulsweb/public/images/icons/validity-1-22.png
 mpulsweb/public/images/icons/validity-2-22.png
 mpulsweb/public/images/icons/validity-background.png
+mpulsweb/public/images/icons/case_status/b_finished.png
+mpulsweb/public/images/icons/case_status/b_running.png
+mpulsweb/public/images/icons/case_status/c_finished.png
+mpulsweb/public/images/icons/case_status/c_running.png
+mpulsweb/public/images/icons/case_status/e_finished.png
+mpulsweb/public/images/icons/case_status/e_running.png
+mpulsweb/public/images/icons/case_status/n_finished.png
+mpulsweb/public/images/icons/case_status/n_running.png
+mpulsweb/public/images/icons/case_status/u_finished.png
+mpulsweb/public/images/icons/case_status/u_running.png
 mpulsweb/public/images/icons/formular/evaluation.png
 mpulsweb/public/images/icons/formular/help.png
 mpulsweb/public/images/icons/formular/info.png
@@ -139,6 +159,7 @@
 mpulsweb/public/images/icons/info/info.png
 mpulsweb/public/images/icons/info/info_22.png
 mpulsweb/public/images/icons/info/info_32.png
+mpulsweb/public/images/icons/info/ok_22.png
 mpulsweb/public/images/icons/info/question.png
 mpulsweb/public/images/icons/info/question_22.png
 mpulsweb/public/images/icons/info/question_32.png
@@ -193,6 +214,16 @@
 mpulsweb/public/images/svg/validity-background.svg
 mpulsweb/public/images/svg/validity.svg
 mpulsweb/public/images/svg/Palette/Tango-Palette.svg
+mpulsweb/public/images/svg/case_status/b_running.svg
+mpulsweb/public/images/svg/case_status/b_stopped.svg
+mpulsweb/public/images/svg/case_status/c_running.svg
+mpulsweb/public/images/svg/case_status/c_stopped.svg
+mpulsweb/public/images/svg/case_status/e_running.svg
+mpulsweb/public/images/svg/case_status/e_stopped.svg
+mpulsweb/public/images/svg/case_status/n_running.svg
+mpulsweb/public/images/svg/case_status/n_stopped.svg
+mpulsweb/public/images/svg/case_status/u_running.svg
+mpulsweb/public/images/svg/case_status/u_stopped.svg
 mpulsweb/public/images/svg/sources/gnome-icon-theme/Makefile.am
 mpulsweb/public/images/svg/sources/gnome-icon-theme/Makefile.in
 mpulsweb/public/images/svg/sources/gnome-icon-theme/actions/Makefile.am
@@ -1144,6 +1175,7 @@
 mpulsweb/public/xml/eval_default.xml
 mpulsweb/templates/base.mako
 mpulsweb/templates/main.mako
+mpulsweb/templates/switch_to_other_datasets.mako
 mpulsweb/templates/administration/delete_user_helper.mako
 mpulsweb/templates/administration/edit_user.mako
 mpulsweb/templates/administration/edit_usergroup.mako
@@ -1195,6 +1227,7 @@
 mpulsweb/templates/casebundle/dialogs/success_delete_admin.mako
 mpulsweb/templates/casebundle/dialogs/success_editor.mako
 mpulsweb/templates/casebundle/dialogs/success_markdelete.mako
+mpulsweb/templates/casebundle/dialogs/success_markevaluate.mako
 mpulsweb/templates/casebundle/dialogs/success_standin.mako
 mpulsweb/templates/casemanagement/appointmentlist.mako
 mpulsweb/templates/casemanagement/appointments.mako
@@ -1209,7 +1242,9 @@
 mpulsweb/templates/casemanagement/overview.mako
 mpulsweb/templates/casemanagement/reminderlist.mako
 mpulsweb/templates/casemanagement/search.mako
+mpulsweb/templates/casemanagement/search_extra.mako
 mpulsweb/templates/casemanagement/showAppointment.mako
+mpulsweb/templates/casemanagement/upload.mako
 mpulsweb/templates/casemanagement/dialogs/confirm.mako
 mpulsweb/templates/casemanagement/dialogs/confirm_anonymize.mako
 mpulsweb/templates/casemanagement/dialogs/confirm_copy.mako
@@ -1220,6 +1255,7 @@
 mpulsweb/templates/casemanagement/dialogs/confirm_markanonymize.mako
 mpulsweb/templates/casemanagement/dialogs/confirm_restore.mako
 mpulsweb/templates/casemanagement/dialogs/failed_markanonymize.mako
+mpulsweb/templates/casemanagement/dialogs/failed_xml_import.mako
 mpulsweb/templates/casemanagement/dialogs/success_anonymize.mako
 mpulsweb/templates/casemanagement/dialogs/success_copy.mako
 mpulsweb/templates/casemanagement/dialogs/success_create_appointment.mako
@@ -1232,6 +1268,7 @@
 mpulsweb/templates/casemanagement/dialogs/success_keepactive.mako
 mpulsweb/templates/casemanagement/dialogs/success_markanonymize.mako
 mpulsweb/templates/casemanagement/dialogs/success_restore.mako
+mpulsweb/templates/casemanagement/dialogs/success_xml_import.mako
 mpulsweb/templates/dialogs/confirm.mako
 mpulsweb/templates/dialogs/failed.mako
 mpulsweb/templates/dialogs/notification.mako
@@ -1248,9 +1285,12 @@
 mpulsweb/templates/documents/dialogs/success_attachment.mako
 mpulsweb/templates/documents/dialogs/success_documents.mako
 mpulsweb/templates/error/error.mako
+mpulsweb/templates/evaluation/agencylist.mako
 mpulsweb/templates/evaluation/evaluate.mako
-mpulsweb/templates/evaluation/evaluate_adele.mako
+mpulsweb/templates/evaluation/evaluate_extra.mako
+mpulsweb/templates/evaluation/overview.mako
 mpulsweb/templates/evaluation/result.mako
+mpulsweb/templates/evaluation/search.mako
 mpulsweb/templates/formularpage/content.mako
 mpulsweb/templates/formularpage/formular.mako
 mpulsweb/templates/help/help.mako
@@ -1262,6 +1302,7 @@
 mpulsweb/templates/logbook/edit.mako
 mpulsweb/templates/logbook/edit_body.mako
 mpulsweb/templates/logbook/evaluation.mako
+mpulsweb/templates/logbook/evaluation_typ.mako
 mpulsweb/templates/logbook/new.mako
 mpulsweb/templates/logbook/overview.mako
 mpulsweb/templates/logbook/overview_print.mako
@@ -1277,6 +1318,8 @@
 mpulsweb/templates/news/newslist.mako
 mpulsweb/templates/news/dialogs/confirm_mark_news_as_read.mako
 mpulsweb/templates/phase/phase.mako
+mpulsweb/templates/phase/dialogs/success_fullautomatic_set_phase.mako
+mpulsweb/templates/phase/dialogs/success_halfautomatic_set_phase.mako
 mpulsweb/templates/phase/dialogs/success_set_phase.mako
 mpulsweb/templates/privacy/default_statement.mako
 mpulsweb/templates/privacy/edit_statement.mako
@@ -1289,6 +1332,7 @@
 mpulsweb/templates/privacy/dialogs/missing_statement.mako
 mpulsweb/templates/privacy/dialogs/missing_statement_body.mako
 mpulsweb/templates/repeatgroup/dialogs/confirm_delete_rg_entry.mako
+mpulsweb/templates/search/search.mako
 mpulsweb/templates/settings/edit.mako
 mpulsweb/templates/settings/show.mako
 mpulsweb/templates/settings/dialogs/success_edit.mako

Modified: base/trunk/mpulsweb.egg-info/entry_points.txt
===================================================================
--- base/trunk/mpulsweb.egg-info/entry_points.txt	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb.egg-info/entry_points.txt	2011-01-24 21:43:23 UTC (rev 4517)
@@ -5,3 +5,9 @@
 
     [paste.app_install]
     main = pylons.util:PylonsInstaller
+    [paste.paster_command]
+    cluster-init = mpulsweb.commands.db.common:ClusterInit
+    db-create = mpulsweb.commands.db.common:DBCreate
+    db-drop = mpulsweb.commands.db.common:DBDrop
+    db-update = mpulsweb.commands.db.common:DBUpdate
+    
\ No newline at end of file

Modified: base/trunk/mpulsweb.egg-info/requires.txt
===================================================================
--- base/trunk/mpulsweb.egg-info/requires.txt	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/mpulsweb.egg-info/requires.txt	2011-01-24 21:43:23 UTC (rev 4517)
@@ -1,2 +1,3 @@
-Pylons>=0.9.7
-pyExcelerator
\ No newline at end of file
+Pylons==0.9.7
+pyExcelerator
+babel
\ No newline at end of file

Modified: base/trunk/setup.py
===================================================================
--- base/trunk/setup.py	2011-01-21 13:36:17 UTC (rev 4516)
+++ base/trunk/setup.py	2011-01-24 21:43:23 UTC (rev 4517)
@@ -52,5 +52,10 @@
 
     [paste.app_install]
     main = pylons.util:PylonsInstaller
+    [paste.paster_command]
+    cluster-init = mpulsweb.commands.db.common:ClusterInit
+    db-create = mpulsweb.commands.db.common:DBCreate
+    db-drop = mpulsweb.commands.db.common:DBDrop
+    db-update = mpulsweb.commands.db.common:DBUpdate
     """,
 )



More information about the Mpuls-commits mailing list