-
Notifications
You must be signed in to change notification settings - Fork 1
/
Copy pathpg_fkpart--1.7.sql
1301 lines (1217 loc) · 38.3 KB
/
pg_fkpart--1.7.sql
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
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
/* contrib/pg_fkpart/pg_fkpart--1.7.sql */
-- complain if script is sourced in psql, rather than via DROP EXTENSION
\echo Use "DROP EXTENSION pg_fkpart" to load this file. \quit
--
-- PostgreSQL Partitioning by Foreign Key Utility
--
-- Copyright(C) 2012 Uptime Technologies, LLC.
-- Copyright(C) 2013 Lemoine Automation Technologies
--
-- This program is free software; you can redistribute it and/or modify
-- it under the terms of the GNU General Public License as published by
-- the Free Software Foundation; version 2 of the License.
--
-- This program is distributed in the hope that it will be useful,
-- but WITHOUT ANY WARRANTY; without even the implied warranty of
-- MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
-- GNU General Public License for more details.
--
-- You should have received a copy of the GNU General Public License along
-- with this program; if not, write to the Free Software Foundation, Inc.,
-- 51 Franklin Street, Fifth Floor, Boston, MA 02110-1301 USA.
--
--CREATE SCHEMA pgfkpart; -- Because the schema contains the extension
-- TODO:
-- manage the tables with a primary key which is not _table_name || 'id'
--
-- pgfkpart._foreign_key_definitions view
--
DROP VIEW IF EXISTS pgfkpart._foreign_key_definitions;
CREATE OR REPLACE VIEW pgfkpart._foreign_key_definitions AS
SELECT
tc.constraint_name, tc.table_schema, tc.table_name, kcu.column_name,
ccu.table_schema AS foreign_table_schema,
ccu.table_name AS foreign_table_name,
ccu.column_name AS foreign_column_name,
rc.match_option,
rc.update_rule,
rc.delete_rule
FROM
information_schema.table_constraints AS tc
JOIN information_schema.key_column_usage AS kcu ON tc.constraint_name = kcu.constraint_name
JOIN information_schema.constraint_column_usage AS ccu ON ccu.constraint_name = tc.constraint_name
LEFT OUTER JOIN information_schema.referential_constraints AS rc ON tc.constraint_name = rc.constraint_name
WHERE constraint_type = 'FOREIGN KEY';
--
-- pgfkpart._get_attname_by_attnum()
--
-- Get an attribute name by nspname, relname and attribute number
--
CREATE OR REPLACE FUNCTION pgfkpart._get_attname_by_attnum (
NAME,
NAME,
SMALLINT
) RETURNS NAME
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_attnum ALIAS FOR $3;
_attname NAME;
BEGIN
SELECT a.attname INTO _attname
FROM pg_namespace n, pg_class c, pg_attribute a
WHERE n.nspname = _nspname
AND c.relname = _relname
AND n.oid = c.relnamespace
AND c.oid = a.attrelid
AND a.attnum = _attnum;
RETURN _attname;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_primary_key_def()
--
-- Get a primary key definition string for new partition.
--
CREATE OR REPLACE FUNCTION pgfkpart._get_primary_key_def (
NAME,
NAME,
NAME
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_conname NAME;
_conkey SMALLINT[];
_size SMALLINT;
_keyidx SMALLINT;
_keyname NAME;
_keys TEXT;
BEGIN
SELECT a.conname, a.conkey, array_length(a.conkey, 1)
INTO _conname, _conkey, _size
FROM pg_namespace n, pg_class c, pg_constraint a
WHERE n.nspname = _nspname
AND c.relname = _relname
AND n.oid = c.relnamespace
AND c.oid = a.conrelid
AND a.contype = 'p';
IF NOT FOUND THEN
RETURN '';
END IF;
_keys = '';
FOR _keyidx IN 1.._size LOOP
SELECT pgfkpart._get_attname_by_attnum(_nspname::name, _relname::name, _keyidx::smallint)
INTO _keyname;
_keys = _keys || ',' || _keyname;
END LOOP;
RETURN 'ALTER TABLE pgfkpart.' || _partname || ' ADD PRIMARY KEY (' || substring(_keys,2) || ')';
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_parent_index_def()
--
-- Get index definition string(s) for the parent table
--
CREATE OR REPLACE FUNCTION pgfkpart._get_parent_index_def (
NAME,
NAME
) RETURNS SETOF TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_r RECORD;
_indexdef TEXT;
BEGIN
FOR _r IN SELECT index_name, index_def, index_isunique, index_immediate, index_isexclusion, constraint_def
FROM pgfkpart.parentindex
WHERE table_schema=_nspname AND table_name=_relname
LOOP
IF _r.index_isunique THEN
_indexdef = 'ALTER TABLE ' || _nspname || '.' || _relname || '
ADD CONSTRAINT ' || _r.index_name || ' UNIQUE' ||
substring (_r.index_def from '\(.*\)');
IF NOT _r.index_immediate THEN
_indexdef = _indexdef || ' DEFERRABLE INITIALLY DEFERRED';
END IF;
ELSIF _r.index_isexclusion THEN
_indexdef = 'ALTER TABLE ' || _nspname || '.' || _relname || '
ADD CONSTRAINT ' || _r.index_name || ' ' || _r.constraint_def;
ELSE
_indexdef = _r.index_def;
END IF;
RETURN NEXT _indexdef;
END LOOP;
RETURN;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_index_name()
--
-- Get the index name for a partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_index_name (
NAME,
NAME,
NAME,
NAME
) RETURNS NAME
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_index_name ALIAS FOR $4;
BEGIN
RETURN regexp_replace (_index_name, '^' || _relname, _partname);
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_index_def()
--
-- Get index definition string(s) for new partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_index_def (
NAME,
NAME,
NAME,
NAME,
TEXT,
BOOL,
BOOL,
BOOL,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_index_name ALIAS FOR $4;
_index_def ALIAS FOR $5;
_index_isunique ALIAS FOR $6;
_index_immediate ALIAS FOR $7;
_index_isexclusion ALIAS FOR $8;
_constraint_def ALIAS FOR $9;
_partindexname NAME;
_partindexdef TEXT;
_def TEXT;
BEGIN
_partindexname = pgfkpart._get_index_name (_nspname, _relname, _partname, _index_name);
IF _index_isunique THEN
_partindexdef = 'ALTER TABLE pgfkpart.' || _partname || '
ADD CONSTRAINT ' || _partindexname || ' UNIQUE' ||
substring (_index_def from '\(.*\)');
IF NOT _index_immediate THEN
_partindexdef = _partindexdef || ' DEFERRABLE INITIALLY DEFERRED';
END IF;
ELSIF _index_isexclusion THEN
_partindexdef = 'ALTER TABLE pgfkpart.' || _partname || '
ADD CONSTRAINT ' || _partindexname || ' ' || _constraint_def;
ELSE
_partindexdef = regexp_replace(_index_def, 'INDEX .* ON ', 'INDEX ' || _partindexname || ' ON ');
_partindexdef = replace(_partindexdef, ' ON ' || _relname, ' ON pgfkpart.' || _partname);
_partindexdef = replace(_partindexdef, ' ON ' || _nspname || '.' || _relname, ' ON pgfkpart.' || _partname);
END IF;
RETURN _partindexdef;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_index_def()
--
-- Get index definition string(s) for new partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_index_def (
NAME,
NAME,
NAME
) RETURNS SETOF TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_r RECORD;
BEGIN
FOR _r IN SELECT index_name, index_def, index_isunique, index_immediate, index_isexclusion, constraint_def
FROM pgfkpart.parentindex
WHERE table_schema=_nspname AND table_name=_relname
LOOP
RETURN NEXT pgfkpart._get_index_def (_nspname, _relname, _partname, _r.index_name, _r.index_def, _r.index_isunique, _r.index_immediate, _r.index_isexclusion, _r.constraint_def);
END LOOP;
RETURN;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_index_def()
--
-- Get index definition string(s) for new partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_index_def (
NAME,
NAME,
NAME,
NAME
) RETURNS SETOF TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_indexname ALIAS FOR $4;
_r RECORD;
BEGIN
FOR _r IN SELECT index_name, index_def, index_isunique, index_immediate, index_isexclusion, constraint_def
FROM pgfkpart.parentindex
WHERE table_schema=_nspname AND table_name=_relname AND index_name=_indexname
LOOP
RETURN NEXT pgfkpart._get_index_def (_nspname, _relname, _partname, _r.index_name, _r.index_def, _r.index_isunique, _r.index_immediate, _r.index_isexclusion, _r.constraint_def);
END LOOP;
RETURN;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_partition_def()
--
-- Get a partiton definition string for new partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_partition_def (
NAME,
NAME,
NAME,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_cond ALIAS FOR $4;
_partition_def TEXT;
_const_def TEXT;
BEGIN
_const_def = pgfkpart._get_constraint_def(_partname, _cond);
_partition_def = 'CREATE TABLE pgfkpart.' || _partname || '( ';
_partition_def = _partition_def || 'CONSTRAINT ' || _const_def;
_partition_def = _partition_def || ') INHERITS (' || _nspname || '.' || _relname || ')';
RETURN _partition_def;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_export_query()
--
-- Get a query to export records with specified condition from parent table.
--
CREATE OR REPLACE FUNCTION pgfkpart._get_export_query (
NAME,
NAME,
TEXT,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_cond ALIAS FOR $3;
_temp_file ALIAS FOR $4;
_query TEXT;
BEGIN
_query = 'COPY ( ' || 'SELECT * FROM ' || _nspname || '.' || _relname || ' WHERE ' || _cond || ' ) to ''' || _temp_file || '''';
RETURN _query;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_import_query()
--
-- Get a query to import records into specified partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_import_query (
NAME,
NAME,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_temp_file ALIAS FOR $3;
_query TEXT;
BEGIN
_query = 'COPY ' || _nspname || '.' || _relname || ' FROM ''' || _temp_file || '''';
RETURN _query;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._add_partition()
--
-- Add a new partition with a specified condition
--
CREATE OR REPLACE FUNCTION pgfkpart._add_partition (
NAME,
NAME,
NAME,
TEXT,
TEXT
) RETURNS BOOLEAN
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_cond ALIAS FOR $4;
_temp_file ALIAS FOR $5;
_r RECORD;
_def TEXT;
BEGIN
FOR _r IN SELECT pgfkpart._get_partition_def(_nspname, _relname, _partname, _cond) LOOP
_def = _r._get_partition_def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
END LOOP;
SELECT pgfkpart._get_export_query(_nspname, _relname, _cond, _temp_file)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
_def = 'DELETE FROM ' || _nspname || '.' || _relname || ' WHERE ' || _cond;
_def = _def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
SELECT pgfkpart._get_import_query('pgfkpart', _partname, _temp_file)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
SELECT pgfkpart._get_primary_key_def(_nspname, _relname, _partname)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
FOR _r IN SELECT pgfkpart._get_index_def(_nspname, _relname, _partname) LOOP
_def = _r._get_index_def || ';';
RAISE NOTICE 'add_partition: %', _def;
EXECUTE _def;
END LOOP;
RETURN true;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._merge_partition()
--
-- Merge a partition into the parent table.
--
CREATE OR REPLACE FUNCTION pgfkpart._merge_partition (
NAME,
NAME,
NAME,
TEXT,
TEXT
) RETURNS BOOLEAN
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_cond ALIAS FOR $4;
_temp_file ALIAS FOR $5;
_r RECORD;
_def TEXT;
BEGIN
SELECT pgfkpart._get_export_query('pgfkpart', _partname, '1 = 1', _temp_file)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'merge_partition: %', _def;
EXECUTE _def;
SELECT pgfkpart._get_import_query(_nspname, _relname, _temp_file)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'merge_partition: %', _def;
EXECUTE _def;
SELECT pgfkpart._get_detach_partition_def(_nspname, _relname, _partname)
INTO _def;
_def = _def || ';';
RAISE NOTICE 'merge_partition: %', _def;
EXECUTE _def;
_def = 'DROP TABLE pgfkpart.' || _partname;
_def = _def || ';';
RAISE NOTICE 'merge_partition: %', _def;
EXECUTE _def;
RETURN true;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_constraint_name()
--
CREATE OR REPLACE FUNCTION pgfkpart._get_constraint_name (
NAME
) RETURNS TEXT
AS $BODY$
DECLARE
_partname ALIAS FOR $1;
BEGIN
RETURN '__' || _partname || '_check';
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_constraint_def()
--
CREATE OR REPLACE FUNCTION pgfkpart._get_constraint_def (
NAME,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_partname ALIAS FOR $1;
_cond ALIAS FOR $2;
BEGIN
RETURN pgfkpart._get_constraint_name(_partname) || ' CHECK(' || _cond || ')';
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_attach_partition_def()
--
-- Get a definition string for attaching a partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_attach_partition_def (
NAME,
NAME,
NAME,
TEXT
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_cond ALIAS FOR $4;
_partition_def TEXT;
_const_def TEXT;
BEGIN
_const_def = pgfkpart._get_constraint_def(_partname, _cond);
_partition_def = 'ALTER TABLE pgfkpart.' || _partname;
_partition_def = _partition_def || ' INHERIT ' || _relname || ',';
_partition_def = _partition_def || ' ADD CONSTRAINT ' || _const_def;
RETURN _partition_def;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart.attach_partition()
--
-- Attach a new partition to the parent table with a specified condition
--
CREATE OR REPLACE FUNCTION pgfkpart.attach_partition (
NAME,
NAME,
NAME,
TEXT
) RETURNS BOOLEAN
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_cond ALIAS FOR $4;
_r RECORD;
_def TEXT;
BEGIN
--
-- Check whether constraint is valid for this partition.
--
_def = 'SELECT count(*) FROM pgfkpart.' || _partname || ' WHERE NOT (' || _cond || ')';
RAISE NOTICE 'attach_partition: %', _def;
FOR _r IN EXECUTE _def LOOP
IF _r.count > 0 THEN
RAISE EXCEPTION 'attach_partition: % record(s) in this partition does not satisfy specified constraint.', _r.count;
END IF;
END LOOP;
FOR _r IN SELECT pgfkpart._get_attach_partition_def(_nspname, _relname, _partname, _cond) LOOP
_def = _r._get_attach_partition_def || ';';
RAISE NOTICE 'attach_partition: %', _def;
EXECUTE _def;
END LOOP;
-- SELECT pgfkpart._get_primary_key_def(_nspname, _relname, _partname)
-- INTO _def;
-- _def = _def || ';';
-- RAISE NOTICE 'attach_partition: %', _def;
-- EXECUTE _def;
--
-- FOR _r IN SELECT pgfkpart._get_index_def(_nspname, _relname, _partname) LOOP
-- _def = _r._get_index_def || ';';
-- RAISE NOTICE 'attach_partition: %', _def;
-- EXECUTE _def;
-- END LOOP;
RETURN true;
END
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart._get_detach_partition_def()
--
-- Get a definition string for detaching a partition
--
CREATE OR REPLACE FUNCTION pgfkpart._get_detach_partition_def (
NAME,
NAME,
NAME
) RETURNS TEXT
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_partition_def TEXT;
_const_name TEXT;
BEGIN
_const_name = pgfkpart._get_constraint_name(_partname);
_partition_def = 'ALTER TABLE pgfkpart.' || _partname;
_partition_def = _partition_def || ' NO INHERIT ' || _nspname || '.' || _relname || ',';
_partition_def = _partition_def || ' DROP CONSTRAINT ' || _const_name;
RETURN _partition_def;
END;
$BODY$ LANGUAGE 'plpgsql';
--
-- pgfkpart.detach_partition()
--
-- Detach a partition from the parent table.
--
CREATE OR REPLACE FUNCTION pgfkpart.detach_partition (
NAME,
NAME,
NAME
) RETURNS BOOLEAN
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname ALIAS FOR $3;
_r RECORD;
_def TEXT;
BEGIN
FOR _r IN SELECT pgfkpart._get_detach_partition_def(_nspname, _relname, _partname) LOOP
_def = _r._get_detach_partition_def || ';';
RAISE NOTICE 'detach_partition: %', _def;
EXECUTE _def;
END LOOP;
RETURN true;
END
$BODY$ LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION pgfkpart.show_partition (
NAME,
NAME
) RETURNS SETOF NAME
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_partname NAME;
BEGIN
FOR _partname IN SELECT c.relname
FROM pg_namespace n, pg_class p, pg_inherits i, pg_class c
WHERE n.nspname=_nspname
AND n.oid=p.relnamespace
AND p.relname=_relname
AND p.oid=i.inhparent
AND i.inhrelid=c.oid
ORDER BY c.relname LOOP
RETURN NEXT _partname;
END LOOP;
END
$BODY$ LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION pgfkpart._exec(
TEXT
) RETURNS void
AS
$BODY$
BEGIN
EXECUTE $1;
END;
$BODY$
LANGUAGE 'plpgsql';
-- DROP TABLE IF EXISTS pgfkpart.partition;
CREATE TABLE IF NOT EXISTS pgfkpart.partition
(
partitionid SERIAL NOT NULL,
table_schema NAME NOT NULL,
table_name NAME NOT NULL,
column_name NAME NOT NULL,
foreign_table_schema NAME NOT NULL,
foreign_table_name NAME NOT NULL,
foreign_column_name NAME NOT NULL,
CONSTRAINT partitions_pkey PRIMARY KEY (partitionid),
CONSTRAINT partitions_key UNIQUE (table_schema, table_name)
)
WITH (
OIDS=FALSE
);
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.partition', '');
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.partition_partitionid_seq', '');
-- Reference to the foreign keys that were 'partitioned'
-- DROP TABLE IF EXISTS pgfkpart.partforeignkey
CREATE TABLE IF NOT EXISTS pgfkpart.partforeignkey
(
partforeignkeyid SERIAL NOT NULL,
constraint_name NAME NOT NULL,
table_schema NAME NOT NULL,
table_name NAME NOT NULL,
column_name NAME NOT NULL,
foreign_table_schema NAME NOT NULL,
foreign_table_name NAME NOT NULL,
foreign_column_name NAME NOT NULL,
match_option TEXT NOT NULL,
update_rule TEXT NOT NULL,
delete_rule TEXT NOT NULL
)
WITH (
OIDS=FALSE
);
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.partforeignkey', '');
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.partforeignkey_partforeignkeyid_seq', '');
-- Table to store the initial parent indexes
-- DROP TABLE IF EXISTS pgfkpart.parentindex
CREATE TABLE IF NOT EXISTS pgfkpart.parentindex
(
parentindexid SERIAL NOT NULL,
table_schema NAME NOT NULL,
table_name NAME NOT NULL,
index_name NAME NOT NULL,
index_def TEXT NOT NULL,
index_isunique BOOLEAN NOT NULL,
index_immediate BOOLEAN NOT NULL,
index_isprimary BOOLEAN NOT NULL,
index_isexclusion BOOLEAN NOT NULL,
constraint_def TEXT,
CONSTRAINT parentindex_pkey PRIMARY KEY (parentindexid),
CONSTRAINT parentindex_key UNIQUE (table_schema, table_name, index_name)
)
WITH (
OIDS=FALSE
);
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.parentindex', '');
SELECT pg_catalog.pg_extension_config_dump('pgfkpart.parentindex_parentindexid_seq', '');
CREATE OR REPLACE FUNCTION pgfkpart._get_partition_name (
NAME,
TEXT
) RETURNS NAME
AS $BODY$
DECLARE
_relname ALIAS FOR $1;
_column_value ALIAS FOR $2;
BEGIN
RETURN _relname || '_p' || _column_value;
END
$BODY$
LANGUAGE 'plpgsql';
CREATE OR REPLACE FUNCTION pgfkpart._add_partition_with_fk (
NAME,
NAME,
TEXT,
TEXT,
TEXT
) RETURNS BOOLEAN
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_column_value ALIAS FOR $3;
_cond ALIAS FOR $4;
_temp_file ALIAS FOR $5;
_partname NAME;
_r RECORD;
_request TEXT;
_result BOOLEAN;
BEGIN
_partname := pgfkpart._get_partition_name (_relname, _column_value);
-- Execute _add_partition
SELECT pgfkpart._add_partition (_nspname, _relname, _partname, _cond, _temp_file) INTO _result;
-- Restore the foreign key if needed
FOR _r IN SELECT * FROM pgfkpart.partforeignkey WHERE table_schema=_nspname AND table_name=_relname LOOP
-- Check the foreign key table exists. If not, create it
EXECUTE 'SELECT * FROM pg_class t, pg_namespace s
WHERE t.relname=$$' || pgfkpart._get_partition_name (_r.foreign_table_name, _column_value) || '$$
AND t.relnamespace=s.oid
AND s.nspname=$$pgfkpart$$';
IF NOT FOUND THEN
EXECUTE 'SELECT pgfkpart._add_partition_with_fk(
$$' || _r.foreign_table_schema || '$$,
$$' || _r.foreign_table_name || '$$,
$$' || _column_value || '$$,
$$' || _r.foreign_column_name || '=' || _column_value || '$$,
$$' || _temp_file || _r.foreign_table_name || '$$)';
END IF;
-- Add the foreign key once the foreign key table exists
_request := 'ALTER TABLE pgfkpart.' || _partname ||'
ADD CONSTRAINT ' || _r.constraint_name || ' FOREIGN KEY (' || _r.column_name || ')
REFERENCES pgfkpart.' || pgfkpart._get_partition_name (_r.foreign_table_name, _column_value) || ' (' || _r.foreign_column_name || ') ';
IF _r.match_option <> 'NONE' THEN
_request := _request || _r.match_option;
END IF;
_request := _request || '
ON UPDATE ' || _r.update_rule || ' ON DELETE ' || _r.delete_rule;
EXECUTE _request;
END LOOP;
RETURN _result;
END
$BODY$
LANGUAGE 'plpgsql';
--
-- pgfkpart.partition_with_fk()
--
-- Partition a table following a specified foreign key
--
CREATE OR REPLACE FUNCTION pgfkpart.partition_with_fk (
NAME,
NAME,
NAME,
NAME,
BOOLEAN
) RETURNS void
AS $BODY$
BEGIN
EXECUTE pgfkpart.partition_with_fk ($1, $2, $3, $4, $5, NULL);
END
$BODY$
LANGUAGE 'plpgsql';
--
-- pgfkpart.partition_with_fk()
--
-- Partition a table following a specified foreign key
--
CREATE OR REPLACE FUNCTION pgfkpart.partition_with_fk (
NAME,
NAME,
NAME,
NAME,
BOOLEAN,
TEXT
) RETURNS void
AS $BODY$
DECLARE
_nspname ALIAS FOR $1;
_relname ALIAS FOR $2;
_foreignnspname ALIAS FOR $3;
_foreignrelname ALIAS FOR $4;
_returning ALIAS FOR $5;
_tmpfilepath ALIAS FOR $6;
_column_name NAME;
_foreign_column_name NAME;
_r RECORD;
_returning_text TEXT;
BEGIN
-- Check if the table has already been partitioned
SELECT table_schema, table_name, column_name, foreign_table_schema, foreign_table_name, foreign_column_name
INTO _r
FROM pgfkpart.partition
WHERE table_schema=_nspname AND table_name=_relname;
IF FOUND
THEN
IF _r.foreign_table_schema=_foreignnspname AND _r.foreign_table_name=_foreignrelname
THEN RAISE INFO 'The table %.% is already partitioned', _nspname, _relname; RETURN;
ELSE RAISE EXCEPTION 'The table %.% is already partitioned but with the foreign key %.%', _nspname, _relname, _r.foreign_table_schema, _r.foreign_table_name;
END IF;
END IF;
-- Get _column_name and _foreign_column_name
SELECT column_name, foreign_column_name
INTO _column_name, _foreign_column_name
FROM pgfkpart._foreign_key_definitions
WHERE table_name=_relname AND table_schema=_nspname
AND foreign_table_name=_foreignrelname AND foreign_table_schema=_foreignnspname;
IF NOT FOUND
THEN RAISE EXCEPTION 'No foreign key is defined between %.% and %.%', _nspname, _relname, _foreignnspname, _foreignrelname;
END IF;
-- If one of the foreign key is on a partitioned table, move the foreign key to the partitioned tables
-- It must be done before add_partition
FOR _r IN SELECT d.* FROM pgfkpart._foreign_key_definitions d
INNER JOIN pgfkpart.partition p ON (d.foreign_table_name=p.table_name AND d.foreign_table_schema=p.table_schema)
WHERE d.table_schema=_nspname AND d.table_name=_relname LOOP
-- Store this foreign key in table partforeignkey
INSERT INTO pgfkpart.partforeignkey(constraint_name, table_schema, table_name, column_name, foreign_table_schema, foreign_table_name, foreign_column_name, match_option, update_rule, delete_rule)
VALUES (_r.constraint_name, _r.table_schema, _r.table_name, _r.column_name, _r.foreign_table_schema, _r.foreign_table_name, _r.foreign_column_name, _r.match_option, _r.update_rule, _r.delete_rule);
-- Remove the old foreign key
EXECUTE 'ALTER TABLE ' || _nspname || '.' || _relname || ' DROP CONSTRAINT ' || _r.constraint_name;
END LOOP;
-- Complete _tmpfilepath if unknown
IF _tmpfilepath IS NULL
THEN _tmpfilepath := '/tmp/pgfkpart_' || _relname;
END IF;
-- Set _returning_text
IF _returning
THEN _returning_text := '_r';
ELSE _returning_text := 'NULL';
END IF;
-- Store the indexes in pgfkpart.parentindex and remove them
INSERT INTO pgfkpart.parentindex (table_schema, table_name, index_name, index_def, index_isunique, index_immediate, index_isprimary, index_isexclusion, constraint_def)
SELECT _nspname, _relname, idxs.indexname, idxs.indexdef, idx.indisunique, idx.indimmediate, idx.indisprimary, idx.indisexclusion, pg_get_constraintdef(con.oid, true) AS constraint_def
FROM pg_indexes idxs
INNER JOIN pg_class cls2 ON (idxs.indexname=cls2.relname)
INNER JOIN pg_index idx ON (idx.indexrelid=cls2.oid)
INNER JOIN pg_class cls ON (cls.oid=idx.indrelid)
INNER JOIN pg_namespace nsp ON (nsp.oid=cls.relnamespace)
LEFT JOIN pg_constraint con ON (idxs.indexname=con.conname)
WHERE nsp.nspname=_nspname
AND cls.relname=_relname
AND idx.indisprimary <> true;
FOR _r IN SELECT index_name, index_isunique, index_isexclusion FROM pgfkpart.parentindex WHERE table_schema=_nspname AND table_name=_relname LOOP
RAISE NOTICE 'partition_with_fk: about to remove index %', _r.index_name;
IF _r.index_isunique OR _r.index_isexclusion THEN
EXECUTE 'ALTER TABLE ' || _nspname || '.' || _relname || ' DROP CONSTRAINT IF EXISTS ' || _r.index_name || ' CASCADE';
END IF;
EXECUTE 'DROP INDEX IF EXISTS ' || _r.index_name || ' CASCADE';
END LOOP;
-- Execute _add_partition on all the rows of _foreignrelname
RAISE INFO 'Partitioning %.%...', _nspname, _relname;
EXECUTE 'SELECT pgfkpart._exec(
$A$SELECT pgfkpart._add_partition_with_fk($$' || _nspname || '$$,
$$' || _relname || '$$,
$$$A$ || ' || _foreign_column_name || ' || $A$$$,
$$' || _column_name || '=$A$ || ' || _foreign_column_name || ' || $A$$$,
$$' || _tmpfilepath || '$$)$A$
)
FROM ' || _foreignnspname || '.' || _foreignrelname;
-- Store the table was partitioned
INSERT INTO pgfkpart.partition (table_schema, table_name, column_name, foreign_table_schema, foreign_table_name, foreign_column_name)
VALUES (_nspname, _relname, _column_name, _foreignnspname, _foreignrelname, _foreign_column_name);
-- Add a trigger to the main table
EXECUTE 'CREATE OR REPLACE FUNCTION ' || _nspname || '.' || _relname || '_child_insert ()
RETURNS trigger AS
$A$
DECLARE
_partition NAME;
_column_name NAME;
_column_value TEXT;
_r ' || _nspname || '.' || _relname || '%ROWTYPE;
BEGIN
-- Get the column name
SELECT column_name
INTO _column_name
FROM pgfkpart.partition
WHERE table_schema=$$' || _nspname || '$$ AND table_name=$$' || _relname || '$$;
-- Get the column value
EXECUTE $$SELECT $1.$$ || _column_name
INTO _column_value
USING NEW;
-- Get the partition name
SELECT pgfkpart._get_partition_name($$' || _relname || '$$, _column_value)
INTO _partition;
-- Check if the partition name has already been created. If not, create it
IF NOT EXISTS (SELECT * FROM pg_class t, pg_namespace s
WHERE t.relname=_partition
AND t.relnamespace=s.oid
AND s.nspname=$$pgfkpart$$)
THEN EXECUTE $EXEC$SELECT pgfkpart._add_partition_with_fk($$' || _nspname || '$$,
$$' || _relname || '$$,
$$$EXEC$ || NEW.' || _column_name || ' || $EXEC$$$,
$$' || _column_name || '= $EXEC$ || NEW.' || _column_name || ' || $EXEC$$$,
$$' || _tmpfilepath || '$$)$EXEC$;
END IF;
-- Insert in the partition table instead
EXECUTE $EXEC$INSERT INTO pgfkpart.$EXEC$ || _partition || $EXEC$ VALUES ($1.*) RETURNING *$EXEC$
INTO _r
USING NEW;
RETURN ' || _returning_text || ';
END
$A$ LANGUAGE plpgsql';
EXECUTE 'CREATE TRIGGER ' || _relname || '_before_insert
BEFORE INSERT
ON ' || _nspname || '.' || _relname || '
FOR EACH ROW
EXECUTE PROCEDURE ' || _nspname || '.' || _relname || '_child_insert();';
IF _returning THEN
EXECUTE 'CREATE OR REPLACE FUNCTION ' || _nspname || '.' || _relname || '_parent_remove ()
RETURNS trigger AS
$A$
DECLARE
_r ' || _relname || '%ROWTYPE;
BEGIN
DELETE FROM ONLY ' || _relname || ' WHERE ' || _relname || 'id = NEW.' || _relname || 'id
RETURNING * INTO _r;
RETURN _r;