File: README.md

package info (click to toggle)
plpgsql-check 2.8.8-1
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid
  • size: 2,520 kB
  • sloc: ansic: 14,262; sql: 5,504; makefile: 24; python: 7; sh: 2
file content (1024 lines) | stat: -rw-r--r-- 49,385 bytes parent folder | download | duplicates (2)
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
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
[![Stand With Ukraine](https://raw.githubusercontent.com/vshymanskyy/StandWithUkraine/main/banner2-direct.svg)](https://stand-with-ukraine.pp.ua)

plpgsql_check
=============

This extension is a full linter for plpgsql for PostgreSQL.  It leverages only the internal 
PostgreSQL parser/evaluator so you see exactly the errors would occur at runtime.
Furthermore, it parses the SQL inside your routines and finds errors not usually found during
the "CREATE PROCEDURE/FUNCTION" command.  You can control the levels of many warnings and hints.
Finally, you can add PRAGMA type markers to turn off/on many aspects allowing you to hide
messages you already know about, or to remind you to come back for deeper cleaning later.

I founded this project, because I wanted to publish the code I wrote for the  two years,
when I tried to write enhanced checking for PostgreSQL upstream. It was not fully
successful - integration into upstream requires some larger plpgsql refactoring.
But the code is fully functional and can be used in production (and it is used in production).
So, I created this extension to be available for all plpgsql developers.

If if you want to join our group to help the further development of this extension, register
yourself at that [postgresql extension hacking](https://groups.google.com/forum/#!forum/postgresql-extensions-hacking)
google group.

# Features

* checks fields of referenced database objects and types inside embedded SQL
* validates you are using the correct types for function parameters
* identifies unused variables and function arguments, unmodified OUT arguments
* partial detection of dead code (code after an RETURN command)
* detection of missing RETURN command in function (common after exception handlers, complex logic)
* tries to identify unwanted hidden casts, which can be a performance issue like unused indexes
* ability to collect relations and functions used by function
* ability to check EXECUTE statements against SQL injection vulnerability

I invite any ideas, patches, bugreports.

PostgreSQL PostgreSQL 14 - 18 are supported.

The SQL statements inside PL/pgSQL functions are checked by the validator for semantic errors. These errors
can be found by calling the plpgsql_check_function:

# Active mode

    postgres=# CREATE EXTENSION plpgsql_check;
    LOAD
    postgres=# CREATE TABLE t1(a int, b int);
    CREATE TABLE

    postgres=#
    CREATE OR REPLACE FUNCTION public.f1()
    RETURNS void
    LANGUAGE plpgsql
    AS $function$
    DECLARE r record;
    BEGIN
      FOR r IN SELECT * FROM t1
      LOOP
        RAISE NOTICE '%', r.c; -- there is bug - table t1 missing "c" column
      END LOOP;
    END;
    $function$;

    CREATE FUNCTION

    postgres=# select f1(); -- execution doesn't find a bug due to empty table t1
      f1 
     ────
       
     (1 row)

    postgres=# \x
    Expanded display is on.
    postgres=# select * from plpgsql_check_function_tb('f1()');
    ─[ RECORD 1 ]───────────────────────────
    functionid │ f1
    lineno     │ 6
    statement  │ RAISE
    sqlstate   │ 42703
    message    │ record "r" has no field "c"
    detail     │ [null]
    hint       │ [null]
    level      │ error
    position   │ 0
    query      │ [null]

    postgres=# \sf+ f1
        CREATE OR REPLACE FUNCTION public.f1()
         RETURNS void
         LANGUAGE plpgsql
    1       AS $function$
    2       DECLARE r record;
    3       BEGIN
    4         FOR r IN SELECT * FROM t1
    5         LOOP
    6           RAISE NOTICE '%', r.c; -- there is bug - table t1 missing "c" column
    7         END LOOP;
    8       END;
    9       $function$


Function plpgsql_check_function() has three possible output formats: text, json or xml

    select * from plpgsql_check_function('f1()', fatal_errors := false);
                             plpgsql_check_function                         
    ------------------------------------------------------------------------
     error:42703:4:SQL statement:column "c" of relation "t1" does not exist
     Query: update t1 set c = 30
     --                   ^
     error:42P01:7:RAISE:missing FROM-clause entry for table "r"
     Query: SELECT r.c
     --            ^
     error:42601:7:RAISE:too few parameters specified for RAISE
    (7 rows)

    postgres=# select * from plpgsql_check_function('fx()', format:='xml');
                     plpgsql_check_function                     
    ────────────────────────────────────────────────────────────────
     <Function oid="16400">                                        ↵
       <Issue>                                                     ↵
         <Level>error</level>                                      ↵
         <Sqlstate>42P01</Sqlstate>                                ↵
         <Message>relation "foo111" does not exist</Message>       ↵
         <Stmt lineno="3">RETURN</Stmt>                            ↵
         <Query position="23">SELECT (select a from foo111)</Query>↵
       </Issue>                                                    ↵
      </Function>
     (1 row)

## Arguments

You can set level of warnings via function's parameters:
            
### Mandatory argument

* `funcoid oid` - function name or function signature - functions require a function specification.
  Any function in PostgreSQL can be specified by Oid or by name or by signature. When
  you know oid or complete function's signature, you can use a regprocedure type parameter
  like `'fx()'::regprocedure` or `16799::regprocedure`. Possible alternative is using
  a name only, when function's name is unique - like `'fx'`. When the name is not unique
  or the function doesn't exists it raises a error.

### Optional arguments

* `relid DEFAULT 0` - oid of relation assigned with trigger function. It is necessary to check
   any trigger function.  You are sending the table in that the trigger operates on.

* `fatal_errors boolean DEFAULT true` - stop on first error (prevents massive error reports)

* `other_warnings boolean DEFAULT true` - show warnings like different attributes number
  in assignmenet on left and right side, variable overlaps function's parameter, unused
  variables, unwanted casting, etc.

* `extra_warnings boolean DEFAULT true` - show warnings like missing `RETURN`,
  shadowed variables, dead code, never read (unused) function's parameter,
  unmodified variables, modified auto variables, etc.

* `performance_warnings boolean DEFAULT false` - performance related warnings like
  declared type with type modifier, casting, implicit casts in where clause (can be
  the reason why an index is not used), etc.

* `security_warnings boolean DEFAULT false` - security related checks like SQL injection
  vulnerability detection

* `compatibility_warnings boolean DEFAULT false` - compatibility related checks like obsolete explicit
  setting internal cursor names in refcursor's or cursor's variables.

* `anyelementtype regtype DEFAULT 'int'` - an actual type to be used when testing the anyelement type

* `anyenumtype regtype DEFAULT '-'` - an actual type to be used when testing the anyenum type

* `anyrangetype regtype DEFAULT 'int4range'` - an actual type to be used when testing the anyrange type

* `anycompatibletype DEFAULT 'int'` - an actual type to be used when testing the anycompatible type

* `anycompatiblerangetype DEFAULT 'int4range'` - an actual range type to be used when testing the anycompatible range type

* `without_warnings DEFAULT false` - disable all warnings (Ignores all xxxx_warning parameters, a quick override)

* `all_warnings DEFAULT false` - enable all warnings (Ignores other xxx_warning parameters, a quick positive)

* `newtable DEFAULT NULL`, `oldtable DEFAULT NULL` - the names of NEW or OLD transition
   tables. These parameters are required when transition tables are used in trigger functions.

* `use_incomment_options DEFAULT true` - when it is true, then in-comment options are active

* `incomment_options_usage_warning DEFAULT false` - when it is true, then the warning is raised when
   in-comment option is used.

* `constant_tracing boolean DEFAULT true` - when it is true, then the variable that holds
   some constant content, can be used like constant (it is work only in some simple cases,
   and the content of variable should not be ambigonuous).

## Triggers

When you want to check any trigger, you have to enter a relation that will be
used together with trigger function

    CREATE TABLE bar(a int, b int);

    postgres=# \sf+ foo_trg
        CREATE OR REPLACE FUNCTION public.foo_trg()
             RETURNS trigger
             LANGUAGE plpgsql
    1       AS $function$
    2       BEGIN
    3         NEW.c := NEW.a + NEW.b;
    4         RETURN NEW;
    5       END;
    6       $function$

Missing relation specification

    postgres=# select * from plpgsql_check_function('foo_trg()');
    ERROR:  missing trigger relation
    HINT:  Trigger relation oid must be valid

Correct trigger checking (with specified relation)

    postgres=# select * from plpgsql_check_function('foo_trg()', 'bar');
                     plpgsql_check_function                 
    --------------------------------------------------------
     error:42703:3:assignment:record "new" has no field "c"
    (1 row)

For triggers with transitive tables you can set the `oldtable` and `newtable` parameters:

    create or replace function footab_trig_func()
    returns trigger as $$
    declare x int;
    begin
      if false then
        -- should be ok;
        select count(*) from newtab into x; 

        -- should fail;
        select count(*) from newtab where d = 10 into x;
      end if;
      return null;
    end;
    $$ language plpgsql;

    select * from plpgsql_check_function('footab_trig_func','footab', newtable := 'newtab');


## In-comment options

plpgsql_check allows persistent setting written in comments. These options are taken from
function's source code before checking. The syntax is:

    @plpgsql_check_option: optioname [=] value [, optname [=] value ...]

The settings from comment options has top high priority, but generally it can be disabled
by option `use_incomment_options` to `false`.

Example:

    create or replace function fx(anyelement)
    returns text as $$
    begin
      /*
       * rewrite default polymorphic type to text
       * @plpgsql_check_options: anyelementtype = text
       */
      return $1;
    end;
    $$ language plpgsql;


## Checking all of your code

You can use the plpgsql_check_function for mass checking of functions/procedures and mass checking
of triggers. Please, test following queries:

    -- check all nontrigger plpgsql functions
    SELECT p.oid, p.proname, plpgsql_check_function(p.oid)
       FROM pg_catalog.pg_namespace n
       JOIN pg_catalog.pg_proc p ON pronamespace = n.oid
       JOIN pg_catalog.pg_language l ON p.prolang = l.oid
      WHERE l.lanname = 'plpgsql' AND p.prorettype <> 2279;

or

    -- check all trigger plpgsql functions
    SELECT p.proname, tgrelid::regclass, cf.*
       FROM pg_proc p
            JOIN pg_trigger t ON t.tgfoid = p.oid 
            JOIN pg_language l ON p.prolang = l.oid
            JOIN pg_namespace n ON p.pronamespace = n.oid,
            LATERAL plpgsql_check_function(p.oid, t.tgrelid, oldtable=>t.tgoldtable, newtable=>t.tgnewtable) cf
      WHERE n.nspname = 'public' and l.lanname = 'plpgsql';

or

    -- check all plpgsql functions (functions or trigger functions with defined triggers)
    SELECT
        (pcf).functionid::regprocedure, (pcf).lineno, (pcf).statement,
        (pcf).sqlstate, (pcf).message, (pcf).detail, (pcf).hint, (pcf).level,
        (pcf)."position", (pcf).query, (pcf).context
    FROM
    (
        SELECT
            plpgsql_check_function_tb(pg_proc.oid, COALESCE(pg_trigger.tgrelid, 0),
                                      oldtable=>pg_trigger.tgoldtable,
                                      newtable=>pg_trigger.tgnewtable) AS pcf
        FROM pg_proc
        LEFT JOIN pg_trigger
            ON (pg_trigger.tgfoid = pg_proc.oid)
        WHERE
            prolang = (SELECT lang.oid FROM pg_language lang WHERE lang.lanname = 'plpgsql') AND
            pronamespace <> (SELECT nsp.oid FROM pg_namespace nsp WHERE nsp.nspname = 'pg_catalog') AND
            -- ignore unused triggers
            (pg_proc.prorettype <> (SELECT typ.oid FROM pg_type typ WHERE typ.typname = 'trigger') OR
             pg_trigger.tgfoid IS NOT NULL)
        OFFSET 0
    ) ss
    ORDER BY (pcf).functionid::regprocedure::text, (pcf).lineno;

# Passive mode (only recommended for development or preproduction)

Functions can be checked upon execution - plpgsql_check module must be loaded (via postgresql.conf).

## Configuration Settings

    plpgsql_check.mode = [ disabled | by_function | fresh_start | every_start ]
    plpgsql_check.fatal_errors = [ yes | no ]

    plpgsql_check.show_nonperformance_warnings = false
    plpgsql_check.show_performance_warnings = false

Default mode is <i>by_function</i>, that means that the enhanced check is done only in
active mode - by calling the <i>plpgsql_check_function</i>. `fresh_start` means cold start (first the function is called).

You can enable passive mode by

    load 'plpgsql'; -- 1.1 and higher doesn't need it
    load 'plpgsql_check';
    set plpgsql_check.mode = 'every_start';  -- This scans all code before it is executed

    SELECT fx(10); -- run functions - function is checked before runtime starts it

# Compatibility warnings

## Assigning string to refcursor variable

PostgreSQL cursor's and refcursor's variables are enhanced string variables that holds
unique name of related portal (internal structure of Postgres that is used for cursor's
implementation). Until PostgreSQL 16, the the portal had same name like name of cursor
variable. PostgreSQL 16 and higher change this mechanism and by default related portal
will be named by some unique name. It solves some issues with cursors in nested blocks
or when cursor is used in recursive called function.

With mentioned change, the refcursor's variable should to take value from another
refcursor variable or from some cursor variable (when cursor is opened).

    -- obsolete pattern
    DECLARE
      cur CURSOR FOR SELECT 1;
      rcur refcursor;
    BEGIN
      rcur := 'cur';
      OPEN cur;
      ...

    -- new pattern
    DECLARE
      cur CURSOR FOR SELECT 1;
      rcur refcursor;
    BEGIN
      OPEN cur;
      rcur := cur;
      ...

When `compatibility_warnings` flag is active, then `plpgsql_check` try to identify
some fishy assigning to refcursor's variable or returning of refcursor's values:

    CREATE OR REPLACE FUNCTION public.foo()
     RETURNS refcursor
    AS $$
    declare
       c cursor for select 1;
       r refcursor;
    begin
      open c;
      r := 'c';
      return r;
    end;
    $$ LANGUAGE plpgsql;

    select * from plpgsql_check_function('foo', extra_warnings =>false, compatibility_warnings => true);
    ┌───────────────────────────────────────────────────────────────────────────────────┐
    │                              plpgsql_check_function                               │
    ╞═══════════════════════════════════════════════════════════════════════════════════╡
    │ compatibility:00000:6:assignment:obsolete setting of refcursor or cursor variable │
    │ Detail: Internal name of cursor should not be specified by users.                 │
    │ Context: at assignment to variable "r" declared on line 3                         │
    └───────────────────────────────────────────────────────────────────────────────────┘
    (3 rows)

# Limits

<i>plpgsql_check</i> should find almost all errors on really static code. When developers use
PLpgSQL's dynamic features like dynamic SQL or record data type, then false positives are
possible. These should be rare - in well written code - and then the affected function
should be redesigned or plpgsql_check should be disabled for this function.

    CREATE OR REPLACE FUNCTION f1()
    RETURNS void AS $$
    DECLARE r record;
    BEGIN
      FOR r IN EXECUTE 'SELECT * FROM t1'
      LOOP
        RAISE NOTICE '%', r.c;
      END LOOP;
    END;
    $$ LANGUAGE plpgsql SET plpgsql.enable_check TO false;

<i>A usage of plpgsql_check adds a small overhead (when passive mode is enabled) and you should use
that setting only in development or preproduction environments.</i>

## Dynamic SQL

This module doesn't check queries that are assembled in runtime. It is not possible
to identify results of dynamic queries - so <i>plpgsql_check</i> cannot to set correct type to record
variables and cannot to check a dependent SQLs and expressions. 

When type of record's variable is not know, you can assign it explicitly with pragma `type`:

    DECLARE r record;
    BEGIN
      EXECUTE format('SELECT * FROM %I', _tablename) INTO r;
      PERFORM plpgsql_check_pragma('type: r (id int, processed bool)');
      IF NOT r.processed THEN
        ...

<b>
Attention: The SQL injection check can detect only some SQL injection vulnerabilities. This tool
cannot be used for security audit! Some issues will not be detected. This check can raise false
alarms too - probably when variable is sanitized by other command or when the value is of some composite
type.
</b>

## Refcursors

<i>plpgsql_check</i> cannot be used to detect structure of referenced cursors. A reference on cursor
in PLpgSQL is implemented as name of global cursor. In check time, the name is not known (not in
all possibilities), and global cursor doesn't exist. It is a significant issue for any static analysis.
PLpgSQL cannot know how to set the correct type for the record variables and cannot to check the dependent 
SQL statements and expressions. A solution is the same for dynamic SQL. Don't use record variable
as target when you use <i>refcursor</i> type or disable <i>plpgsql_check</i> for these functions.

    CREATE OR REPLACE FUNCTION foo(refcur_var refcursor)
    RETURNS void AS $$
    DECLARE
      rec_var record;
    BEGIN
      FETCH refcur_var INTO rec_var; -- this is STOP for plpgsql_check
      RAISE NOTICE '%', rec_var;     -- record rec_var is not assigned yet error

In this case a record type should not be used (use known rowtype instead):

    CREATE OR REPLACE FUNCTION foo(refcur_var refcursor)
    RETURNS void AS $$
    DECLARE
      rec_var some_rowtype;
    BEGIN
      FETCH refcur_var INTO rec_var;
      RAISE NOTICE '%', rec_var;

## Temporary tables

<i>plpgsql_check</i> cannot verify queries over temporary tables that are created in plpgsql's function
runtime. For this use case it is necessary to create a fake temp table or disable <i>plpgsql_check</i> for this
function.

In reality temp tables are stored in own (per user) schema with higher priority than persistent
tables. So you can do (with following trick safetly):

    CREATE OR REPLACE FUNCTION public.disable_dml()
    RETURNS trigger
    LANGUAGE plpgsql AS $function$
    BEGIN
      RAISE EXCEPTION SQLSTATE '42P01'
         USING message = format('this instance of %I table doesn''t allow any DML operation', TG_TABLE_NAME),
               hint = format('you should use "CREATE TEMP TABLE %1$I(LIKE %1$I INCLUDING ALL);" statement',
                             TG_TABLE_NAME);
      RETURN NULL;
    END;
    $function$;
    
    CREATE TABLE foo(a int, b int); -- doesn't hold data, ever
    CREATE TRIGGER foo_disable_dml
       BEFORE INSERT OR UPDATE OR DELETE ON foo
       EXECUTE PROCEDURE disable_dml();

    postgres=# INSERT INTO  foo VALUES(10,20);
    ERROR:  this instance of foo table doesn't allow any DML operation
    HINT:  you should to run "CREATE TEMP TABLE foo(LIKE foo INCLUDING ALL);" statement
    postgres=# 
    
    CREATE TABLE
    postgres=# INSERT INTO  foo VALUES(10,20);
    INSERT 0 1

This trick emulates GLOBAL TEMP tables partially and it allows a statical validation.
Other possibility is using a [template foreign data wrapper] (https://github.com/okbob/template_fdw)

You can use pragma `table` and create ephemeral table:

    BEGIN
       CREATE TEMP TABLE xxx(a int);
       PERFORM plpgsql_check_pragma('table: xxx(a int)');
       INSERT INTO xxx VALUES(10);
       PERFORM plpgsql_check_pragma('table: [pg_temp].zzz(like schemaname.table1 including all)');
       ...


# Dependency list

A function <i>plpgsql_show_dependency_tb</i> will show all functions, operators and relations used
inside processed function:

    postgres=# select * from plpgsql_show_dependency_tb('testfunc(int,float)');
    ┌──────────┬───────┬────────┬─────────┬────────────────────────────┐
    │   type   │  oid  │ schema │  name   │           params           │
    ╞══════════╪═══════╪════════╪═════════╪════════════════════════════╡
    │ FUNCTION │ 36008 │ public │ myfunc1 │ (integer,double precision) │
    │ FUNCTION │ 35999 │ public │ myfunc2 │ (integer,double precision) │
    │ OPERATOR │ 36007 │ public │ **      │ (integer,integer)          │
    │ RELATION │ 36005 │ public │ myview  │                            │
    │ RELATION │ 36002 │ public │ mytable │                            │
    └──────────┴───────┴────────┴─────────┴────────────────────────────┘
    (4 rows)

Optional arguments of <i>plpgsql_show_dependency_tb</i> are `relid`, `anyelementtype`, `enumtype`,
`anyrangetype`, `anycompatibletype` and `anycompatiblerangetype`.

# Profiler

The plpgsql_check contains simple profiler of plpgsql functions and procedures. It can work with/without
access to shared memory. It depends on `shared_preload_libraries` config. When plpgsql_check is initialized
by `shared_preload_libraries`, then it can allocate shared memory, and function's profiles are stored there.
When plpgsql_check cannot to allocate shared memory, the profile is stored in session memory.

Due to dependencies, `shared_preload_libraries` should to contain `plpgsql` first

    postgres=# show shared_preload_libraries ;
    ┌──────────────────────────┐
    │ shared_preload_libraries │
    ╞══════════════════════════╡
    │ plpgsql,plpgsql_check    │
    └──────────────────────────┘
    (1 row)

The profiler is active when GUC `plpgsql_check.profiler` is on. The profiler doesn't require shared memory,
but if there is not enough shared memory, then the profiler is limited just to active session.
The profiler can be activated by calling function `plpgsql_check_profiler(true)` and disabled
by calling same function with `false` argument (or with literals `on`, `off`).

The plpgsql_check should be initialized before any plpgsql function is executed. Only
early initialization ensures correct work of profiler and tracer. When you doesn't use
`shared_preloaded_libraries`, you can use command `load 'plpgsql_check'` instead.

When plpgsql_check is initialized by `shared_preload_libraries`, another GUC is
available to configure the amount of shared memory used by the profiler:
`plpgsql_check.profiler_max_shared_chunks`.  This defines the maximum number of
statements chunk that can be stored in shared memory.  For each plpgsql
function (or procedure), the whole content is split into chunks of 30
statements.  If needed, multiple chunks can be used to store the whole content
of a single function.  A single chunk is 1704 bytes.  The default value for
this GUC is 15000, which should be enough for big projects containing hundreds
of thousands of statements in plpgsql, and will consume about 24MB of memory.
If your project doesn't require that much number of chunks, you can set this
parameter to a smaller number in order to decrease the memory usage.  The
minimum value is 50 (which should consume about 83kB of memory), and the
maximum value is 100000 (which should consume about 163MB of memory).  Changing
this parameter requires a PostgreSQL restart.

The profiler will also retrieve the query identifier for each instruction that
contains an expression or optimizable statement.  Note that this requires
pg_stat_statements, or another similar third-party extension), to be installed.
There are some limitations to the query identifier retrieval:

* if a plpgsql expression contains underlying statements, only the top level
  query identifier will be retrieved
* the profiler doesn't compute query identifier by itself but relies on
  external extension, such as pg_stat_statements, for that.  It means that
  depending on the external extension behavior, you may not be able to see a
  query identifier for some statements.  That's for instance the case with DDL
  statements, as pg_stat_statements doesn't expose the query identifier for
  such queries.
* a query identifier is retrieved only for instructions containing
  expressions.  This means that plpgsql_profiler_function_tb() function can
  report less query identifier than instructions on a single line.

Attention: An update of shared profiles can decrease performance on servers under higher load.

The profile can be displayed by function `plpgsql_profiler_function_tb`:

    postgres=# select lineno, avg_time, source from plpgsql_profiler_function_tb('fx(int)');
    ┌────────┬──────────┬───────────────────────────────────────────────────────────────────┐
    │ lineno │ avg_time │                              source                               │
    ╞════════╪══════════╪═══════════════════════════════════════════════════════════════════╡
    │      1 │          │                                                                   │
    │      2 │          │ declare result int = 0;                                           │
    │      3 │    0.075 │ begin                                                             │
    │      4 │    0.202 │   for i in 1..$1 loop                                             │
    │      5 │    0.005 │     select result + i into result; select result + i into result; │
    │      6 │          │   end loop;                                                       │
    │      7 │        0 │   return result;                                                  │
    │      8 │          │ end;                                                              │
    └────────┴──────────┴───────────────────────────────────────────────────────────────────┘
    (9 rows)

The times in the result are in miliseconds.

The profile per statements (not per line) can be displayed by function plpgsql_profiler_function_statements_tb:

            CREATE OR REPLACE FUNCTION public.fx1(a integer)
             RETURNS integer
             LANGUAGE plpgsql
    1       AS $function$
    2       begin
    3         if a > 10 then
    4           raise notice 'ahoj';
    5           return -1;
    6         else
    7           raise notice 'nazdar';
    8           return 1;
    9         end if;
    10      end;
    11      $function$

    postgres=# select stmtid, parent_stmtid, parent_note, lineno, exec_stmts, stmtname
                 from plpgsql_profiler_function_statements_tb('fx1');
    ┌────────┬───────────────┬─────────────┬────────┬────────────┬─────────────────┐
    │ stmtid │ parent_stmtid │ parent_note │ lineno │ exec_stmts │    stmtname     │
    ╞════════╪═══════════════╪═════════════╪════════╪════════════╪═════════════════╡
    │      0 │             ∅ │ ∅           │      2 │          0 │ statement block │
    │      1 │             0 │ body        │      3 │          0 │ IF              │
    │      2 │             1 │ then body   │      4 │          0 │ RAISE           │
    │      3 │             1 │ then body   │      5 │          0 │ RETURN          │
    │      4 │             1 │ else body   │      7 │          0 │ RAISE           │
    │      5 │             1 │ else body   │      8 │          0 │ RETURN          │
    └────────┴───────────────┴─────────────┴────────┴────────────┴─────────────────┘
    (6 rows)

All stored profiles can be displayed by calling function `plpgsql_profiler_functions_all`:

    postgres=# select * from plpgsql_profiler_functions_all();
    ┌───────────────────────┬────────────┬────────────┬──────────┬─────────────┬──────────┬──────────┐
    │        funcoid        │ exec_count │ total_time │ avg_time │ stddev_time │ min_time │ max_time │
    ╞═══════════════════════╪════════════╪════════════╪══════════╪═════════════╪══════════╪══════════╡
    │ fxx(double precision) │          1 │       0.01 │     0.01 │        0.00 │     0.01 │     0.01 │
    └───────────────────────┴────────────┴────────────┴──────────┴─────────────┴──────────┴──────────┘
    (1 row)


There are two functions for cleaning stored profiles: `plpgsql_profiler_reset_all()` and
`plpgsql_profiler_reset(regprocedure)`.

## Coverage metrics

plpgsql_check provides two functions:

* `plpgsql_coverage_statements(name)`
* `plpgsql_coverage_branches(name)`

## Note

There is another very good PLpgSQL profiler - https://github.com/glynastill/plprofiler

My extension is designed to be simple for use and practical. Nothing more or less.

plprofiler is more complex. It builds call graphs and from this graph it can create
flame graph of execution times.

Both extensions can be used together with the builtin PostgreSQL's feature - tracking functions.

    set track_functions to 'pl';
    ...
    select * from pg_stat_user_functions;

# Tracer

plpgsql_check provides a tracing possibility - in this mode you can see notices on
start or end functions (terse and default verbosity) and start or end statements
(verbose verbosity). For default and verbose verbosity the content of function arguments
is displayed. The content of related variables are displayed when verbosity is verbose.

    postgres=# do $$ begin perform fx(10,null, 'now', e'stěhule'); end; $$;
    NOTICE:  #0 ->> start of inline_code_block (Oid=0)
    NOTICE:  #2   ->> start of function fx(integer,integer,date,text) (Oid=16405)
    NOTICE:  #2        call by inline_code_block line 1 at PERFORM
    NOTICE:  #2       "a" => '10', "b" => null, "c" => '2020-08-03', "d" => 'stěhule'
    NOTICE:  #4     ->> start of function fx(integer) (Oid=16404)
    NOTICE:  #4          call by fx(integer,integer,date,text) line 1 at PERFORM
    NOTICE:  #4         "a" => '10'
    NOTICE:  #4     <<- end of function fx (elapsed time=0.098 ms)
    NOTICE:  #2   <<- end of function fx (elapsed time=0.399 ms)
    NOTICE:  #0 <<- end of block (elapsed time=0.754 ms)

The number after `#` is a execution frame counter (this number is related to depth of error context stack).
It allows to pair start and end of function. Attention - the initial depth of error context stack can be different
in dependency on environment (and used protocol).

Tracing is enabled by setting `plpgsql_check.tracer` to `on`. Attention - enabling this behaviour
has significant negative impact on performance (unlike the profiler). You can set a level for output used by
tracer `plpgsql_check.tracer_errlevel` (default is `notice`). The output content is limited by length
specified by `plpgsql_check.tracer_variable_max_length` configuration variable. The tracer can be activated
by calling function `plpgsql_check_tracer(true)` and disabled by calling same function with `false` argument
(or with literals `on`, `off`).

First, the usage of tracer should be explicitly enabled by superuser by setting `set plpgsql_check.enable_tracer to on;`
or `plpgsql_check.enable_tracer to on` in `postgresql.conf`. This is a security safeguard. The tracer shows content of
plpgsql's variables, and then some security sensitive information can be displayed to an unprivileged user (when he runs
security definer function). Second, the extension `plpgsql_check` should be loaded. It can be done by execution of some
`plpgsql_check` function or explicitly by command `load 'plpgsql_check';`. You can use configuration's option
`shared_preload_libraries`, `local_preload_libraries` or `session_preload_libraries`.

In terse verbose mode the output is reduced:

    postgres=# set plpgsql_check.tracer_verbosity TO terse;
    SET
    postgres=# do $$ begin perform fx(10,null, 'now', e'stěhule'); end; $$;
    NOTICE:  #0 start of inline code block (oid=0)
    NOTICE:  #2 start of fx (oid=16405)
    NOTICE:  #4 start of fx (oid=16404)
    NOTICE:  #4 end of fx
    NOTICE:  #2 end of fx
    NOTICE:  #0 end of inline code block

In verbose mode the output is extended about statement details:

    postgres=# do $$ begin perform fx(10,null, 'now', e'stěhule'); end; $$;
    NOTICE:  #0            ->> start of block inline_code_block (oid=0)
    NOTICE:  #0.1       1  --> start of PERFORM
    NOTICE:  #2              ->> start of function fx(integer,integer,date,text) (oid=16405)
    NOTICE:  #2                   call by inline_code_block line 1 at PERFORM
    NOTICE:  #2                  "a" => '10', "b" => null, "c" => '2020-08-04', "d" => 'stěhule'
    NOTICE:  #2.1       1    --> start of PERFORM
    NOTICE:  #2.1                "a" => '10'
    NOTICE:  #4                ->> start of function fx(integer) (oid=16404)
    NOTICE:  #4                     call by fx(integer,integer,date,text) line 1 at PERFORM
    NOTICE:  #4                    "a" => '10'
    NOTICE:  #4.1       6      --> start of assignment
    NOTICE:  #4.1                  "a" => '10', "b" => '20'
    NOTICE:  #4.1              <-- end of assignment (elapsed time=0.076 ms)
    NOTICE:  #4.1                  "res" => '130'
    NOTICE:  #4.2       7      --> start of RETURN
    NOTICE:  #4.2                  "res" => '130'
    NOTICE:  #4.2              <-- end of RETURN (elapsed time=0.054 ms)
    NOTICE:  #4                <<- end of function fx (elapsed time=0.373 ms)
    NOTICE:  #2.1            <-- end of PERFORM (elapsed time=0.589 ms)
    NOTICE:  #2              <<- end of function fx (elapsed time=0.727 ms)
    NOTICE:  #0.1          <-- end of PERFORM (elapsed time=1.147 ms)
    NOTICE:  #0            <<- end of block (elapsed time=1.286 ms)

A special feature of tracer is tracing of the `ASSERT` statement when `plpgsql_check.trace_assert` is `on`. When
`plpgsql_check.trace_assert_verbosity` is `DEFAULT`, then all function's or procedure's variables are
displayed when assert expression is false. When this configuration is `VERBOSE` then all variables
from all plpgsql frames are displayed. This behaviour is independent on `plpgsql.check_asserts` value.
It can be used, although the assertions are disabled in plpgsql runtime.

    postgres=# set plpgsql_check.tracer to off;
    postgres=# set plpgsql_check.trace_assert_verbosity TO verbose;

    postgres=# do $$ begin perform fx(10,null, 'now', e'stěhule'); end; $$;
    NOTICE:  #4 PLpgSQL assert expression (false) on line 12 of fx(integer) is false
    NOTICE:   "a" => '10', "res" => null, "b" => '20'
    NOTICE:  #2 PL/pgSQL function fx(integer,integer,date,text) line 1 at PERFORM
    NOTICE:   "a" => '10', "b" => null, "c" => '2020-08-05', "d" => 'stěhule'
    NOTICE:  #0 PL/pgSQL function inline_code_block line 1 at PERFORM
    ERROR:  assertion failed
    CONTEXT:  PL/pgSQL function fx(integer) line 12 at ASSERT
    SQL statement "SELECT fx(a)"
    PL/pgSQL function fx(integer,integer,date,text) line 1 at PERFORM
    SQL statement "SELECT fx(10,null, 'now', e'stěhule')"
    PL/pgSQL function inline_code_block line 1 at PERFORM

    postgres=# set plpgsql.check_asserts to off;
    SET
    postgres=# do $$ begin perform fx(10,null, 'now', e'stěhule'); end; $$;
    NOTICE:  #4 PLpgSQL assert expression (false) on line 12 of fx(integer) is false
    NOTICE:   "a" => '10', "res" => null, "b" => '20'
    NOTICE:  #2 PL/pgSQL function fx(integer,integer,date,text) line 1 at PERFORM
    NOTICE:   "a" => '10', "b" => null, "c" => '2020-08-05', "d" => 'stěhule'
    NOTICE:  #0 PL/pgSQL function inline_code_block line 1 at PERFORM
    DO

Tracer can show usage of subtransaction buffer id (`nxids`). The displayed `tnl` number
is transaction nesting level number (for plpgsql it depends on deep of blocks with
exception's handlers).

## Detection of unclosed cursors

PLpgSQL's cursors are just names of SQL cursors. The life cycle of SQL cursors is not
joined with scope of related plpgsql's cursor variable. SQL cursors are cloased by self
at transaction end, but for long transaction and too much opened cursors it can be too late.
It is better to close cursor explicitly when cursor is not necessary (by CLOSE statement).
Without it the significant memory issues are possible.

When OPEN statement try to use cursor that is not closed yet, the warning is raised.
This feature can be disabled by setting `plpgsql_check.cursors_leaks to off`. This check
is not active, when routine is called recusively 

The unclosed cursors can be checked immediately when function is finished. This check is
disabled by default, and should be enabled by `plpgsql_check.strict_cursors_leaks to on`.

Any unclosed cursor is reported once.

## Using with plugin_debugger

If you use `plugin_debugger` (plpgsql debugger) together with `plpgsql_check`, then
`plpgsql_check` should be initialized after `plugin_debugger` (because `plugin_debugger`
doesn't support the sharing of PL/pgSQL's debug API). For example (`postgresql.conf`):

    shared_preload_libraries = 'plugin_debugger,plpgsql,plpgsql_check'


## Attention - SECURITY

Tracer prints content of variables or function arguments. For security definer function, this
content can hold security sensitive data. This is reason why tracer is disabled by default and should
be enabled only with super user rights `plpgsql_check.enable_tracer`.

# Pragma

You can configure plpgsql_check behaviour inside a checked function with "pragma" function. This
is a analogy of PL/SQL or ADA language of PRAGMA feature. PLpgSQL doesn't support PRAGMA, but
plpgsql_check detects function named `plpgsql_check_pragma` and takes options from the parameters of
this function. These plpgsql_check options are valid to the end of this group of statements.

    CREATE OR REPLACE FUNCTION test()
    RETURNS void AS $$
    BEGIN
      ...
      -- for following statements disable check
      PERFORM plpgsql_check_pragma('disable:check');
      ...
      -- enable check again
      PERFORM plpgsql_check_pragma('enable:check');
      ...
    END;
    $$ LANGUAGE plpgsql;

The function `plpgsql_check_pragma` is immutable function that returns one. It is defined
by `plpgsql_check` extension. You can declare alternative `plpgsql_check_pragma` function
like:

    CREATE OR REPLACE FUNCTION plpgsql_check_pragma(VARIADIC args[])
    RETURNS int AS $$
    SELECT 1
    $$ LANGUAGE sql IMMUTABLE;

Using pragma function in declaration part of top block sets options on function level too.

    CREATE OR REPLACE FUNCTION test()
    RETURNS void AS $$
    DECLARE
      aux int := plpgsql_check_pragma('disable:extra_warnings');
      ...


Shorter syntax for pragma is supported too:

    CREATE OR REPLACE FUNCTION test()
    RETURNS void AS $$
    DECLARE r record;
    BEGIN
      PERFORM 'PRAGMA:TYPE:r (a int, b int)';
      PERFORM 'PRAGMA:TABLE: x (like pg_class)';
      ...

## Supported pragmas

* `echo:str` - print string (for testing). Inside string, there can be used "variables": @@id, @@name, @@signature

* `status:check`,`status:tracer`, `status:other_warnings`, `status:performance_warnings`, `status:extra_warnings`,`status:security_warnings`
  This outputs the current value (e.g. other_warnings enabled)

* `enable:check`,`enable:tracer`, `enable:other_warnings`, `enable:performance_warnings`, `enable:extra_warnings`,`enable:security_warnings`

* `disable:check`,`disable:tracer`, `disable:other_warnings`, `disable:performance_warnings`, `disable:extra_warnings`,`disable:security_warnings`
  This can be used to disable the Hint in returning from an anyelement function.  Just put the pragma before the RETURN statement.
  
* `type:varname typename` or `type:varname (fieldname type, ...)` - set type to variable of record type

* `table: name (column_name type, ...)` or `table: name (like tablename)` - create ephemeral temporary table (if you want to specify schema, then only `pg_temp` schema is allowed.

* `sequence: name` - create ephemeral temporary sequence

* `assert-schema: varname` - check-time assertation - ensure so schema specified by variable is valid

* `assert-table: [ varname_schema, ] , varname` - ensure so table name specified by variables (by constant tracing) is valid

* `assert-column: [varname_schema, ], varname_table , varname` - ensure so column spefified by variables is valid

Pragmas `enable:tracer` and `disable:tracer`are active for Postgres 12 and higher

# Update

plpgsql_check doesn't support update (of plpgsql_check). You should to drop this
before install new version of this extension.

# Compilation

You need a development environment for PostgreSQL extensions:

    make clean
    make install

result:

    [pavel@localhost plpgsql_check]$ make USE_PGXS=1 clean
    rm -f plpgsql_check.so   libplpgsql_check.a  libplpgsql_check.pc
    rm -f plpgsql_check.o
    rm -rf results/ regression.diffs regression.out tmp_check/ log/
    [pavel@localhost plpgsql_check]$ make USE_PGXS=1 all
    clang -O2 -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fpic -I/usr/local/pgsql/lib/pgxs/src/makefiles/../../src/pl/plpgsql/src -I. -I./ -I/usr/local/pgsql/include/server -I/usr/local/pgsql/include/internal -D_GNU_SOURCE   -c -o plpgsql_check.o plpgsql_check.c
    clang -O2 -Wall -Wmissing-prototypes -Wpointer-arith -Wdeclaration-after-statement -Wendif-labels -Wmissing-format-attribute -Wformat-security -fno-strict-aliasing -fwrapv -fpic -I/usr/local/pgsql/lib/pgxs/src/makefiles/../../src/pl/plpgsql/src -shared -o plpgsql_check.so plpgsql_check.o -L/usr/local/pgsql/lib -Wl,--as-needed -Wl,-rpath,'/usr/local/pgsql/lib',--enable-new-dtags  
    [pavel@localhost plpgsql_check]$ su root
    Password: *******
    [root@localhost plpgsql_check]# make USE_PGXS=1 install
    /usr/bin/mkdir -p '/usr/local/pgsql/lib'
    /usr/bin/mkdir -p '/usr/local/pgsql/share/extension'
    /usr/bin/mkdir -p '/usr/local/pgsql/share/extension'
    /usr/bin/install -c -m 755  plpgsql_check.so '/usr/local/pgsql/lib/plpgsql_check.so'
    /usr/bin/install -c -m 644 plpgsql_check.control '/usr/local/pgsql/share/extension/'
    /usr/bin/install -c -m 644 plpgsql_check--0.9.sql '/usr/local/pgsql/share/extension/'
    [root@localhost plpgsql_check]# exit
    [pavel@localhost plpgsql_check]$ make USE_PGXS=1 installcheck
    /usr/local/pgsql/lib/pgxs/src/makefiles/../../src/test/regress/pg_regress --inputdir=./ --psqldir='/usr/local/pgsql/bin'    --dbname=pl_regression --load-language=plpgsql --dbname=contrib_regression plpgsql_check_passive plpgsql_check_active plpgsql_check_active-9.5
    (using postmaster on Unix socket, default port)
    ============== dropping database "contrib_regression" ==============
    DROP DATABASE
    ============== creating database "contrib_regression" ==============
    CREATE DATABASE
    ALTER DATABASE
    ============== installing plpgsql                     ==============
    CREATE LANGUAGE
    ============== running regression test queries        ==============
    test plpgsql_check_passive    ... ok
    test plpgsql_check_active     ... ok
    test plpgsql_check_active-9.5 ... ok
    
    =====================
     All 3 tests passed. 
    =====================

## Compilation for PostgresPro

`plpgsql_check` requires some unpublished patches to successufully compiled and used with PostgresPro. Use
`plpgsql_check` from PostgresPro repository.

## Compilation on Ubuntu

Sometimes successful compilation can require libicu-dev package (PostgreSQL 10 and higher - when pg was compiled with
ICU support)

    sudo apt install libicu-dev

## Compilation plpgsql_check on Windows

You can check precompiled dll libraries http://okbob.blogspot.cz/2015/02/plpgsqlcheck-is-available-for-microsoft.html,
http://okbob.blogspot.com/2023/10/compiled-dll-of-plpgsqlcheck-254-and.html

or compile by self:

1. Download and install PostgreSQL for Win32 from http://www.enterprisedb.com
2. Download and install Microsoft Visual C++ Express
3. Read tutorial http://blog.2ndquadrant.com/compiling-postgresql-extensions-visual-studio-windows
4. Build plpgsql_check.dll
5. Install plugin
  1. copy `plpgsql_check.dll` to `PostgreSQL\14\lib`
  2. copy `plpgsql_check.control` and `plpgsql_check--2.1.sql` to `PostgreSQL\14\share\extension`

## Meson build

1. `meson setup build`
2. `cd build`
3. `ninja`
4. `ninja install`
5. optionaly `ninja bindist`

## Checked on

* gcc on Linux (against all supported PostgreSQL)
* clang 3.4 on Linux (against PostgreSQL 10)
* for success regress tests the PostgreSQL 10 or higher is required

Compilation against PostgreSQL 10 requires libICU!

# Licence

Copyright (c) Pavel Stehule (pavel.stehule@gmail.com)

 Permission is hereby granted, free of charge, to any person obtaining a copy
 of this software and associated documentation files (the "Software"), to deal
 in the Software without restriction, including without limitation the rights
 to use, copy, modify, merge, publish, distribute, sublicense, and/or sell
 copies of the Software, and to permit persons to whom the Software is
 furnished to do so, subject to the following conditions:

 The above copyright notice and this permission notice shall be included in
 all copies or substantial portions of the Software.

 THE SOFTWARE IS PROVIDED "AS IS", WITHOUT WARRANTY OF ANY KIND, EXPRESS OR
 IMPLIED, INCLUDING BUT NOT LIMITED TO THE WARRANTIES OF MERCHANTABILITY,
 FITNESS FOR A PARTICULAR PURPOSE AND NONINFRINGEMENT. IN NO EVENT SHALL THE
 AUTHORS OR COPYRIGHT HOLDERS BE LIABLE FOR ANY CLAIM, DAMAGES OR OTHER
 LIABILITY, WHETHER IN AN ACTION OF CONTRACT, TORT OR OTHERWISE, ARISING FROM,
 OUT OF OR IN CONNECTION WITH THE SOFTWARE OR THE USE OR OTHER DEALINGS IN
 THE SOFTWARE.

# Note

If you like it, send a postcard to address

    Pavel Stehule
    Skalice 12
    256 01 Benesov u Prahy
    Czech Republic


I invite any questions, comments, bug reports, patches on mail address pavel.stehule@gmail.com