1
|
ALTER TABLE tablefieldinfo ADD COLUMN IF NOT EXISTS foreign_schema varchar(100);
|
2
|
|
3
|
ALTER TABLE tablefieldinfo ADD COLUMN IF NOT EXISTS foreign_table VARCHAR(100); -- Die Spalte referenziert auf diese Tabelle ...
|
4
|
ALTER TABLE tablefieldinfo ADD COLUMN IF NOT EXISTS foreign_column VARCHAR(50); -- ... und Spalte
|
5
|
|
6
|
ALTER TABLE tablefieldinfo ADD COLUMN IF NOT EXISTS isWritable BOOLEAN DEFAULT false;
|
7
|
|
8
|
ALTER TABLE recnogroup ADD COLUMN IF NOT EXISTS reg_gruppe_textno INTEGER;
|
9
|
ALTER TABLE recnogroup ADD COLUMN IF NOT EXISTS reg_bez_textno INTEGER;
|
10
|
|
11
|
ALTER TABLE SettingsDyn ADD COLUMN IF NOT EXISTS sd_deleted BOOLEAN DEFAULT False;
|
12
|
|
13
|
ALTER TABLE adk ADD COLUMN IF NOT EXISTS ad_dokversand INTEGER;
|
14
|
ALTER TABLE anfart ADD COLUMN IF NOT EXISTS aArt_aknr_idx VARCHAR(30);
|
15
|
|
16
|
--- Liefert Dokumentversandbezeuchnung von ad_dokversand
|
17
|
CREATE FUNCTION TAdk.DokVersandTyp(IN _ad_dokversand INTEGER, OUT ad_dokversand INTEGER, OUT ad_DokVersandBez VARCHAR) RETURNS RECORD AS $$
|
18
|
BEGIN
|
19
|
SELECT null, null INTO ad_dokversand, ad_DokVersandBez;
|
20
|
END $$ LANGUAGE plpgsql STABLE;
|
21
|
|
22
|
ALTER TABLE belegdokument ADD COLUMN beld_gewicht NUMERIC(12,4);
|
23
|
ALTER TABLE belegpos ADD COLUMN belp_gewicht NUMERIC(12,4);
|
24
|
|
25
|
|
26
|
ALTER TABLE belegpos ADD COLUMN IF NOT EXISTS belp_bstat VARCHAR(2) REFERENCES auftgbs ON UPDATE CASCADE ON DELETE SET NULL; -- Statusflags1
|
27
|
ALTER TABLE belegpos ADD COLUMN IF NOT EXISTS belp_bstat1 VARCHAR(2) REFERENCES auftgbs ON UPDATE CASCADE ON DELETE SET NULL; -- Statusflags2
|
28
|
ALTER TABLE belegpos ADD COLUMN IF NOT EXISTS belp_bstat2 VARCHAR(2) REFERENCES auftgbs ON UPDATE CASCADE ON DELETE SET NULL; -- Statusflags3
|
29
|
|
30
|
|
31
|
/*
|
32
|
ALTER TABLE belegposabzu ADD COLUMN IF NOT EXISTS belpaz_type VARCHAR(1) DEFAULT 'E';
|
33
|
ALTER TABLE belegposabzu ADD COLUMN IF NOT EXISTS belpaz_pos INTEGER;
|
34
|
ALTER TABLE belegposabzu ADD COLUMN IF NOT EXISTS belpaz_zutxt_int TEXT;
|
35
|
|
36
|
ALTER TABLE belegabzu ADD COLUMN IF NOT EXISTS belaz_type VARCHAR(1) DEFAULT 'E';
|
37
|
ALTER TABLE belegabzu ADD COLUMN IF NOT EXISTS belaz_pos INTEGER;
|
38
|
ALTER TABLE belegabzu ADD COLUMN IF NOT EXISTS belaz_zutxt_int TEXT;
|
39
|
|
40
|
ALTER TABLE belabzu ADD COLUMN IF NOT EXISTS beaz_type VARCHAR(1) DEFAULT 'E';
|
41
|
ALTER TABLE belabzu ADD COLUMN IF NOT EXISTS beaz_pos INTEGER;
|
42
|
ALTER TABLE belabzu ADD COLUMN IF NOT EXISTS beaz_zutxt_int TEXT;
|
43
|
|
44
|
ALTER TABLE ldsabzu ADD COLUMN IF NOT EXISTS ldaz_type VARCHAR(1) DEFAULT 'E';
|
45
|
ALTER TABLE ldsabzu ADD COLUMN IF NOT EXISTS ldaz_pos INTEGER;
|
46
|
ALTER TABLE ldsabzu ADD COLUMN IF NOT EXISTS ldaz_zutxt_int TEXT;
|
47
|
ALTER TABLE ldsabzu ADD COLUMN IF NOT EXISTS ldaz_visible BOOLEAN NOT NULL DEFAULT TRUE;
|
48
|
|
49
|
ALTER TABLE belzeil_grund ADD COLUMN IF NOT EXISTS bz_vkp_mce INTEGER REFERENCES artmgc;
|
50
|
ALTER TABLE ldsdok ADD COLUMN IF NOT EXISTS ld_ekp_mce INTEGER REFERENCES artmgc;
|
51
|
ALTER TABLE ldsdok ADD COLUMN IF NOT EXISTS ld_ekp_mce INTEGER REFERENCES artmgc;
|
52
|
ALTER TABLE auftg ADD COLUMN IF NOT EXISTS ag_vkp_mce INTEGER REFERENCES artmgc;
|
53
|
|
54
|
|
55
|
ALTER TABLE artpruefung ADD COLUMN IF NOT EXISTS apr_doktxt Text;
|
56
|
ALTER TABLE artpruefung ADD COLUMN IF NOT EXISTS apr_aufdok BOOL NOT NULL DEFAULT FALSE;
|
57
|
ALTER TABLE artpruefung ADD COLUMN IF NOT EXISTS apr_abz_id INTEGER REFERENCES abzu ON UPDATE CASCADE;
|
58
|
|
59
|
ALTER TABLE ab2ba ADD COLUMN IF NOT EXISTS a2ba_noz_id INTEGER REFERENCES normzert;
|
60
|
--*/
|
61
|
|
62
|
CREATE FUNCTION TSystem.Settings__GetBool(vari varchar, defvalue boolean DEFAULT false) RETURNS boolean AS $$
|
63
|
DECLARE r boolean;
|
64
|
s varchar;
|
65
|
BEGIN
|
66
|
IF vari = 'AdminLoginAllowed' THEN RETURN true; END IF;
|
67
|
|
68
|
SELECT s_inha INTO s FROM public.settings WHERE s_vari = vari;
|
69
|
--
|
70
|
IF NOT FOUND THEN
|
71
|
RETURN defvalue;
|
72
|
END IF;
|
73
|
--
|
74
|
IF UPPER(s) IN ('-1','1', 'T', 'TRUE') THEN
|
75
|
RETURN true;
|
76
|
ELSE
|
77
|
RETURN false;
|
78
|
END IF;
|
79
|
END$$LANGUAGE plpgsql PARALLEL SAFE;
|
80
|
|
81
|
CREATE OR REPLACE FUNCTION TSystem.Settings__GetText(vari varchar)
|
82
|
RETURNS text
|
83
|
AS $$
|
84
|
SELECT coalesce(
|
85
|
(SELECT s_inha FROM public.settings WHERE s_vari = vari)
|
86
|
, ''
|
87
|
);
|
88
|
$$ LANGUAGE sql PARALLEL SAFE;
|
89
|
|
90
|
-- Hinweis: Begrenzung von den 8191 Zeichen, im PgDAC, bei vom VARCHAR ohne Längenangabe.
|
91
|
CREATE FUNCTION TSystem.Settings__Get(vari varchar)
|
92
|
RETURNS varchar
|
93
|
AS $$
|
94
|
SELECT TSystem.Settings__GetText(vari);
|
95
|
$$LANGUAGE sql PARALLEL SAFE;
|
96
|
|
97
|
|
98
|
-- Setting als BOOL setzen
|
99
|
CREATE FUNCTION TSystem.Settings__Set(vari VARCHAR, inha BOOL) RETURNS VOID AS $$
|
100
|
BEGIN
|
101
|
IF inha IS NULL THEN
|
102
|
PERFORM TSystem.Settings__Delete(vari);
|
103
|
RETURN;
|
104
|
END IF;
|
105
|
IF inha THEN
|
106
|
PERFORM TSystem.Settings__Set(vari, '-1'); -- true
|
107
|
ELSE
|
108
|
PERFORM TSystem.Settings__Set(vari, '0'); -- false
|
109
|
END IF;
|
110
|
|
111
|
RETURN;
|
112
|
END $$ LANGUAGE plpgsql;
|
113
|
|
114
|
--
|
115
|
|
116
|
-- Setting als VARCHAR setzen
|
117
|
CREATE FUNCTION TSystem.Settings__Set(vari VARCHAR, inha VARCHAR) RETURNS VOID AS $$
|
118
|
DECLARE num NUMERIC;
|
119
|
BEGIN
|
120
|
IF inha IS NULL THEN
|
121
|
PERFORM TSystem.Settings__Delete(vari);
|
122
|
RETURN;
|
123
|
END IF;
|
124
|
IF EXISTS(SELECT true FROM public.settings WHERE s_inha = inha AND s_vari = vari) THEN
|
125
|
RETURN;
|
126
|
END IF;
|
127
|
BEGIN
|
128
|
num:= inha::NUMERIC(20,8); -- Cast auf max. Numeric versuchen. Länge entspr. Standard für interne Werte.
|
129
|
EXCEPTION
|
130
|
WHEN OTHERS THEN num:= NULL;
|
131
|
END;
|
132
|
UPDATE settings SET s_inha= inha, s_num_inha= num WHERE s_vari = vari;
|
133
|
IF NOT FOUND THEN
|
134
|
INSERT INTO settings (s_vari, s_inha, s_num_inha) VALUES (vari, inha, num);
|
135
|
END IF;
|
136
|
|
137
|
RETURN;
|
138
|
END $$ LANGUAGE plpgsql;
|
139
|
|
140
|
--
|
141
|
|
142
|
-- Setting als INTEGER setzen
|
143
|
CREATE FUNCTION TSystem.Settings__Set(vari VARCHAR, inha INTEGER) RETURNS VOID AS $$
|
144
|
DECLARE num NUMERIC;
|
145
|
BEGIN
|
146
|
IF inha IS NULL THEN
|
147
|
PERFORM TSystem.Settings__Delete(vari);
|
148
|
RETURN;
|
149
|
END IF;
|
150
|
IF EXISTS(SELECT true FROM public.settings WHERE s_inha = inha::VARCHAR AND s_vari = vari) THEN
|
151
|
RETURN;
|
152
|
END IF;
|
153
|
BEGIN
|
154
|
num:= inha::NUMERIC(20,8); -- Cast auf max. Numeric versuchen. Länge entspr. Standard für interne Werte.
|
155
|
EXCEPTION
|
156
|
WHEN OTHERS THEN num:= NULL;
|
157
|
END;
|
158
|
UPDATE settings SET s_inha= inha::VARCHAR, s_num_inha= num WHERE s_vari = vari;
|
159
|
IF NOT FOUND THEN
|
160
|
INSERT INTO settings (s_vari, s_inha, s_num_inha) VALUES (vari, inha::VARCHAR, num);
|
161
|
END IF;
|
162
|
|
163
|
RETURN;
|
164
|
END $$ LANGUAGE plpgsql;
|
165
|
|
166
|
|
167
|
-- Value aus einem INI-TEXT auslesen -> [Section] Name=Value
|
168
|
CREATE FUNCTION TSystem.INI_GetValue(ini TEXT, section VARCHAR, name VARCHAR, defvalue VARCHAR DEFAULT NULL) RETURNS VARCHAR AS $$
|
169
|
DECLARE
|
170
|
sectionsinhalt TEXT;
|
171
|
val VARCHAR;
|
172
|
BEGIN
|
173
|
--Inhalt der eingegebenen 'section' ablesen oder 'defvalue' nehmen, wenn nicht gefunden
|
174
|
SELECT trim(substring(ini FROM E'\\[' || section || E'\\]([^\\[]*)'), E'\r\n\t ') INTO sectionsinhalt;
|
175
|
IF sectionsinhalt IS NULL THEN
|
176
|
RETURN defvalue;
|
177
|
END IF;
|
178
|
|
179
|
--Value mit dem 'name' aus der 'section' ablesen oder 'defvalue' nehmen, wenn nicht gefunden
|
180
|
SELECT COALESCE(trim(substring(sectionsinhalt FROM E'[$\r\n]*' || name || E'[ \t]*=[ \t]*([^\r\n$]*)'), E'\r\n\t '), defvalue) INTO val;
|
181
|
|
182
|
RETURN val;
|
183
|
END $$ LANGUAGE plpgsql IMMUTABLE;
|
184
|
|
185
|
CREATE FUNCTION tsystem.dokutypes__find__by__parentnode_id( _parentnode_id varchar )
|
186
|
RETURNS varchar
|
187
|
AS $$
|
188
|
SELECT null
|
189
|
$$ LANGUAGE sql;
|
190
|
|
191
|
CREATE FUNCTION tsystem.database__triggers_inaktiv__get(
|
192
|
IN _all_schemas boolean = false
|
193
|
)
|
194
|
RETURNS TABLE (
|
195
|
tgname varchar,
|
196
|
src_schemaname varchar,
|
197
|
src_tablename varchar,
|
198
|
trg_schemaname varchar,
|
199
|
trg_tablename varchar
|
200
|
)
|
201
|
AS $$
|
202
|
-- hinweis: cast as varchar nur in pg kleiner 13?!
|
203
|
SELECT tgname::varchar,
|
204
|
src_schema.nspname::varchar AS src_schemaname,
|
205
|
src_table.relname::varchar AS src_tablename,
|
206
|
trg_schema.nspname::varchar AS trg_schemaname,
|
207
|
trg_table.relname::varchar AS trg_tablename
|
208
|
FROM pg_trigger
|
209
|
LEFT JOIN pg_class AS src_table ON src_table.oid = pg_trigger.tgrelid
|
210
|
LEFT JOIN pg_class AS trg_table ON trg_table.oid = pg_trigger.tgconstrrelid
|
211
|
LEFT JOIN pg_namespace AS src_schema ON src_schema.oid = src_table.relnamespace
|
212
|
LEFT JOIN pg_namespace AS trg_schema ON trg_schema.oid = trg_table.relnamespace
|
213
|
WHERE tgenabled = 'D'
|
214
|
AND (
|
215
|
-- Prüfung auf deaktivierte Trigger für alle Schemata
|
216
|
_all_schemas
|
217
|
-- Prüfung auf deaktivierte Trigger gilt nicht für folg. Schemata
|
218
|
-- ignore: trigger on drop, fkey: public -> drop, drop -> public, drop -> drop
|
219
|
-- relevant: trigger on public, fkey: public -> public
|
220
|
OR (
|
221
|
-- Quelle des deaktivierten Triggers bzw. Contraint-Triggers (fKey) ist nicht in folg. Schemata
|
222
|
coalesce( src_schema.nspname, '' ) NOT IN ( 'z_99_drop', 'x_950_import', 'x_900_export' )
|
223
|
-- analog für Ziel des Contraint-Triggers (fKey)
|
224
|
AND coalesce( trg_schema.nspname, '' ) NOT IN ( 'z_99_drop', 'x_950_import', 'x_900_export' )
|
225
|
)
|
226
|
)
|
227
|
ORDER BY tgname
|
228
|
$$ LANGUAGE sql;
|
229
|
|
230
|
|
231
|
|
232
|
|
233
|
--
|
234
|
CREATE FUNCTION TSystem.triggers__all__disable() RETURNS VOID AS $$
|
235
|
DECLARE r RECORD;
|
236
|
BEGIN
|
237
|
BEGIN
|
238
|
PERFORM TSystem.Settings__Set('triggersdisabled', True);
|
239
|
EXCEPTION WHEN OTHERS THEN
|
240
|
PERFORM TSystem.Settings__Set('triggersdisabled', True);
|
241
|
END;
|
242
|
|
243
|
FOR r IN
|
244
|
--SELECT DISTINCT schemaname, tablename
|
245
|
--FROM tablefieldinfo
|
246
|
--WHERE schemaname NOT IN ('z_99_drop', 'import')
|
247
|
-- AND tablename NOT IN ('tablefieldinfo') -- es gibt ein SELECT darauf, drum lässt sich kein ALTER TABLE machen
|
248
|
-- AND NOT isView
|
249
|
SELECT DISTINCT table_schema AS schemaname, table_name AS tablename
|
250
|
FROM information_schema.tables
|
251
|
WHERE table_catalog = current_database()
|
252
|
AND table_type = 'BASE TABLE'
|
253
|
AND table_schema NOT IN ('information_schema', 'pg_catalog', 'z_99_drop', 'import')
|
254
|
LOOP
|
255
|
EXECUTE 'ALTER TABLE ' || quote_ident(r.schemaname) || '.' || quote_ident(r.tablename) || ' DISABLE TRIGGER ALL';
|
256
|
END LOOP;
|
257
|
END $$ LANGUAGE plpgsql;
|
258
|
--
|
259
|
|
260
|
--
|
261
|
CREATE FUNCTION TSystem.triggers__all__enable() RETURNS VOID AS $$
|
262
|
DECLARE r RECORD;
|
263
|
BEGIN
|
264
|
FOR r IN -- aus TFormDBUpdates.Up_EnableTrigger -> lokales CodeSelect
|
265
|
SELECT DISTINCT table_schema AS schemaname, table_name AS tablename
|
266
|
FROM information_schema.tables
|
267
|
WHERE table_catalog = current_database()
|
268
|
AND table_type = 'BASE TABLE'
|
269
|
AND table_schema NOT IN ('information_schema', 'pg_catalog', 'z_99_drop', 'import')
|
270
|
LOOP
|
271
|
EXECUTE 'ALTER TABLE ' || quote_ident(r.schemaname) || '.' || quote_ident(r.tablename) || ' ENABLE TRIGGER ALL';
|
272
|
END LOOP;
|
273
|
|
274
|
BEGIN
|
275
|
PERFORM TSystem.Settings__Set('triggersdisabled', False);
|
276
|
EXCEPTION WHEN OTHERS THEN
|
277
|
PERFORM TSystem.Settings__Set('triggersdisabled', False);
|
278
|
END;
|
279
|
END $$ LANGUAGE plpgsql;
|
280
|
|
281
|
|
282
|
CREATE FUNCTION TSystem.LogDebug(source VARCHAR, message TEXT, category INTEGER DEFAULT 0, context TEXT DEFAULT NULL) RETURNS VOID AS $$
|
283
|
BEGIN
|
284
|
RETURN;
|
285
|
END $$ LANGUAGE plpgsql;
|
286
|
|
287
|
|
288
|
|
289
|
-- Erstellt einen View zur Abfrage von DB-Tabellen, Views darauf, Feldern und ForeignKeys der Felder. Schließt PG_catalog und einige System-Schemata aus.
|
290
|
DROP VIEW IF EXISTS TSystem.tablefieldinfo_view;
|
291
|
CREATE VIEW TSystem.tablefieldinfo_view AS
|
292
|
|
293
|
SELECT
|
294
|
-- this filters out composite indicies and duplicated FKs on same columns
|
295
|
DISTINCT ON ( n.nspname, c.relname, a.attnum )
|
296
|
|
297
|
-- this function is used by the information schema views
|
298
|
-- the bitmask works like this:
|
299
|
-- b'00000100' = deleteable
|
300
|
-- b'00001000' = updateable
|
301
|
-- b'00010000' = insertable
|
302
|
(pg_relation_is_updatable(c.oid::regclass, false)::bit(8) & b'00011100' = b'00011100' ) AS isWritable,
|
303
|
|
304
|
c.relkind = 'v' AS isview,
|
305
|
n.nspname AS schemaname,
|
306
|
c.relname AS tablename,
|
307
|
a.attnum AS index,
|
308
|
a.attname AS field,
|
309
|
|
310
|
-- t.typcategory,
|
311
|
format_type( a.atttypid, null ) AS type,
|
312
|
|
313
|
-- length only for string types
|
314
|
CASE WHEN
|
315
|
-- S = varchars und chars
|
316
|
t.typcategory IN ( 'S' )
|
317
|
THEN nullif(a.atttypmod,-1) - 4
|
318
|
ELSE null
|
319
|
END
|
320
|
AS length,
|
321
|
|
322
|
-- adsrc was removed in pg12
|
323
|
pg_get_expr( d.adbin, d.adrelid ) AS "default",
|
324
|
|
325
|
fn.nspname AS foreign_table_schema,
|
326
|
ft.relname AS foreign_table_name,
|
327
|
fc.attname AS foreign_column_name
|
328
|
|
329
|
FROM
|
330
|
pg_class AS c
|
331
|
|
332
|
-- schemata
|
333
|
LEFT JOIN pg_namespace AS n ON
|
334
|
n.oid = c.relnamespace
|
335
|
|
336
|
-- columns
|
337
|
LEFT JOIN pg_attribute AS a ON
|
338
|
c.oid = a.attrelid
|
339
|
|
340
|
-- columntypes
|
341
|
LEFT JOIN pg_type AS t ON
|
342
|
t.oid = a.atttypid
|
343
|
|
344
|
-- default values of columns
|
345
|
LEFT JOIN pg_attrdef AS d ON
|
346
|
d.adrelid = c.oid
|
347
|
AND d.adnum = a.attnum
|
348
|
|
349
|
-- FKs
|
350
|
LEFT JOIN pg_constraint AS f ON
|
351
|
f.contype = 'f' -- foreignkey
|
352
|
AND f.conrelid = c.oid -- local table
|
353
|
AND array_length ( f.confkey , 1 ) < 2 -- exclude composite keys
|
354
|
AND f.conkey[1] = a.attnum -- conkey is a array over the attributes ordinal positions
|
355
|
|
356
|
-- destination of FKs
|
357
|
LEFT JOIN pg_attribute AS fc ON
|
358
|
f.confrelid = fc.attrelid -- foreign table
|
359
|
AND f.confkey[1] = fc.attnum
|
360
|
|
361
|
LEFT JOIN pg_class AS ft ON
|
362
|
ft.oid = f.confrelid
|
363
|
|
364
|
LEFT JOIN pg_namespace AS fn ON
|
365
|
fn.oid = ft.relnamespace
|
366
|
|
367
|
WHERE
|
368
|
-- only tables and views ( including materialized views )
|
369
|
c.relkind IN ('r','v','m')
|
370
|
|
371
|
-- p = permanent table ( default tables)
|
372
|
-- u = unlogged table ( eg. tlog.auditlog )
|
373
|
-- t = temporary table ( pg_temp_%, create temp table )
|
374
|
AND c.relpersistence IN ('p','u')
|
375
|
|
376
|
-- exclude certain namespaces; they are lowercase by default, except for doubleQuoted Identifier
|
377
|
AND n.nspname NOT IN (
|
378
|
'pg_catalog', 'information_schema', 'tcache', 'tsystem', 'sunext', 'import', 'z_99_drop', 'x_900_export'
|
379
|
)
|
380
|
|
381
|
-- hide internal fields
|
382
|
-- # select attname, attnum from pg_attribute where attrelid = 'abk'::regclass::oid and attnum < 3
|
383
|
-- ┌──────────────┬────────┐
|
384
|
-- │ attname │ attnum │
|
385
|
-- ╞══════════════╪════════╡
|
386
|
-- │ tableoid │ -7 │
|
387
|
-- │ cmax │ -6 │
|
388
|
-- │ xmax │ -5 │
|
389
|
-- │ cmin │ -4 │
|
390
|
-- │ xmin │ -3 │
|
391
|
-- │ ctid │ -1 │
|
392
|
-- │ ab_ix │ 1 │
|
393
|
-- │ ab_parentabk │ 2 │
|
394
|
-- └──────────────┴────────┘
|
395
|
AND a.attnum > 0
|
396
|
|
397
|
-- they have been deleted anyways by the TSystem.tablefieldinfo__recreate() function
|
398
|
AND a.attname NOT IN ('insert_by', 'modified_by', 'insert_date', 'modified_date')
|
399
|
|
400
|
-- we must omit dropped columns
|
401
|
AND a.attisdropped IS false
|
402
|
|
403
|
|
404
|
ORDER BY schemaname, tablename, index
|
405
|
;
|
406
|
|
407
|
-- Ausgelagert aus Delphi. Ergänzt um Weitergabe der Constraints zugrundeliegender Tabelle an die Views.
|
408
|
CREATE OR REPLACE FUNCTION TSystem.tablefieldinfo__recreate(OUT fieldCountBefore INTEGER, OUT fieldCountAfter INTEGER) RETURNS RECORD AS $$
|
409
|
BEGIN
|
410
|
FieldCountBefore := COUNT(*) FROM tablefieldinfo;
|
411
|
|
412
|
-- Einfach alles rauswerfen und neu aufbauen aus den Information-Schema Katalogen.
|
413
|
TRUNCATE tablefieldinfo;
|
414
|
|
415
|
INSERT INTO tablefieldinfo ( isWritable, isView, schemaname, tablename, index, field, type, length, def, foreign_schema, foreign_table, foreign_column)
|
416
|
SELECT * FROM TSystem.TableFieldInfo_view ORDER BY schemaname, tablename, field;
|
417
|
|
418
|
-- View ist Updatable und wird als ChildLink benutzt. Also brauchen wir Defaults und Foreign-Keys.
|
419
|
PERFORM TSystem.CopyConstraintInfo('public', 'oplpm_data', 'public', 'oplpm');
|
420
|
PERFORM TSystem.CopyConstraintInfo('public', 'oplpm_stam', 'public', 'oplpm_data');
|
421
|
|
422
|
-- view dbrid default wert setzen
|
423
|
UPDATE tablefieldinfo SET def = 'nextval(''db_id_seq'')' WHERE isView AND isWritable AND field = 'dbrid';
|
424
|
|
425
|
FieldCountAfter := COUNT(*) FROM tablefieldinfo;
|
426
|
|
427
|
--- #18294 Auditlog-Config-FieldList Refresh
|
428
|
--PERFORM tlog.AuditlogConfig_OF__all__recreate();
|
429
|
|
430
|
RETURN;
|
431
|
END $$ LANGUAGE plpgsql VOLATILE;
|
432
|
--
|
433
|
|
434
|
CREATE OR REPLACE FUNCTION TSystem.CopyConstraintInfo( srcSchema VARCHAR, srcTable VARCHAR, trgSchema VARCHAR, trgViewOrTableName VARCHAR) RETURNS VOID AS $$
|
435
|
BEGIN
|
436
|
|
437
|
-- kopiert spalten defaultwert von tabellen in view informationen
|
438
|
UPDATE tablefieldinfo AS trg SET
|
439
|
def = CASE WHEN trg.isWritable THEN src.def ELSE NULL END,
|
440
|
foreign_table = src.foreign_table,
|
441
|
foreign_column = src.foreign_column
|
442
|
FROM tablefieldinfo AS src
|
443
|
WHERE trg.schemaname = trgSchema
|
444
|
AND trg.tablename = trgViewOrTableName
|
445
|
AND src.Field = trg.field
|
446
|
AND src.schemaname = srcSchema
|
447
|
AND src.tablename = srcTable;
|
448
|
RETURN;
|
449
|
END $$ LANGUAGE plpgsql VOLATILE;
|
450
|
|
451
|
SELECT TSystem.tablefieldinfo__recreate();
|
452
|
|
453
|
|
454
|
-- DELETE FROM dbupdates WHERE upd_kunde IS NOT null
|