forked from sjstoelting/pgsql-tweaks
-
Notifications
You must be signed in to change notification settings - Fork 0
/
help.html
2672 lines (2662 loc) · 115 KB
/
help.html
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
<div class="markdown-heading"><h1 class="heading-element">
<a href="https://www.postgresql.org" rel="nofollow">PostgreSQL</a> Views and Functions</h1><a id="user-content-postgresql-views-and-functions" class="anchor" aria-label="Permalink: PostgreSQL Views and Functions" href="#postgresql-views-and-functions"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The functions and views published in this repository are some of those, which I
regularly need in my daily job.</p>
<p>As these procedures are sort of essential, at least to me, I install them in the
public schema. That way they are available for everyone without having to know
a schema name.</p>
<p>All functions and views are covered by tests. The tests are done in simple SQL
statements. Each test does raise division by zero if it fails.</p>
<p>The tests have been done with PostgreSQL 12 up to 17.</p>
<p>All examples have been tested with PostgreSQL 17, differences in the behavior of previous versions are noted.</p>
<p><a href=""><img src="https://camo.githubusercontent.com/1042d1fc01ac97f78a8c307a3ee403e1eba45a812519c0290319e3b872b3ade1/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31322d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-12-blue.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/d2a89cd3f2051b2365b8b045ef9d3654181181b3abe1492d0399909e1509d747/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31332d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-13-blue.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/b2dd345d55c35062416aff03b72efd385599e03675909bdefb362d27c0d6e6bd/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31342d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-14-blue.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/2afe3e6dfa0535af3158334804ad3e1e6b09cfda81d51435d3f812fb05c62df1/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31352d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-15-blue.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/b6c9ddd95255ec3cbdf81d2069c3809387320b4f1489052dd8fba4544591ba33/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31362d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-16-blue.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/d4308dc0c9177c0ebe49205431eebc432e19f044dff1d87bc077e188fbdc9359/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f506f737467726553514c2d31372d626c75652e737667" alt="version" data-canonical-src="https://img.shields.io/badge/PostgreSQL-17-blue.svg" style="max-width: 100%;"></a></p>
<p><a href=""><img src="https://camo.githubusercontent.com/e0d0f6996fdf3cba78960efb62417ee001bcefd28e8b4eeef2f3b4d31dfc7700/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f4c616e67756167652d706c2f706753514c2d677265656e2e737667" alt="Lang" data-canonical-src="https://img.shields.io/badge/Language-pl/pgSQL-green.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/5eb31bac795fead9fbd57443292b5dfaeaaa49f08fd856d0254192c8803a279e/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f4c6963656e73652d506f737467726553514c2d677265656e2e737667" alt="PostgreSQL" data-canonical-src="https://img.shields.io/badge/License-PostgreSQL-green.svg" style="max-width: 100%;"></a>
<a href=""><img src="https://camo.githubusercontent.com/b09338ed28c485df31576dbdcd7c6da762ea2ee056e78f07f34642933e3a4198/68747470733a2f2f696d672e736869656c64732e696f2f62616467652f457874656e73696f6e2d506f737467726553514c2d677265656e2e737667" alt="Extension" data-canonical-src="https://img.shields.io/badge/Extension-PostgreSQL-green.svg" style="max-width: 100%;"></a></p>
<div class="markdown-heading"><h1 class="heading-element">Repositories</h1><a id="user-content-repositories" class="anchor" aria-label="Permalink: Repositories" href="#repositories"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The main repository is now on
<a href="https://gitlab.com/sjstoelting/pgsql-tweaks.git" rel="nofollow">GitLab</a>. A mirror will stay on <a href="https://github.com/sjstoelting/pgsql-tweaks">GitHub</a>.</p>
<p>If you discover any issue, please file them on
<a href="https://gitlab.com/sjstoelting/pgsql-tweaks/-/issues" rel="nofollow">https://gitlab.com/sjstoelting/pgsql-tweaks/-/issues</a>.</p>
<div class="markdown-heading"><h1 class="heading-element">Building the extension</h1><a id="user-content-building-the-extension" class="anchor" aria-label="Permalink: Building the extension" href="#building-the-extension"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>Each function and test is organized into its own separate file for easy management. The shell script <code>create_sql.sh</code> is responsible for assembling these files into the appropriate SQL scripts needed for extension creation.</p>
<div class="markdown-heading"><h2 class="heading-element">Configuration</h2><a id="user-content-configuration" class="anchor" aria-label="Permalink: Configuration" href="#configuration"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>Copy the example configuration file <code>build.cfg.example</code> to <code>build.cfg</code>.
Modify <code>build.cfg</code> to include the database connection information of your environment.</p>
<div class="markdown-heading"><h2 class="heading-element">Running the Script</h2><a id="user-content-running-the-script" class="anchor" aria-label="Permalink: Running the Script" href="#running-the-script"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The script automatically generates the necessary SQL scripts by combining the function and test files.
It is assumed that you have a <a href="https://www.postgresql.org/docs/current/static/libpq-pgpass.html" rel="nofollow"><code>.pgpass</code></a> file in your home directory, containing the database credentials matching the configuration. This file simplifies the login process during script execution.
Otherwise you have to login with credentials for each execution.</p>
<p>The test results are generated with messages and captions in your local language settings. In addition the <code>test/sql/out/pgsql-tweaks-test-[version number].out</code> file has timing on, you see the execution time for each test.</p>
<div class="markdown-heading"><h2 class="heading-element">Releasing</h2><a id="user-content-releasing" class="anchor" aria-label="Permalink: Releasing" href="#releasing"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The script accepts an optional argument to control whether a zip file for <a href="https://pgxn.org/" rel="nofollow">PGXN</a> (PostgreSQL Extension Network) is created. PGXN is also the prefered installation method.</p>
<p>You have to pass <code>'y'</code> as the first argument to the script. The language of the test results will be in English UTF8 en_EN.
In addition a zip archive is generated ready for submission to PGXN.</p>
<p>The <code>test/sql/out/pgsql-tweaks-test-[version number].out</code> file is generated without timing, otherwise the test results would not be comparable.</p>
<p>Example:</p>
<div class="highlight highlight-source-shell"><pre>./create_sql.sh y</pre></div>
<p>This will create a zip file of the extension in the <code>$HOME/tmp</code> directory with the pattern <code>pgsql-tweaks-[version number].zip</code>.
When the directory <code>$HOME/tmp</code> does not exist, it is created by the scirpt.
If no argument is provided, or if the argument is not <code>'y'</code>, the PGXN zip file is <strong>not</strong> created.</p>
<div class="markdown-heading"><h1 class="heading-element">Installation</h1><a id="user-content-installation" class="anchor" aria-label="Permalink: Installation" href="#installation"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>You may either, install all functions as a package, or install single functions of your choice.</p>
<div class="markdown-heading"><h2 class="heading-element">Install the package from source</h2><a id="user-content-install-the-package-from-source" class="anchor" aria-label="Permalink: Install the package from source" href="#install-the-package-from-source"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>Get the source by either, download the code as ZIP file, or by git clone.</p>
<div class="highlight highlight-source-shell"><pre><span class="pl-c1">cd</span> pgsql_tweaks
make install</pre></div>
<p>Afterwards you are able to create the extension in a database:</p>
<div class="highlight highlight-source-sql"><pre>CREATE EXTENSION pgsql_tweaks;</pre></div>
<div class="markdown-heading"><h2 class="heading-element">Install the package with PGXN</h2><a id="user-content-install-the-package-with-pgxn" class="anchor" aria-label="Permalink: Install the package with PGXN" href="#install-the-package-with-pgxn"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>pgsql_tweaks is now available over the PostgreSQL extension management, <a href="https://pgxn.org/dist/pgsql_tweaks/" rel="nofollow">PGXN</a>.</p>
<p>The installation is done with the PGXN installer and it is the prefered installation.</p>
<div class="highlight highlight-source-shell"><pre>pgxn install pgsql_tweaks</pre></div>
<p>Afterwards you are able to create the extension in a database:</p>
<div class="highlight highlight-source-sql"><pre>CREATE EXTENSION pgsql_tweaks;</pre></div>
<div class="markdown-heading"><h2 class="heading-element">Testing</h2><a id="user-content-testing" class="anchor" aria-label="Permalink: Testing" href="#testing"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>When your local language is not set LC_MESSAGES to en_EN, you have to execute the the test in the installation directory with an additional parameter to have comparable resutls.</p>
<div class="highlight highlight-source-shell"><pre>LC_MESSAGES=en_EN psql -f test/sql/out/pgsql-tweaks-[version number].sql <span class="pl-k">></span> pgsql-tweaks-test-[version number].out
diff pgsql-tweaks-[version number].out test/sql/out/pgsql-tweaks-test-[version number].out</pre></div>
<div class="markdown-heading"><h1 class="heading-element">Table of content</h1><a id="user-content-table-of-content" class="anchor" aria-label="Permalink: Table of content" href="#table-of-content"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>1 <a href="#user-content-list-of-functions">List of functions</a></p>
<p>1.1 <a href="#user-content-functions-to-check-data-types">Functions to check data types</a><br>
1.1.1 <a href="#user-content-function-is_date">FUNCTION is_date</a><br>
1.1.2 <a href="#user-content-function-is_time">FUNCTION is_time</a><br>
1.1.3 <a href="#user-content-function-is_timestamp">FUNCTION is_timestamp</a><br>
1.1.4 <a href="#user-content-function-is_real">FUNCTION is_real</a><br>
1.1.5 <a href="#user-content-function-is_double_precision">FUNCTION is_double_precision</a><br>
1.1.6 <a href="#user-content-function-is_numeric">FUNCTION is_numeric</a><br>
1.1.7 <a href="#user-content-function-is_bigint">FUNCTION is_bigint</a><br>
1.1.8 <a href="#user-content-function-is_integer">FUNCTION is_integer</a><br>
1.1.9 <a href="#user-content-function-is_smallint">FUNCTION is_smallint</a><br>
1.1.10 <a href="#user-content-function-is_boolean">FUNCTION is_boolean</a><br>
1.1.11 <a href="#user-content-function-is_json">FUNCTION is_json</a><br>
1.1.12 <a href="#user-content-function-is_jsonb">FUNCTION is_jsonb</a><br>
1.1.13 <a href="#user-content-function-is_empty-or-is_empty_b">FUNCTION is_empty or is_empty_b</a><br>
1.1.14 <a href="#user-content-function-is_hex">FUNCTION is_hex</a></p>
<p>1.2 <a href="#user-content-functions-about-encryption">Functions about encryption</a><br>
1.2.1 <a href="#user-content-function-sha256">FUNCTION sha256</a></p>
<p>1.3 <a href="#user-content-functions-and-views-to-get-extended-system-information">Functions and views to get extended system information</a><br>
1.3.1 <a href="#user-content-function-pg_schema_size">FUNCTION pg_schema_size</a><br>
1.3.2 <a href="#user-content-view-pg_db_views">VIEW pg_db_views</a><br>
1.3.3 <a href="#user-content-view-pg_foreign_keys">VIEW pg_foreign_keys</a><br>
1.3.4 <a href="#user-content-view-pg_functions">VIEW pg_functions</a><br>
1.3.4 <a href="#user-content-view-pg_active_locks">VIEW pg_active_locks</a><br>
1.3.5 <a href="#user-content-view-pg_table_matview_infos">VIEW pg_table_matview_infos</a><br>
1.3.6 <a href="#user-content-view-pg_object_ownership">VIEW pg_object_ownership</a><br>
1.3.7 <a href="#user-content-view-pg_partitioned_tables_infos">VIEW pg_partitioned_tables_infos</a></p>
<p>1.4 <a href="#user-content-functions-about-encodings">Functions about encodings</a><br>
1.4.1 <a href="#user-content-function-is_encoding">FUNCTION is_encoding</a><br>
1.4.2 <a href="#user-content-function-is_latin1">FUNCTION is_latin1</a><br>
1.4.3 <a href="#user-content-function-return_not_part_of_latin1">FUNCTION return_not_part_of_latin1</a><br>
1.4.4 <a href="#user-content-function-replace_latin1">FUNCTION replace_latin1</a><br>
1.4.4.1 <a href="#user-content-replace_latin1-s-text-">replace_latin1(s text)</a><br>
1.4.4.2 <a href="#user-content-replace_latin1-s-text-replacement-text-">replace_latin1(s text, replacement text)</a><br>
1.4.4.3 <a href="#user-content-replace_latin1-s-text-s_search-text-s_replace-text-">replace_latin1(s text, s_search text[], s_replace text[])</a><br>
1.4.5 <a href="#user-content-function-return_not_part_of_encoding">FUNCTION return_not_part_of_encoding</a><br>
1.4.6 <a href="#user-content-function-replace_encoding">FUNCTION replace_encoding</a><br>
1.4.6.1 <a href="#user-content-replace_encoding-s-text-e-text-">replace_encoding(s text, e text)</a><br>
1.4.6.2 <a href="#user-content-replace_encoding-s-text-e-text-replacement-text-">replace_encoding(s text, e text, replacement text)</a><br>
1.4.6.3 <a href="#user-content-replace_encoding-s-text-s_search-text-s_replace-text-">replace_encoding(s text, s_search text[], s_replace text[])</a></p>
<p>1.5 <a href="#user-content-user-defined-aggregates">User defined aggregates</a><br>
1.5.1 <a href="#user-content-aggregate-gap_fill">AGGREGATE gap_fill</a><br>
1.5.2 <a href="#user-content-aggregate-array_min">AGGREGATE array_min</a><br>
1.5.3 <a href="#user-content-aggregate-array_max">AGGREGATE array_max</a><br>
1.5.4 <a href="#user-content-aggregate-array_avg">AGGREGATE array_avg</a><br>
1.5.5 <a href="#user-content-aggregate-array_sum">AGGREGATE array_sum</a></p>
<p>1.6 <a href="#user-content-format-functions">Format functions</a><br>
1.6.1 <a href="#user-content-function-date_de">FUNCTION date_de</a><br>
1.6.2 <a href="#user-content-function-datetime_de">FUNCTION datetime_de</a></p>
<p>1.7 <a href="#user-content-conversion-functions">Conversion functions</a><br>
1.7.1 <a href="#user-content-function-to_unix_timestamp">FUNCTION to_unix_timestamp</a><br>
1.7.2 <a href="#user-content-function-hex2bigint">FUNCTION hex2bigint</a></p>
<p>1.8 <a href="#user-content-other-functions">Other functions</a><br>
1.8.1 <a href="#user-content-function-array_trim">FUNCTION array_trim</a></p>
<div class="markdown-heading"><h1 class="heading-element">List of functions</h1><a id="user-content-list-of-functions" class="anchor" aria-label="Permalink: List of functions" href="#list-of-functions"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="markdown-heading"><h2 class="heading-element">Functions to check data types</h2><a id="user-content-functions-to-check-data-types" class="anchor" aria-label="Permalink: Functions to check data types" href="#functions-to-check-data-types"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_date</h3><a id="user-content-function-is_date" class="anchor" aria-label="Permalink: FUNCTION is_date" href="#function-is_date"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being a date.<br>
You might pass a second parameter to use a format string. Without the format,
the default format of PostgreSQL is used.</p>
<p>There has been a behaviour change in PostgreSQL 10. A conversion is now handled
strict, as in previous versions the conversion tried to calculate dates.</p>
<div class="markdown-heading"><h4 class="heading-element">Example PostgreSQL < 10</h4><a id="user-content-example-postgresql--10" class="anchor" aria-label="Permalink: Example PostgreSQL < 10" href="#example-postgresql--10"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_date(<span class="pl-s"><span class="pl-pds">'</span>31.02.2018<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true because the conversion would return a valid result for</span>
<span class="pl-k">SELECT</span> to_date(<span class="pl-s"><span class="pl-pds">'</span>31.02.2018<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY<span class="pl-pds">'</span></span>);</pre></div>
<p>Result PostgreSQL 9.6 and previous versions:</p>
<table>
<thead>
<tr>
<th>to_date</th>
</tr>
</thead>
<tbody>
<tr>
<td>2018-03-03</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples" class="anchor" aria-label="Permalink: Examples" href="#examples"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is in PostgreSQL default format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_date(<span class="pl-s"><span class="pl-pds">'</span>2018-01-01<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_date(<span class="pl-s"><span class="pl-pds">'</span>2018-02-31<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is in PostgreSQL German format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_date(<span class="pl-s"><span class="pl-pds">'</span>01.01.2018<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_date(<span class="pl-s"><span class="pl-pds">'</span>31.02.2018<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_time</h3><a id="user-content-function-is_time" class="anchor" aria-label="Permalink: FUNCTION is_time" href="#function-is_time"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being a time.<br>
You might pass a second parameter to use a format string. Without the format,
the default format of PostgreSQL is used.</p>
<p>There has been a behaviour change in PostgreSQL 10. A conversion is now handled
strict, as in previous versions the conversion tried to calculate time.</p>
<div class="markdown-heading"><h4 class="heading-element">Example PostgreSQL < 10</h4><a id="user-content-example-postgresql--10-1" class="anchor" aria-label="Permalink: Example PostgreSQL < 10" href="#example-postgresql--10-1"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_time(<span class="pl-s"><span class="pl-pds">'</span>25.33.55,456574<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>HH24.MI.SS,US<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true because the conversion would return a valid result for</span>
<span class="pl-k">SELECT</span> to_timestamp(<span class="pl-s"><span class="pl-pds">'</span>25.33.55,456574<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>HH24.MI.SS,US<span class="pl-pds">'</span></span>)::<span class="pl-k">TIME</span>;</pre></div>
<p>Result PostgreSQL 9.6 and previous versions:</p>
<table>
<thead>
<tr>
<th>to_timestamp</th>
</tr>
</thead>
<tbody>
<tr>
<td>01:33:55.456574</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-1" class="anchor" aria-label="Permalink: Examples" href="#examples-1"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is in PostgreSQL default format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_time(<span class="pl-s"><span class="pl-pds">'</span>14:33:55.456574<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_time(<span class="pl-s"><span class="pl-pds">'</span>25:33:55.456574<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is some time format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_time(<span class="pl-s"><span class="pl-pds">'</span>14.33.55,456574<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>HH24.MI.SS,US<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_time(<span class="pl-s"><span class="pl-pds">'</span>25.33.55,456574<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>HH24.MI.SS,US<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_timestamp</h3><a id="user-content-function-is_timestamp" class="anchor" aria-label="Permalink: FUNCTION is_timestamp" href="#function-is_timestamp"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being a timestamp.<br>
You might pass a second parameter to use a format string. Without the format,
the default format of PostgreSQL is used.</p>
<p>There has been a behaviour change in PostgreSQL 10. A conversion is now handled
strict, as in previous versions the conversion tried to calculate a date.</p>
<div class="markdown-heading"><h4 class="heading-element">Example PostgreSQL < 10</h4><a id="user-content-example-postgresql--10-2" class="anchor" aria-label="Permalink: Example PostgreSQL < 10" href="#example-postgresql--10-2"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_timestamp(<span class="pl-s"><span class="pl-pds">'</span>2018-01-01 25:00:00<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true because the conversion would return a valid result for</span>
<span class="pl-k">SELECT</span> to_timestamp(<span class="pl-s"><span class="pl-pds">'</span>01.01.2018 25:00:00<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY HH24.MI.SS<span class="pl-pds">'</span></span>)::<span class="pl-k">TIMESTAMP</span>;</pre></div>
<p>Result PostgreSQL 9.6 and previous versions:</p>
<table>
<thead>
<tr>
<th>to_timestamp</th>
</tr>
</thead>
<tbody>
<tr>
<td>2018-01-02 01:00:00</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-2" class="anchor" aria-label="Permalink: Examples" href="#examples-2"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is in PostgreSQL default format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_timestamp(<span class="pl-s"><span class="pl-pds">'</span>2018-01-01 00:00:00<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_timestamp(<span class="pl-s"><span class="pl-pds">'</span>2018-01-01 25:00:00<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false in PostgreSQL >= 10</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">/*</span>*</span>
<span class="pl-c"> * Parameter is in PostgreSQL German format</span>
<span class="pl-c"> <span class="pl-c">*/</span></span>
<span class="pl-k">SELECT</span> is_timestamp(<span class="pl-s"><span class="pl-pds">'</span>01.01.2018 00:00:00<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY HH24.MI.SS<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_timestamp(<span class="pl-s"><span class="pl-pds">'</span>01.01.2018 25:00:00<span class="pl-pds">'</span></span>, <span class="pl-s"><span class="pl-pds">'</span>DD.MM.YYYY HH24.MI.SS<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_real</h3><a id="user-content-function-is_real" class="anchor" aria-label="Permalink: FUNCTION is_real" href="#function-is_real"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type REAL.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-3" class="anchor" aria-label="Permalink: Examples" href="#examples-3"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_real(<span class="pl-s"><span class="pl-pds">'</span>123.456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_real(<span class="pl-s"><span class="pl-pds">'</span>123,456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_double_precision</h3><a id="user-content-function-is_double_precision" class="anchor" aria-label="Permalink: FUNCTION is_double_precision" href="#function-is_double_precision"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type DOUBLE PRECISION.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-4" class="anchor" aria-label="Permalink: Examples" href="#examples-4"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_double_precision(<span class="pl-s"><span class="pl-pds">'</span>123.456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_double_precision(<span class="pl-s"><span class="pl-pds">'</span>123,456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_numeric</h3><a id="user-content-function-is_numeric" class="anchor" aria-label="Permalink: FUNCTION is_numeric" href="#function-is_numeric"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type NUMERIC.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-5" class="anchor" aria-label="Permalink: Examples" href="#examples-5"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_numeric(<span class="pl-s"><span class="pl-pds">'</span>123<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_numeric(<span class="pl-s"><span class="pl-pds">'</span>1 2<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_bigint</h3><a id="user-content-function-is_bigint" class="anchor" aria-label="Permalink: FUNCTION is_bigint" href="#function-is_bigint"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type BIGINT.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-6" class="anchor" aria-label="Permalink: Examples" href="#examples-6"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_bigint(<span class="pl-s"><span class="pl-pds">'</span>3243546343<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_bigint(<span class="pl-s"><span class="pl-pds">'</span>123.456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_integer</h3><a id="user-content-function-is_integer" class="anchor" aria-label="Permalink: FUNCTION is_integer" href="#function-is_integer"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type INTEGER.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-7" class="anchor" aria-label="Permalink: Examples" href="#examples-7"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_integer(<span class="pl-s"><span class="pl-pds">'</span>123<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_integer(<span class="pl-s"><span class="pl-pds">'</span>123.456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_smallint</h3><a id="user-content-function-is_smallint" class="anchor" aria-label="Permalink: FUNCTION is_smallint" href="#function-is_smallint"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks strings for being of data type SMALLINT.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-8" class="anchor" aria-label="Permalink: Examples" href="#examples-8"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_smallint(<span class="pl-s"><span class="pl-pds">'</span>123<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_smallint(<span class="pl-s"><span class="pl-pds">'</span>123.456<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_boolean</h3><a id="user-content-function-is_boolean" class="anchor" aria-label="Permalink: FUNCTION is_boolean" href="#function-is_boolean"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks a string variable for containing valid BOOLEAN values.</p>
<table>
<thead>
<tr>
<th>boolean strings</th>
</tr>
</thead>
<tbody>
<tr>
<td>t</td>
</tr>
<tr>
<td>f</td>
</tr>
<tr>
<td>T</td>
</tr>
<tr>
<td>F</td>
</tr>
<tr>
<td>y</td>
</tr>
<tr>
<td>n</td>
</tr>
<tr>
<td>Y</td>
</tr>
<tr>
<td>N</td>
</tr>
<tr>
<td>true</td>
</tr>
<tr>
<td>false</td>
</tr>
<tr>
<td>TRUE</td>
</tr>
<tr>
<td>FALSE</td>
</tr>
<tr>
<td>yes</td>
</tr>
<tr>
<td>no</td>
</tr>
<tr>
<td>YES</td>
</tr>
<tr>
<td>NO</td>
</tr>
<tr>
<td>0</td>
</tr>
<tr>
<td>1</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-9" class="anchor" aria-label="Permalink: Examples" href="#examples-9"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>t<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>F<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>True<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>False<span class="pl-pds">'</span></span>);
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>0<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>1<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_boolean(<span class="pl-s"><span class="pl-pds">'</span>-1<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_json</h3><a id="user-content-function-is_json" class="anchor" aria-label="Permalink: FUNCTION is_json" href="#function-is_json"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks a string variable for containing a valid JSON.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-10" class="anchor" aria-label="Permalink: Examples" href="#examples-10"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_json(<span class="pl-s"><span class="pl-pds">'</span>{"review": {"date": "1970-12-30", "votes": 10, "rating": 5, "helpful_votes": 0}, "product": {"id": "1551803542", "group": "Book", "title": "Start and Run a Coffee Bar (Start & Run a)", "category": "Business & Investing", "sales_rank": 11611, "similar_ids": ["0471136174", "0910627312", "047112138X", "0786883561", "0201570483"], "subcategory": "General"}, "customer_id": "AE22YDHSBFYIP"}<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_json(<span class="pl-s"><span class="pl-pds">'</span>Not a JSON<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_jsonb</h3><a id="user-content-function-is_jsonb" class="anchor" aria-label="Permalink: FUNCTION is_jsonb" href="#function-is_jsonb"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks a string variable for containing a valid JSONB.</p>
<div class="markdown-heading"><h4 class="heading-element">Example</h4><a id="user-content-example" class="anchor" aria-label="Permalink: Example" href="#example"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_jsonb(<span class="pl-s"><span class="pl-pds">'</span>{"review": {"date": "1970-12-30", "votes": 10, "rating": 5, "helpful_votes": 0}, "product": {"id": "1551803542", "group": "Book", "title": "Start and Run a Coffee Bar (Start & Run a)", "category": "Business & Investing", "sales_rank": 11611, "similar_ids": ["0471136174", "0910627312", "047112138X", "0786883561", "0201570483"], "subcategory": "General"}, "customer_id": "AE22YDHSBFYIP"}<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_jsonb(<span class="pl-s"><span class="pl-pds">'</span>Not a JSONB<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_empty or is_empty_b</h3><a id="user-content-function-is_empty-or-is_empty_b" class="anchor" aria-label="Permalink: FUNCTION is_empty or is_empty_b" href="#function-is_empty-or-is_empty_b"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks a string variable for being either, NULL or '' and is returing a boolean result.</p>
<p>The extension <a href="https://pgtap.org/" rel="nofollow">pgtap</a> has the same name for a function with the same purpose, but a different returning value.<br>
Therefore the function name differs, if pgtap is installed.</p>
<p>The function <strong>is_empty</strong>, when pgtap is not installed.</p>
<p>The function <strong>is_empty_b</strong>, when pgtap is not installed. The <strong>b</strong> stands for its boolean result.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-11" class="anchor" aria-label="Permalink: Examples" href="#examples-11"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_empty(<span class="pl-s"><span class="pl-pds">'</span>abc<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_empty(<span class="pl-s"><span class="pl-pds">'</span><span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_empty(<span class="pl-k">NULL</span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION is_hex</h3><a id="user-content-function-is_hex" class="anchor" aria-label="Permalink: FUNCTION is_hex" href="#function-is_hex"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function checks a string variable for being a hexadecimal number being a
bigint.</p>
<p>❗<span>This function needs to have
hex2bigint being installed!</span>❗</p>
<p>If you use the package, both functions are installed in the correct sort order.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-12" class="anchor" aria-label="Permalink: Examples" href="#examples-12"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_hex(<span class="pl-s"><span class="pl-pds">'</span>a1b0<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is true</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">t</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_hex(<span class="pl-s"><span class="pl-pds">'</span>a1b0w<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> is_hex(<span class="pl-s"><span class="pl-pds">'</span>a1b0c3c3c3c4b5d3<span class="pl-pds">'</span></span>) <span class="pl-k">AS</span> res;
<span class="pl-c"><span class="pl-c">--</span> Result is false (does not fit into a bigint)</span></pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">f</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h2 class="heading-element">Functions about encryption</h2><a id="user-content-functions-about-encryption" class="anchor" aria-label="Permalink: Functions about encryption" href="#functions-about-encryption"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION sha256</h3><a id="user-content-function-sha256" class="anchor" aria-label="Permalink: FUNCTION sha256" href="#function-sha256"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>Creates a function which returns a SHA256 hash for the given string.<br>
The parameter has to be converted into a binary string of <a href="https://www.postgresql.org/docs/current/static/datatype-binary.html" rel="nofollow">bytea</a>.
:heavy_exclamation_mark:<span>The function needs the <a href="https://www.postgresql.org/docs/current/static/pgcrypto.html" rel="nofollow">pgcrypto</a> package</span>❗</p>
<p>❗This function has an external dependency and is only installed, if the package pgcrypto is installed❗</p>
<div class="markdown-heading"><h4 class="heading-element">Example</h4><a id="user-content-example-1" class="anchor" aria-label="Permalink: Example" href="#example-1"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> sha256(<span class="pl-s"><span class="pl-pds">'</span>test-string<span class="pl-pds">'</span></span>::<span class="pl-k">bytea</span>) <span class="pl-k">AS</span> res;</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="center">res</th>
</tr>
</thead>
<tbody>
<tr>
<td align="center">ffe65f1d98fafedea3514adc956c8ada5980c6c5d2552fd61f48401aefd5c00e</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h2 class="heading-element">Functions and views to get extended system information</h2><a id="user-content-functions-and-views-to-get-extended-system-information" class="anchor" aria-label="Permalink: Functions and views to get extended system information" href="#functions-and-views-to-get-extended-system-information"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="markdown-heading"><h3 class="heading-element">FUNCTION pg_schema_size</h3><a id="user-content-function-pg_schema_size" class="anchor" aria-label="Permalink: FUNCTION pg_schema_size" href="#function-pg_schema_size"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>The function returns the size for schema given as parameter in bytes.</p>
<div class="markdown-heading"><h4 class="heading-element">Examples</h4><a id="user-content-examples-13" class="anchor" aria-label="Permalink: Examples" href="#examples-13"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">--</span> Returns the size of the schema public in bytes</span>
<span class="pl-k">SELECT</span> pg_schema_size(<span class="pl-s"><span class="pl-pds">'</span>public<span class="pl-pds">'</span></span>);</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="right">pg_schema_size</th>
</tr>
</thead>
<tbody>
<tr>
<td align="right">348536832</td>
</tr>
</tbody>
</table>
<div class="highlight highlight-source-sql"><pre><span class="pl-c"><span class="pl-c">--</span> Returns the size of the schema public formatted</span>
<span class="pl-k">SELECT</span> pg_size_pretty(pg_schema_size(<span class="pl-s"><span class="pl-pds">'</span>public<span class="pl-pds">'</span></span>));</pre></div>
<p>Result:</p>
<table>
<thead>
<tr>
<th align="right">pg_schema_size</th>
</tr>
</thead>
<tbody>
<tr>
<td align="right">332 MB</td>
</tr>
</tbody>
</table>
<div class="markdown-heading"><h3 class="heading-element">VIEW pg_db_views</h3><a id="user-content-view-pg_db_views" class="anchor" aria-label="Permalink: VIEW pg_db_views" href="#view-pg_db_views"><span aria-hidden="true" class="octicon octicon-link"></span></a></div>
<p>Creates a view to get all views of the current database but excluding system views and all views which do start with "pg" or "_pg".</p>
<div class="highlight highlight-source-sql"><pre><span class="pl-k">SELECT</span> <span class="pl-k">*</span>
<span class="pl-k">FROM</span> pg_db_views;</pre></div>
<table>
<thead>
<tr>
<th>view_catalog</th>
<th>view_schema</th>
<th>view_name</th>
<th>view_definition</th>
</tr>
</thead>
<tbody>
<tr>
<td>chinook</td>
<td>public</td>
<td>v_json_artist_data</td>
<td>WITH tracks AS (</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>SELECT "Track"."AlbumId" AS album_id,</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>"Track"."TrackId" AS track_id,</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>"Track"."Name" AS track_name,</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>"Track"."MediaTypeId" AS media_type_id,</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>"Track"."Milliseconds" AS milliseconds,</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>
<td>"Track"."UnitPrice" AS unit_price</td>
</tr>
<tr>
<td></td>
<td></td>
<td></td>