-
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathstructure.sql
10755 lines (7659 loc) · 303 KB
/
structure.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
SET statement_timeout = 0;
SET lock_timeout = 0;
SET idle_in_transaction_session_timeout = 0;
SET client_encoding = 'UTF8';
SET standard_conforming_strings = on;
SELECT pg_catalog.set_config('search_path', '', false);
SET check_function_bodies = false;
SET xmloption = content;
SET client_min_messages = warning;
SET row_security = off;
--
-- Name: es_co_utf_8; Type: COLLATION; Schema: public; Owner: -
--
CREATE COLLATION public.es_co_utf_8 (provider = libc, locale = 'es_CO.UTF-8');
--
-- Name: fuzzystrmatch; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS fuzzystrmatch WITH SCHEMA public;
--
-- Name: EXTENSION fuzzystrmatch; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION fuzzystrmatch IS 'determine similarities and distance between strings';
--
-- Name: unaccent; Type: EXTENSION; Schema: -; Owner: -
--
CREATE EXTENSION IF NOT EXISTS unaccent WITH SCHEMA public;
--
-- Name: EXTENSION unaccent; Type: COMMENT; Schema: -; Owner: -
--
COMMENT ON EXTENSION unaccent IS 'text search dictionary that removes accents';
--
-- Name: completa_obs(character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.completa_obs(obs character varying, nuevaobs character varying) RETURNS character varying
LANGUAGE plpgsql
AS $$
BEGIN
RETURN CASE WHEN obs IS NULL THEN nuevaobs
WHEN obs='' THEN nuevaobs
WHEN RIGHT(obs, 1)='.' THEN obs || ' ' || nuevaobs
ELSE obs || '. ' || nuevaobs
END;
END; $$;
--
-- Name: cor1440_gen_actividad_cambiada(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.cor1440_gen_actividad_cambiada() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
ASSERT(TG_OP = 'UPDATE');
ASSERT(NEW.id = OLD.id);
CALL cor1440_gen_recalcular_poblacion_actividad(NEW.id);
RETURN NULL;
END ;
$$;
--
-- Name: cor1440_gen_asistencia_cambiada_creada_eliminada(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.cor1440_gen_asistencia_cambiada_creada_eliminada() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
CASE
WHEN (TG_OP = 'UPDATE') THEN
ASSERT(NEW.id = OLD.id);
CALL cor1440_gen_recalcular_poblacion_actividad(NEW.actividad_id);
WHEN (TG_OP = 'INSERT') THEN
CALL cor1440_gen_recalcular_poblacion_actividad(NEW.actividad_id);
ELSE -- DELETE
CALL cor1440_gen_recalcular_poblacion_actividad(OLD.actividad_id);
END CASE;
RETURN NULL;
END;
$$;
--
-- Name: cor1440_gen_persona_cambiada(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.cor1440_gen_persona_cambiada() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
aid INTEGER;
BEGIN
ASSERT(TG_OP = 'UPDATE');
ASSERT(NEW.id = OLD.id);
FOR aid IN
SELECT actividad_id FROM cor1440_gen_asistencia
WHERE persona_id=NEW.id
LOOP
CALL cor1440_gen_recalcular_poblacion_actividad(aid);
END LOOP;
RETURN NULL;
END ;
$$;
--
-- Name: cor1440_gen_recalcular_poblacion_actividad(bigint); Type: PROCEDURE; Schema: public; Owner: -
--
CREATE PROCEDURE public.cor1440_gen_recalcular_poblacion_actividad(IN par_actividad_id bigint)
LANGUAGE plpgsql
AS $$
DECLARE
rangos INTEGER ARRAY;
idrangos INTEGER ARRAY;
i INTEGER;
a_dia INTEGER;
a_mes INTEGER;
a_anio INTEGER;
asistente RECORD;
edad INTEGER;
rango_id INTEGER;
BEGIN
RAISE NOTICE 'actividad_id es %', par_actividad_id;
SELECT EXTRACT(DAY FROM fecha) INTO a_dia FROM cor1440_gen_actividad
WHERE id=par_actividad_id LIMIT 1;
RAISE NOTICE 'a_dia es %', a_dia;
SELECT EXTRACT(MONTH FROM fecha) INTO a_mes FROM cor1440_gen_actividad
WHERE id=par_actividad_id;
RAISE NOTICE 'a_mes es %', a_mes;
SELECT EXTRACT(YEAR FROM fecha) INTO a_anio FROM cor1440_gen_actividad
WHERE id=par_actividad_id;
RAISE NOTICE 'a_anio es %', a_anio;
DELETE FROM cor1440_gen_actividad_rangoedadac
WHERE actividad_id=par_actividad_id
;
FOR rango_id IN SELECT id FROM cor1440_gen_rangoedadac
WHERE fechadeshabilitacion IS NULL
LOOP
INSERT INTO cor1440_gen_actividad_rangoedadac
(actividad_id, rangoedadac_id, mr, fr, s, created_at, updated_at)
(SELECT par_actividad_id, rango_id, 0, 0, 0, NOW(), NOW());
END LOOP;
FOR asistente IN SELECT p.id, p.anionac, p.mesnac, p.dianac, p.sexo
FROM cor1440_gen_asistencia AS asi
JOIN cor1440_gen_actividad AS ac ON ac.id=asi.actividad_id
JOIN msip_persona AS p ON p.id=asi.persona_id
WHERE ac.id=par_actividad_id
LOOP
RAISE NOTICE 'persona_id es %', asistente.id;
edad = msip_edad_de_fechanac_fecharef(asistente.anionac, asistente.mesnac,
asistente.dianac, a_anio, a_mes, a_dia);
RAISE NOTICE 'edad es %', edad;
SELECT id INTO rango_id FROM cor1440_gen_rangoedadac WHERE
fechadeshabilitacion IS NULL AND
limiteinferior <= edad AND
(limitesuperior IS NULL OR edad <= limitesuperior) LIMIT 1;
IF rango_id IS NULL THEN
rango_id := 7;
END IF;
RAISE NOTICE 'rango_id es %', rango_id;
CASE asistente.sexo
WHEN 'F' THEN
UPDATE cor1440_gen_actividad_rangoedadac SET fr = fr + 1
WHERE actividad_id=par_actividad_id
AND rangoedadac_id=rango_id;
WHEN 'M' THEN
UPDATE cor1440_gen_actividad_rangoedadac SET mr = mr + 1
WHERE actividad_id=par_actividad_id
AND rangoedadac_id=rango_id;
ELSE
UPDATE cor1440_gen_actividad_rangoedadac SET s = s + 1
WHERE actividad_id=par_actividad_id
AND rangoedadac_id=rango_id;
END CASE;
END LOOP;
DELETE FROM cor1440_gen_actividad_rangoedadac
WHERE actividad_id = par_actividad_id
AND mr = 0 AND fr = 0 AND s = 0
;
RETURN;
END;
$$;
--
-- Name: divarr(anyarray); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.divarr(in_array anyarray) RETURNS SETOF text
LANGUAGE sql IMMUTABLE
AS $_$
SELECT ($1)[s] FROM generate_series(1,array_upper($1, 1)) AS s;
$_$;
--
-- Name: edad_de_fechanac(integer, integer, integer, date); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.edad_de_fechanac(anionac integer, mesnac integer, dianac integer, fechahecho date) RETURNS integer
LANGUAGE plpgsql IMMUTABLE
AS $$
DECLARE
aniohecho INTEGER = EXTRACT(year FROM fechahecho);
meshecho INTEGER = EXTRACT(month FROM fechahecho);
diahecho INTEGER = EXTRACT(day FROM fechahecho);
na INTEGER;
BEGIN
na = CASE WHEN anionac IS NULL OR aniohecho IS NULL THEN
NULL
ELSE
aniohecho - anionac
END;
na = CASE WHEN mesnac IS NOT NULL AND meshecho IS NOT NULL AND
mesnac > meshecho OR
(dianac IS NOT NULL AND diahecho IS NOT NULL
AND dianac > diahecho) THEN
na - 1
ELSE
na
END;
RETURN na;
END;$$;
--
-- Name: f_unaccent(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.f_unaccent(text) RETURNS text
LANGUAGE sql IMMUTABLE
AS $_$
SELECT public.unaccent('public.unaccent', $1)
$_$;
--
-- Name: first_element(anyarray); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.first_element(anyarray) RETURNS anyelement
LANGUAGE sql IMMUTABLE
AS $_$
SELECT ($1)[1] ;
$_$;
--
-- Name: first_element_state(anyarray, anyelement); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.first_element_state(anyarray, anyelement) RETURNS anyarray
LANGUAGE sql IMMUTABLE
AS $_$
SELECT CASE WHEN array_upper($1,1) IS NULL
THEN array_append($1,$2)
ELSE $1
END;
$_$;
--
-- Name: msip_agregar_o_remplazar_familiar_inverso(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_agregar_o_remplazar_familiar_inverso() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
num2 INTEGER;
rinv CHAR(2);
rexistente CHAR(2);
BEGIN
ASSERT(TG_OP = 'INSERT' OR TG_OP = 'UPDATE');
RAISE NOTICE 'Insertando o actualizando en msip_persona_trelacion';
RAISE NOTICE 'TG_OP = %', TG_OP;
RAISE NOTICE 'NEW.id = %', NEW.id;
RAISE NOTICE 'NEW.persona1 = %', NEW.persona1;
RAISE NOTICE 'NEW.persona2 = %', NEW.persona2;
RAISE NOTICE 'NEW.trelacion_id = %', NEW.trelacion_id;
RAISE NOTICE 'NEW.observaciones = %', NEW.observaciones;
SELECT COUNT(*) INTO num2 FROM msip_persona_trelacion
WHERE persona1 = NEW.persona2 AND persona2=NEW.persona1;
RAISE NOTICE 'num2 = %', num2;
ASSERT(num2 < 2);
SELECT inverso INTO rinv FROM msip_trelacion
WHERE id = NEW.trelacion_id;
RAISE NOTICE 'rinv = %', rinv;
ASSERT(rinv IS NOT NULL);
CASE num2
WHEN 0 THEN
INSERT INTO msip_persona_trelacion
(persona1, persona2, trelacion_id, observaciones, created_at, updated_at)
VALUES (NEW.persona2, NEW.persona1, rinv, 'Inverso agregado automaticamente', NOW(), NOW());
ELSE -- num2 = 1
SELECT trelacion_id INTO rexistente FROM msip_persona_trelacion
WHERE persona1=NEW.persona2 AND persona2=NEW.persona1;
RAISE NOTICE 'rexistente = %', rexistente;
IF rinv <> rexistente THEN
UPDATE msip_persona_trelacion
SET trelacion_id = rinv,
observaciones = 'Inverso cambiado automaticamente (era ' ||
rexistente || '). ' || COALESCE(observaciones, ''),
updated_at = NOW()
WHERE persona1=NEW.persona2 AND persona2=NEW.persona1;
END IF;
END CASE;
RETURN NULL;
END ;
$$;
--
-- Name: msip_edad_de_fechanac_fecharef(integer, integer, integer, integer, integer, integer); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_edad_de_fechanac_fecharef(anionac integer, mesnac integer, dianac integer, anioref integer, mesref integer, diaref integer) RETURNS integer
LANGUAGE sql IMMUTABLE
AS $$
SELECT CASE
WHEN anionac IS NULL THEN NULL
WHEN anioref IS NULL THEN NULL
WHEN anioref < anionac THEN -1
WHEN mesnac IS NOT NULL AND mesnac > 0
AND mesref IS NOT NULL AND mesref > 0
AND mesnac >= mesref THEN
CASE
WHEN mesnac > mesref OR (dianac IS NOT NULL
AND dianac > 0 AND diaref IS NOT NULL
AND diaref > 0 AND dianac > diaref) THEN
anioref-anionac-1
ELSE
anioref-anionac
END
ELSE
anioref-anionac
END
$$;
--
-- Name: msip_eliminar_familiar_inverso(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_eliminar_familiar_inverso() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
num2 INTEGER;
BEGIN
ASSERT(TG_OP = 'DELETE');
RAISE NOTICE 'Eliminando inverso de msip_persona_trelacion';
SELECT COUNT(*) INTO num2 FROM msip_persona_trelacion
WHERE persona1 = OLD.persona2 AND persona2=OLD.persona1;
RAISE NOTICE 'num2 = %', num2;
ASSERT(num2 < 2);
IF num2 = 1 THEN
DELETE FROM msip_persona_trelacion
WHERE persona1 = OLD.persona2 AND persona2 = OLD.persona1;
END IF;
RETURN NULL;
END ;
$$;
--
-- Name: msip_nombre_vereda(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_nombre_vereda() RETURNS character varying
LANGUAGE sql
AS $$
SELECT 'Vereda '
$$;
--
-- Name: msip_ubicacionpre_dpa_nomenclatura(character varying, character varying, character varying, character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_ubicacionpre_dpa_nomenclatura(pais character varying, departamento character varying, municipio character varying, vereda character varying, centropoblado character varying) RETURNS text[]
LANGUAGE sql
AS $$
SELECT CASE
WHEN pais IS NULL OR pais = '' THEN
array[NULL, NULL]
WHEN departamento IS NULL OR departamento = '' THEN
array[pais, NULL]
WHEN municipio IS NULL OR municipio = '' THEN
array[departamento || ' / ' || pais, departamento]
WHEN (vereda IS NULL OR vereda = '') AND
(centropoblado IS NULL OR centropoblado = '') THEN
array[
municipio || ' / ' || departamento || ' / ' || pais,
municipio || ' / ' || departamento ]
WHEN vereda IS NOT NULL THEN
array[
msip_nombre_vereda() || vereda || ' / ' ||
municipio || ' / ' || departamento || ' / ' || pais,
msip_nombre_vereda() || vereda || ' / ' ||
municipio || ' / ' || departamento ]
ELSE
array[
centropoblado || ' / ' ||
municipio || ' / ' || departamento || ' / ' || pais,
centropoblado || ' / ' ||
municipio || ' / ' || departamento ]
END
$$;
--
-- Name: msip_ubicacionpre_id_rtablabasica(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_ubicacionpre_id_rtablabasica() RETURNS integer
LANGUAGE sql
AS $$
SELECT max(id+1) FROM msip_ubicacionpre WHERE
(id+1) NOT IN (SELECT id FROM msip_ubicacionpre) AND
id<10000000
$$;
--
-- Name: msip_ubicacionpre_nomenclatura(character varying, character varying, character varying, character varying, character varying, character varying, character varying); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.msip_ubicacionpre_nomenclatura(pais character varying, departamento character varying, municipio character varying, vereda character varying, centropoblado character varying, lugar character varying, sitio character varying) RETURNS text[]
LANGUAGE sql
AS $$
SELECT CASE
WHEN (lugar IS NULL OR lugar = '') THEN
msip_ubicacionpre_dpa_nomenclatura(pais, departamento,
municipio, vereda, centropoblado)
WHEN (sitio IS NULL OR sitio= '') THEN
array[lugar || ' / ' ||
(msip_ubicacionpre_dpa_nomenclatura(pais, departamento,
municipio, vereda, centropoblado))[0],
lugar || ' / ' ||
(msip_ubicacionpre_dpa_nomenclatura(pais, departamento,
municipio, vereda, centropoblado))[1] ]
ELSE
array[sitio || ' / ' || lugar || ' / ' ||
(msip_ubicacionpre_dpa_nomenclatura(pais, departamento,
municipio, vereda, centropoblado))[0],
sitio || ' / ' || lugar || ' / ' ||
(msip_ubicacionpre_dpa_nomenclatura(pais, departamento,
municipio, vereda, centropoblado))[1] ]
END
$$;
--
-- Name: probapellido(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probapellido(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT sum(ppar) FROM (SELECT p, probcadap(p) AS ppar FROM (
SELECT p FROM divarr(string_to_array(trim($1), ' ')) AS p)
AS s) AS s2;
$_$;
--
-- Name: probcadap(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probcadap(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT CASE WHEN (SELECT SUM(frec) FROM napellidos)=0 THEN 0
WHEN (SELECT COUNT(*) FROM napellidos WHERE apellido=$1)=0 THEN 0
ELSE (SELECT frec/(SELECT SUM(frec) FROM napellidos)
FROM napellidos WHERE apellido=$1)
END
$_$;
--
-- Name: probcadh(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probcadh(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT CASE WHEN (SELECT SUM(frec) FROM nhombres)=0 THEN 0
WHEN (SELECT COUNT(*) FROM nhombres WHERE nombre=$1)=0 THEN 0
ELSE (SELECT frec/(SELECT SUM(frec) FROM nhombres)
FROM nhombres WHERE nombre=$1)
END
$_$;
--
-- Name: probcadm(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probcadm(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT CASE WHEN (SELECT SUM(frec) FROM nmujeres)=0 THEN 0
WHEN (SELECT COUNT(*) FROM nmujeres WHERE nombre=$1)=0 THEN 0
ELSE (SELECT frec/(SELECT SUM(frec) FROM nmujeres)
FROM nmujeres WHERE nombre=$1)
END
$_$;
--
-- Name: probhombre(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probhombre(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT sum(ppar) FROM (SELECT p, peso*probcadh(p) AS ppar FROM (
SELECT p, CASE WHEN rnum=1 THEN 100 ELSE 1 END AS peso
FROM (SELECT p, row_number() OVER () AS rnum FROM
divarr(string_to_array(trim($1), ' ')) AS p)
AS s) AS s2) AS s3;
$_$;
--
-- Name: probmujer(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.probmujer(in_text text) RETURNS numeric
LANGUAGE sql IMMUTABLE
AS $_$
SELECT sum(ppar) FROM (SELECT p, peso*probcadm(p) AS ppar FROM (
SELECT p, CASE WHEN rnum=1 THEN 100 ELSE 1 END AS peso
FROM (SELECT p, row_number() OVER () AS rnum FROM
divarr(string_to_array(trim($1), ' ')) AS p)
AS s) AS s2) AS s3;
$_$;
--
-- Name: rand(); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.rand() RETURNS double precision
LANGUAGE sql
AS $$SELECT random();$$;
--
-- Name: sivel2_gen_polo_id(integer); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.sivel2_gen_polo_id(presponsable_id integer) RETURNS integer
LANGUAGE sql
AS $$
WITH RECURSIVE des AS (
SELECT id, nombre, papa_id
FROM sivel2_gen_presponsable WHERE id=presponsable_id
UNION SELECT e.id, e.nombre, e.papa_id
FROM sivel2_gen_presponsable e INNER JOIN des d ON d.papa_id=e.id)
SELECT id FROM des WHERE papa_id IS NULL;
$$;
--
-- Name: sivel2_gen_polo_nombre(integer); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.sivel2_gen_polo_nombre(presponsable_id integer) RETURNS character varying
LANGUAGE sql
AS $$
SELECT CASE
WHEN fechadeshabilitacion IS NULL THEN nombre
ELSE nombre || '(DESHABILITADO)'
END
FROM sivel2_gen_presponsable
WHERE id=sivel2_gen_polo_id(presponsable_id)
$$;
--
-- Name: soundexesp(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.soundexesp(entrada text) RETURNS text
LANGUAGE plpgsql IMMUTABLE STRICT COST 500
AS $$
DECLARE
soundex text='';
-- para determinar la primera letra
pri_letra text;
resto text;
sustituida text ='';
-- para quitar adyacentes
anterior text;
actual text;
corregido text;
BEGIN
--raise notice 'entrada=%', entrada;
-- devolver null si recibi un string en blanco o con espacios en blanco
IF length(trim(entrada))= 0 then
RETURN NULL;
END IF;
-- 1: LIMPIEZA:
-- pasar a mayuscula, eliminar la letra "H" inicial, los acentos y la enie
-- 'holá coñó' => 'OLA CONO'
entrada=translate(ltrim(trim(upper(entrada)),'H'),'ÑÁÉÍÓÚÀÈÌÒÙÜ','NAEIOUAEIOUU');
IF array_upper(regexp_split_to_array(entrada, '[^a-zA-Z]'), 1) > 1 THEN
RAISE NOTICE 'Esta función sólo maneja una palabra y no ''%''. Use más bien soundexespm', entrada;
RETURN NULL;
END IF;
-- 2: PRIMERA LETRA ES IMPORTANTE, DEBO ASOCIAR LAS SIMILARES
-- 'vaca' se convierte en 'baca' y 'zapote' se convierte en 'sapote'
-- un fenomeno importante es GE y GI se vuelven JE y JI; CA se vuelve KA, etc
pri_letra =substr(entrada,1,1);
resto =substr(entrada,2);
CASE
when pri_letra IN ('V') then
sustituida='B';
when pri_letra IN ('Z','X') then
sustituida='S';
when pri_letra IN ('G') AND substr(entrada,2,1) IN ('E','I') then
sustituida='J';
when pri_letra IN('C') AND substr(entrada,2,1) NOT IN ('H','E','I') then
sustituida='K';
else
sustituida=pri_letra;
end case;
--corregir el parámetro con las consonantes sustituidas:
entrada=sustituida || resto;
--raise notice 'entrada tras cambios en primera letra %', entrada;
-- 3: corregir "letras compuestas" y volverlas una sola
entrada=REPLACE(entrada,'CH','V');
entrada=REPLACE(entrada,'QU','K');
entrada=REPLACE(entrada,'LL','J');
entrada=REPLACE(entrada,'CE','S');
entrada=REPLACE(entrada,'CI','S');
entrada=REPLACE(entrada,'YA','J');
entrada=REPLACE(entrada,'YE','J');
entrada=REPLACE(entrada,'YI','J');
entrada=REPLACE(entrada,'YO','J');
entrada=REPLACE(entrada,'YU','J');
entrada=REPLACE(entrada,'GE','J');
entrada=REPLACE(entrada,'GI','J');
entrada=REPLACE(entrada,'NY','N');
-- para debug: --return entrada;
--raise notice 'entrada tras cambiar letras compuestas %', entrada;
-- EMPIEZA EL CALCULO DEL SOUNDEX
-- 4: OBTENER PRIMERA letra
pri_letra=substr(entrada,1,1);
-- 5: retener el resto del string
resto=substr(entrada,2);
--6: en el resto del string, quitar vocales y vocales fonéticas
resto=translate(resto,'@AEIOUHWY','@');
--7: convertir las letras foneticamente equivalentes a numeros (esto hace que B sea equivalente a V, C con S y Z, etc.)
resto=translate(resto, 'BPFVCGKSXZDTLMNRQJ', '111122222233455677');
-- así va quedando la cosa
soundex=pri_letra || resto;
--8: eliminar números iguales adyacentes (A11233 se vuelve A123)
anterior=substr(soundex,1,1);
corregido=anterior;
FOR i IN 2 .. length(soundex) LOOP
actual = substr(soundex, i, 1);
IF actual <> anterior THEN
corregido=corregido || actual;
anterior=actual;
END IF;
END LOOP;
-- así va la cosa
soundex=corregido;
-- 9: siempre retornar un string de 4 posiciones
soundex=rpad(soundex,4,'0');
soundex=substr(soundex,1,4);
-- YA ESTUVO
RETURN soundex;
END;
$$;
--
-- Name: soundexespm(text); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.soundexespm(entrada text) RETURNS text
LANGUAGE plpgsql IMMUTABLE STRICT COST 500
AS $$
DECLARE
soundex text = '' ;
partes text[];
sep text = '';
se text = '';
BEGIN
entrada=translate(ltrim(trim(upper(entrada)),'H'),'ÑÁÉÍÓÚÀÈÌÒÙÜ','NAEIOUAEIOUU');
partes=regexp_split_to_array(entrada, '[^a-zA-Z]');
--raise notice 'partes=%', partes;
FOR i IN 1 .. array_upper(partes, 1) LOOP
se = soundexesp(partes[i]);
IF length(se) > 0 THEN
soundex = soundex || sep || se;
sep = ' ';
--raise notice 'i=% . soundexesp=%', i, se;
END IF;
END LOOP;
RETURN soundex;
END;
$$;
--
-- Name: substring_index(text, text, integer); Type: FUNCTION; Schema: public; Owner: -
--
CREATE FUNCTION public.substring_index(text, text, integer) RETURNS text
LANGUAGE sql
AS $_$SELECT array_to_string((string_to_array($1, $2)) [1:$3], $2);$_$;
--
-- Name: first(anyelement); Type: AGGREGATE; Schema: public; Owner: -
--
CREATE AGGREGATE public.first(anyelement) (
SFUNC = public.first_element_state,
STYPE = anyarray,
FINALFUNC = public.first_element
);
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: ar_internal_metadata; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.ar_internal_metadata (
key character varying NOT NULL,
value character varying,
created_at timestamp without time zone NOT NULL,
updated_at timestamp without time zone NOT NULL
);
--
-- Name: cor1440_gen_actividad; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad (
id integer NOT NULL,
minutos integer,
nombre character varying(500),
objetivo character varying(5000),
resultado character varying(5000),
fecha date NOT NULL,
observaciones character varying(5000),
created_at timestamp without time zone,
updated_at timestamp without time zone,
oficina_id integer NOT NULL,
usuario_id integer NOT NULL,
lugar character varying(500)
);
--
-- Name: cor1440_gen_actividad_actividadpf; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_actividadpf (
actividad_id integer NOT NULL,
actividadpf_id integer NOT NULL
);
--
-- Name: cor1440_gen_actividad_actividadtipo; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_actividadtipo (
actividad_id integer,
actividadtipo_id integer
);
--
-- Name: cor1440_gen_actividad_anexo_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE public.cor1440_gen_actividad_anexo_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: cor1440_gen_actividad_anexo; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_anexo (
actividad_id integer NOT NULL,
anexo_id integer NOT NULL,
id integer DEFAULT nextval('public.cor1440_gen_actividad_anexo_id_seq'::regclass) NOT NULL
);
--
-- Name: cor1440_gen_actividad_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE public.cor1440_gen_actividad_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: cor1440_gen_actividad_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE public.cor1440_gen_actividad_id_seq OWNED BY public.cor1440_gen_actividad.id;
--
-- Name: cor1440_gen_actividad_orgsocial; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_orgsocial (
actividad_id bigint NOT NULL,
orgsocial_id bigint NOT NULL
);
--
-- Name: cor1440_gen_actividad_proyecto; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_proyecto (
id integer NOT NULL,
actividad_id integer,
proyecto_id integer
);
--
-- Name: cor1440_gen_actividad_proyecto_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE public.cor1440_gen_actividad_proyecto_id_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: cor1440_gen_actividad_proyecto_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE public.cor1440_gen_actividad_proyecto_id_seq OWNED BY public.cor1440_gen_actividad_proyecto.id;
--
-- Name: cor1440_gen_actividad_proyectofinanciero_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE public.cor1440_gen_actividad_proyectofinanciero_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: cor1440_gen_actividad_proyectofinanciero; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_proyectofinanciero (
actividad_id integer NOT NULL,
proyectofinanciero_id integer NOT NULL,
id integer DEFAULT nextval('public.cor1440_gen_actividad_proyectofinanciero_id_seq'::regclass) NOT NULL
);
--
-- Name: cor1440_gen_actividad_rangoedadac; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_rangoedadac (
id integer NOT NULL,
actividad_id integer,
rangoedadac_id integer,
ml integer,
mr integer,
fl integer,
fr integer,
created_at timestamp without time zone,
updated_at timestamp without time zone,
s integer
);
--
-- Name: cor1440_gen_actividad_rangoedadac_id_seq; Type: SEQUENCE; Schema: public; Owner: -
--
CREATE SEQUENCE public.cor1440_gen_actividad_rangoedadac_id_seq
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
--
-- Name: cor1440_gen_actividad_rangoedadac_id_seq; Type: SEQUENCE OWNED BY; Schema: public; Owner: -
--
ALTER SEQUENCE public.cor1440_gen_actividad_rangoedadac_id_seq OWNED BY public.cor1440_gen_actividad_rangoedadac.id;
--
-- Name: cor1440_gen_actividad_respuestafor; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_respuestafor (
actividad_id integer NOT NULL,
respuestafor_id integer NOT NULL
);
--
-- Name: cor1440_gen_actividad_usuario; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividad_usuario (
actividad_id integer NOT NULL,
usuario_id integer NOT NULL
);
--
-- Name: cor1440_gen_actividadarea; Type: TABLE; Schema: public; Owner: -
--
CREATE TABLE public.cor1440_gen_actividadarea (
id integer NOT NULL,
nombre character varying(500),
observaciones character varying(5000),