1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27 28 29 30 31 32 33 34 35 36 37 38 39 40 41 42 43 44 45 46 47 48 49 50 51 52 53 54 55 56 57 58 59 60 61 62 63 64 65 66 67 68 69 70 71 72 73 74 75 76 77 78 79 80 81 82 83 84 85 86 87 88 89 90 91 92 93 94 95 96 97 98 99 100 101 102 103 104 105 106 107 108 109 110 111 112 113 114 115 116 117 118 119 120 121 122 123 124 125 126 127 128 129 130 131 132 133 134 135 136 137 138 139 140 141 142 143 144 145 146 147 148 149 150 151 152 153 154 155 156 157 158 159 160 161 162 163 164 165 166 167 168 169 170 171 172 173 174 175 176 177 178 179 180 181 182 183 184 185 186 187 188 189 190 191 192 193 194 195 196 197 198 199 200 201 202 203 204 205 206 207 208 209 210 211 212 213 214 215 216 217 218 219 220 221 222 223 224 225 226 227 228 229 230 231 232 233 234 235 236 237 238 239 240 241 242 243 244 245 246 247 248 249 250 251 252 253 254 255 256 257 258 259 260 261 262 263 264 265 266 267 268 269 270 271 272 273 274 275 276 277 278 279 280 281 282 283 284 285 286 287 288 289 290 291 292 293 294 295 296 297 298 299 300 301 302 303 304 305 306 307 308 309 310 311 312 313 314 315 316 317 318 319 320 321 322 323 324 325 326 327 328 329 330 331 332 333 334 335 336 337 338 339 340 341 342 343 344 345 346 347 348 349 350 351 352 353 354 355 356 357 358 359 360 361 362 363 364 365 366 367 368 369 370 371 372 373 374 375
|
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
--
--
-- PostGIS - Spatial Types for PostgreSQL
-- http://postgis.net
-- Copyright 2001-2003 Refractions Research Inc.
--
-- This is free software; you can redistribute and/or modify it under
-- the terms of the GNU General Public Licence. See the COPYING file.
--
-- - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - - -
#define CREATEFUNCTION CREATE OR REPLACE FUNCTION
#if USE_VERSION > 72
# define _IMMUTABLE_STRICT IMMUTABLE STRICT
# define _IMMUTABLE IMMUTABLE
# define _STABLE_STRICT STABLE STRICT
# define _STABLE STABLE
# define _VOLATILE_STRICT VOLATILE STRICT
# define _VOLATILE VOLATILE
# define _STRICT STRICT
#else
# define _IMMUTABLE_STRICT with(iscachable,isstrict)
# define _IMMUTABLE with(iscachable)
# define _STABLE_STRICT with(isstrict)
# define _STABLE
# define _VOLATILE_STRICT with(isstrict)
# define _VOLATILE
# define _STRICT with(isstrict)
#endif
#if USE_VERSION >= 73
# define HAS_SCHEMAS 1
#endif
-----------------------------------------------------------------------
-- LONG TERM LOCKING
-----------------------------------------------------------------------
-- UnlockRows(authid)
-- removes all locks held by the given auth
-- returns the number of locks released
CREATEFUNCTION UnlockRows(text)
RETURNS int
AS '
DECLARE
ret int;
BEGIN
IF NOT LongTransactionsEnabled() THEN
RAISE EXCEPTION ''Long transaction support disabled, use EnableLongTransaction() to enable.'';
END IF;
EXECUTE ''DELETE FROM authorization_table where authid = '' ||
quote_literal($1);
GET DIAGNOSTICS ret = ROW_COUNT;
RETURN ret;
END;
'
LANGUAGE 'plpgsql' _VOLATILE_STRICT;
-- LockRow([schema], table, rowid, auth, [expires])
-- Returns 1 if successfully obtained the lock, 0 otherwise
CREATEFUNCTION LockRow(text, text, text, text, timestamp)
RETURNS int
AS '
DECLARE
myschema alias for $1;
mytable alias for $2;
myrid alias for $3;
authid alias for $4;
expires alias for $5;
ret int;
mytoid oid;
myrec RECORD;
BEGIN
IF NOT LongTransactionsEnabled() THEN
RAISE EXCEPTION ''Long transaction support disabled, use EnableLongTransaction() to enable.'';
END IF;
EXECUTE ''DELETE FROM authorization_table WHERE expires < now()'';
#ifdef HAS_SCHEMAS
SELECT c.oid INTO mytoid FROM pg_class c, pg_namespace n
WHERE c.relname = mytable
AND c.relnamespace = n.oid
AND n.nspname = myschema;
#else
SELECT c.oid INTO mytoid FROM pg_class c
WHERE c.relname = mytable;
#endif
-- RAISE NOTICE ''toid: %'', mytoid;
FOR myrec IN SELECT * FROM authorization_table WHERE
toid = mytoid AND rid = myrid
LOOP
IF myrec.authid != authid THEN
RETURN 0;
ELSE
RETURN 1;
END IF;
END LOOP;
EXECUTE ''INSERT INTO authorization_table VALUES (''||
quote_literal(mytoid)||'',''||quote_literal(myrid)||
'',''||quote_literal(expires)||
'',''||quote_literal(authid) ||'')'';
GET DIAGNOSTICS ret = ROW_COUNT;
RETURN ret;
END;'
LANGUAGE 'plpgsql' _VOLATILE_STRICT;
-- LockRow(schema, table, rid, authid);
CREATEFUNCTION LockRow(text, text, text, text)
RETURNS int
AS
'SELECT LockRow($1, $2, $3, $4, now()::timestamp+''1:00'');'
LANGUAGE 'sql' _VOLATILE_STRICT;
-- LockRow(table, rid, authid);
CREATEFUNCTION LockRow(text, text, text)
RETURNS int
AS
#ifdef HAS_SCHEMAS
'SELECT LockRow(current_schema(), $1, $2, $3, now()::timestamp+''1:00'');'
#else
'SELECT LockRow('''', $1, $2, $3, now()::timestamp+''1:00'');'
#endif
LANGUAGE 'sql' _VOLATILE_STRICT;
-- LockRow(schema, table, rid, expires);
CREATEFUNCTION LockRow(text, text, text, timestamp)
RETURNS int
AS
#ifdef HAS_SCHEMAS
'SELECT LockRow(current_schema(), $1, $2, $3, $4);'
#else
'SELECT LockRow('''', $1, $2, $3, $4);'
#endif
LANGUAGE 'sql' _VOLATILE_STRICT;
CREATEFUNCTION AddAuth(text)
RETURNS BOOLEAN
AS '
DECLARE
lockid alias for $1;
okay boolean;
myrec record;
BEGIN
-- check to see if table exists
-- if not, CREATE TEMP TABLE mylock (transid xid, lockcode text)
okay := ''f'';
FOR myrec IN SELECT * FROM pg_class WHERE relname = ''temp_lock_have_table'' LOOP
okay := ''t'';
END LOOP;
IF (okay <> ''t'') THEN
CREATE TEMP TABLE temp_lock_have_table (transid xid, lockcode text);
-- this will only work from pgsql7.4 up
-- ON COMMIT DELETE ROWS;
END IF;
-- INSERT INTO mylock VALUES ( $1)
-- EXECUTE ''INSERT INTO temp_lock_have_table VALUES ( ''||
-- quote_literal(getTransactionID()) || '','' ||
-- quote_literal(lockid) ||'')'';
INSERT INTO temp_lock_have_table VALUES (getTransactionID(), lockid);
RETURN true::boolean;
END;
'
LANGUAGE PLPGSQL;
-- CheckAuth( <schema>, <table>, <ridcolumn> )
--
-- Returns 0
--
CREATEFUNCTION CheckAuth(text, text, text)
RETURNS INT
AS '
DECLARE
#ifdef HAS_SCHEMAS
schema text;
#endif
BEGIN
IF NOT LongTransactionsEnabled() THEN
RAISE EXCEPTION ''Long transaction support disabled, use EnableLongTransaction() to enable.'';
END IF;
#ifdef HAS_SCHEMAS
if ( $1 != '''' ) THEN
schema = $1;
ELSE
SELECT current_schema() into schema;
END IF;
#endif
-- TODO: check for an already existing trigger ?
EXECUTE ''CREATE TRIGGER check_auth BEFORE UPDATE OR DELETE ON ''
#ifdef HAS_SCHEMAS
|| quote_ident(schema) || ''.'' || quote_ident($2)
#else
|| quote_ident($2)
#endif
||'' FOR EACH ROW EXECUTE PROCEDURE CheckAuthTrigger(''
|| quote_literal($3) || '')'';
RETURN 0;
END;
'
LANGUAGE 'plpgsql';
-- CheckAuth(<table>, <ridcolumn>)
CREATEFUNCTION CheckAuth(text, text)
RETURNS INT
AS
'SELECT CheckAuth('''', $1, $2)'
LANGUAGE 'SQL';
CREATEFUNCTION CheckAuthTrigger()
RETURNS trigger AS
'@MODULE_FILENAME@', 'check_authorization'
LANGUAGE C;
CREATEFUNCTION GetTransactionID()
RETURNS xid AS
'@MODULE_FILENAME@', 'getTransactionID'
LANGUAGE C;
--
-- Enable Long transactions support
--
-- Creates the authorization_table if not already existing
--
CREATEFUNCTION EnableLongTransactions()
RETURNS TEXT
AS '
DECLARE
query text;
exists bool;
rec RECORD;
BEGIN
exists = ''f'';
FOR rec IN SELECT * FROM pg_class WHERE relname = ''authorization_table''
LOOP
exists = ''t'';
END LOOP;
IF NOT exists
THEN
query = ''CREATE TABLE authorization_table (
toid oid, -- table oid
rid text, -- row id
expires timestamp,
authid text
)'';
EXECUTE query;
END IF;
exists = ''f'';
FOR rec IN SELECT * FROM pg_class WHERE relname = ''authorized_tables''
LOOP
exists = ''t'';
END LOOP;
IF NOT exists THEN
query = ''CREATE VIEW authorized_tables AS '' ||
''SELECT '' ||
#ifdef HAS_SCHEMAS
''n.nspname as schema, '' ||
#endif
''c.relname as table, trim('' ||
quote_literal(''\\\\000'') ||
'' from t.tgargs) as id_column '' ||
''FROM pg_trigger t, pg_class c, pg_proc p '' ||
#ifdef HAS_SCHEMAS
'', pg_namespace n '' ||
#endif
''WHERE p.proname = '' || quote_literal(''checkauthtrigger'') ||
#ifdef HAS_SCHEMAS
'' AND c.relnamespace = n.oid'' ||
#endif
'' AND t.tgfoid = p.oid and t.tgrelid = c.oid'';
EXECUTE query;
END IF;
RETURN ''Long transactions support enabled'';
END;
'
LANGUAGE 'plpgsql';
--
-- Check if Long transactions support is enabled
--
CREATEFUNCTION LongTransactionsEnabled()
RETURNS bool
AS '
DECLARE
rec RECORD;
BEGIN
FOR rec IN SELECT oid FROM pg_class WHERE relname = ''authorized_tables''
LOOP
return ''t'';
END LOOP;
return ''f'';
END;
'
LANGUAGE 'plpgsql';
--
-- Disable Long transactions support
--
-- (1) Drop any long_xact trigger
-- (2) Drop the authorization_table
-- (3) KEEP the authorized_tables view
--
CREATEFUNCTION DisableLongTransactions()
RETURNS TEXT
AS '
DECLARE
query text;
exists bool;
rec RECORD;
BEGIN
--
-- Drop all triggers applied by CheckAuth()
--
FOR rec IN
SELECT c.relname, t.tgname, t.tgargs FROM pg_trigger t, pg_class c, pg_proc p
WHERE p.proname = ''checkauthtrigger'' and t.tgfoid = p.oid and t.tgrelid = c.oid
LOOP
EXECUTE ''DROP TRIGGER '' || quote_ident(rec.tgname) ||
'' ON '' || quote_ident(rec.relname);
END LOOP;
--
-- Drop the authorization_table table
--
FOR rec IN SELECT * FROM pg_class WHERE relname = ''authorization_table'' LOOP
DROP TABLE authorization_table;
END LOOP;
--
-- Drop the authorized_tables view
--
FOR rec IN SELECT * FROM pg_class WHERE relname = ''authorized_tables'' LOOP
DROP VIEW authorized_tables;
END LOOP;
RETURN ''Long transactions support disabled'';
END;
'
LANGUAGE 'plpgsql';
---------------------------------------------------------------
-- END
---------------------------------------------------------------
|