File: sample_functions.sql

package info (click to toggle)
omnidb-plpgsql-debugger 3.0.0.20201026-6
  • links: PTS, VCS
  • area: main
  • in suites: forky, sid, trixie
  • size: 184 kB
  • sloc: ansic: 420; sql: 215; sh: 81; makefile: 13
file content (263 lines) | stat: -rw-r--r-- 5,040 bytes parent folder | download | duplicates (3)
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
-- SIMPLE
CREATE OR REPLACE FUNCTION omnidb.function_01(text, text)
RETURNS text AS $$
BEGIN
    RETURN $1 || ' ' || $2;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_01('hello', 'world');
-- --> 'hello world'

---

-- PARAMETER ALIAS
CREATE OR REPLACE FUNCTION omnidb.function_02(int, int)
RETURNS int AS $$
DECLARE
    i ALIAS FOR $1;
    j ALIAS FOR $2;
    sum int;
BEGIN
    sum := i + j;
    RETURN sum;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_02(41, 1);
-- --> 42

---

-- NAMED PARAMETERS
CREATE OR REPLACE FUNCTION omnidb.function_03(i int, j int)
RETURNS int AS $$
DECLARE
    sum int;
BEGIN
    sum := i + j;
    RETURN sum;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_03(41, 1);
-- --> 42

---

-- CONTROL STRUCTURES: IF
CREATE OR REPLACE FUNCTION omnidb.function_04(i int)
RETURNS boolean AS $$
DECLARE
    tmp int;
BEGIN
    tmp := i % 2;
    IF tmp = 0 THEN
        RETURN true;
    ELSE
        RETURN false;
    END IF;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_04(3);
-- --> f
-- SELECT omnidb.function_04(32);
-- --> t

---

-- CONTROL STRUCTURES: FOR ... LOOP
CREATE OR REPLACE FUNCTION omnidb.function_05(i numeric)
RETURNS numeric AS $$
DECLARE
    tmp numeric; result numeric;
BEGIN
    result := 1;
    FOR tmp IN 1 .. i LOOP
        result := result * tmp;
    END LOOP;
    RETURN result;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_05(42::numeric);
-- --> 1405006117752879898543142606244511569936384000000000

---

-- CONTROL STRUCTURES: WHILE ... LOOP
CREATE OR REPLACE FUNCTION omnidb.function_06(i numeric)
RETURNS numeric AS $$
DECLARE tmp numeric; result numeric;
BEGIN
    result := 1; tmp := 1;
    WHILE tmp <= i LOOP
        result := result * tmp;
        tmp := tmp + 1;
    END LOOP;
    RETURN result;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_06(42::numeric);
-- --> 1405006117752879898543142606244511569936384000000000

---

-- RECURSIVE
CREATE OR REPLACE FUNCTION omnidb.function_07(i numeric)
RETURNS numeric AS $$
BEGIN
    IF i = 0 THEN
        RETURN 1;
    ELSIF i = 1 THEN
        RETURN 1;
    ELSE
        RETURN i * omnidb.function_07(i - 1);
    END IF;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_07(42::numeric);
-- --> 1405006117752879898543142606244511569936384000000000

---

-- RECORD TYPES
CREATE OR REPLACE FUNCTION omnidb.function_08()
RETURNS text AS $$
DECLARE
    tmp RECORD;
BEGIN
    SELECT INTO tmp 1 + 1 AS a, 2 + 2 AS b;
    RETURN 'a = ' || tmp.a || '; b = ' || tmp.b;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_08();
-- --> 'a = 2; b = 4'

---

-- PERFORM
CREATE TABLE omnidb.foo(x integer);

CREATE OR REPLACE FUNCTION omnidb.function_09_aux() RETURNS void AS
$$ INSERT INTO omnidb.foo VALUES (41),(42) $$ LANGUAGE sql;

CREATE OR REPLACE FUNCTION omnidb.function_09()
RETURNS text AS $$
BEGIN
    PERFORM omnidb.function_09_aux();
    RETURN 'OK';
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_09();
-- --> 'OK'
-- SELECT * FROM omnidb.foo;
-- --> 41, 42

---

-- DYNAMIC SQL
CREATE OR REPLACE FUNCTION omnidb.function_10(i int)
RETURNS omnidb.foo AS $$
DECLARE
    rec RECORD;
BEGIN
    EXECUTE 'SELECT * FROM omnidb.foo WHERE x = ' || i INTO rec;
    RETURN rec;
END;
$$ LANGUAGE plpgsql;

-- SELECT * FROM omnidb.function_10(42);
-- --> 42

---

-- CURSORS
CREATE OR REPLACE FUNCTION omnidb.function_11()
RETURNS numeric AS $$
DECLARE
    tmp RECORD; result numeric;
BEGIN
    result := 0.00;
    FOR tmp IN SELECT * FROM omnidb.foo LOOP
        result := result + tmp.x;
    END LOOP;
    RETURN result;
END;
$$ LANGUAGE plpgsql;

-- SELECT omnidb.function_11();
-- --> 83

---

-- ALTERNATIVE FUNCTION TERMINATOR
CREATE FUNCTION omnidb.function_12(text)
RETURNS text
AS 'DECLARE
        str text;
        ret text;
        i   integer;
        len integer;

    BEGIN
        str := upper($1);
        ret := '''';
        i   := 1;
        len := length(str);
        WHILE i <= len LOOP
            ret := ret || substr(str, i, 1) || '' '';
            i := i + 1;
        END LOOP;
        RETURN ret;
    END;'
LANGUAGE 'plpgsql';

-- SELECT omnidb.function_12('Hello World');
-- --> 'H E L L O W O R L D'

---

-- ERROR HANDLING
CREATE OR REPLACE FUNCTION omnidb.function_13(a integer, b integer)
RETURNS integer AS $$
BEGIN
    RETURN a + b;
EXCEPTION
    WHEN numeric_value_out_of_range THEN
    -- do some important stuff
    RETURN -1;
WHEN OTHERS THEN
    -- do some other important stuff
    RETURN -1;
END;
$$ LANGUAGE plpgsql;

---

-- NESTED EXCEPTION BLOCKS
CREATE TABLE omnidb.bar(a integer, b text);

CREATE FUNCTION omnidb.function_14(key integer, data text)
RETURNS void AS $$
BEGIN
    LOOP
        UPDATE omnidb.bar SET b = data WHERE a = key;
        IF found THEN RETURN;
        END IF;
        BEGIN
            INSERT INTO omnidb.bar (a, b) VALUES (key, data);
            RETURN;
        EXCEPTION WHEN unique_violation THEN
        -- do nothing
        END;
    END LOOP;
EXCEPTION WHEN OTHERS THEN
-- do something else
END;
$$ LANGUAGE plpgsql;