-
Notifications
You must be signed in to change notification settings - Fork 3
/
Copy pathpgkv.sql
2098 lines (2012 loc) · 61.8 KB
/
pgkv.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
--------------------
-- Start Table Setup
--------------------
-- create keyval schema for all key/value types (strings, numbers, hashes, arrays)
create schema keyval;
-- create the key/value table for strings
create table keyval.strings (
key varchar primary key,
value text,
created_at timestamp,
updated_at timestamp
);
-- create the key/value table for numbers
create table keyval.numbers (
key varchar primary key,
value int not null default 0,
created_at timestamp,
updated_at timestamp
);
-- create the key/value table for lists
create table keyval.lists (
key varchar primary key,
value text[],
created_at timestamp,
updated_at timestamp
);
-- create the key/value table for hashes
create extension hstore;
create table keyval.hashes (
key varchar primary key,
value hstore,
created_at timestamp,
updated_at timestamp
);
-------------------------
-- Start String Functions
-------------------------
-- KVAPPEND: Appends the value to the end of the string if the key has already been set.
-- If the key does not exist, sets the key to hold the string value instead.
-- The length of the current string value is always returned.
-- ARG1: keyname varchar
-- ARG2: valuestring text
-- RTRN: integer
--
-- EXAMPLE 1:
-- select * from kvappend('abc', 'hello');
-- kvappend
-- ----------
-- 5
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvappend('abc', 'world');
-- kvappend
-- ----------
-- 10
-- (1 row)
create or replace function kvappend(keyname varchar, valuestring text) returns int as $$
declare
result int;
begin
update keyval.strings set value = (value || valuestring), updated_at = now() where key = keyname returning char_length(value) into result;
if not found then
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
result := char_length(valuestring);
end if;
return result;
end;
$$ language 'plpgsql';
-- KVDEL: Deletes the string value held by the key and returns TRUE.
-- If the key does not exist, FALSE is returned instead.
-- ARG1: keyname varchar
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvdel('abc');
-- kvdel
-- -------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvdel('nonexistent');
--
-- kvdel
-- -------
-- f
-- (1 row)
create or replace function kvdel(keyname varchar) returns boolean as $$
declare
result boolean := false;
begin
delete from keyval.strings where key = keyname;
if found then
result := true;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVDELE: Deletes the string value held by the key.
-- If the key does not exist, an error is raised instead.
-- ARG1: keyname varchar
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvdele('abc');
-- kvdele
-- --------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvdele('nonexistent');
-- ERROR: The keyname provided does not exists!
create or replace function kvdele(keyname varchar) returns void as $$
begin
if not kvdel(keyname) then
raise exception 'The keyname provided does not exist!' using errcode = 'no_data_found';
end if;
end;
$$ language 'plpgsql';
-- KVGET: Returns the string value of the key.
-- If the key does not exist, NULL is returned instead.
-- ARG1: keyname varchar
-- RTRN: text
--
-- EXAMPLE 1:
-- select * from kvget('abc');
-- kvget
-- -------------
-- hello world
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvget('nonexistent');
-- kvget
-- --------
-- <NULL>
-- (1 row)
create or replace function kvget(keyname varchar) returns text as $$
declare
result text;
begin
select value from keyval.strings where key = keyname into result;
return result;
end;
$$ language 'plpgsql';
-- KVGETSET: Sets the key to hold a string value and returns the old value stored.
-- If no value was previously stored, NULL is returned instead.
-- ARG1: keyname varchar
-- ARG2: valuestring text
-- RTRN: text
--
-- EXAMPLE 1:
-- select * from kvgetset('abc', 'hello world');
-- kvgetset
-- ----------
-- <NULL>
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvgetset('abc', 'howdy partner');
-- kvgetset
-- -------------
-- hello world
-- (1 row)
create or replace function kvgetset(keyname varchar, valuestring text) returns text as $$
declare
result text;
begin
select value from keyval.strings where key = keyname into result;
if found then
update keyval.strings set value = valuestring, updated_at = now() where key = keyname;
else
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
end if;
return result;
end;
$$ language 'plpgsql';
-- KVLEN: Returns the length of the string value of the key.
-- If no value was previously stored, NULL is returned instead.
-- ARG1: keyname varchar
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvlen('abc');
-- kvlen
-- -------
-- 11
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvlen('nonexistent');
-- kvlen
-- --------
-- <NULL>
-- (1 row)
create or replace function kvlen(keyname varchar) returns int as $$
declare
result int;
begin
select char_length(value) from keyval.strings where key = keyname into result;
if not found then
result := null;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVMGET: Returns the key and string values of all specified keys.
-- For any keys specified that do not have a string value, NULL is returned instead.
-- ARG1: keynames varchar[]
-- RTRN: table(key varchar, value text)
--
-- EXAMPLE 1:
-- select * from kvmget(array['abc', 'nonexistent', 'def', 'nonexistent']);
-- key | value
-- -------------+---------------
-- abc | hello world
-- nonexistent | <NULL>
-- def | howdy partner
-- nonexistent | <NULL>
-- (4 rows)
create or replace function kvmget(keynames varchar[]) returns table(key varchar, value text) as $$
begin
return query with
keys as (select unnest(keynames))
select keys.unnest, strings.value from keys
left outer join keyval.strings on strings.key = keys.unnest;
end;
$$ language 'plpgsql';
-- KVMSET: Sets all keys to their respective string values.
-- For any keys that already hold a value, they will be overwritten instead.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuestrings text[]
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvmset(array['a', 'b', 'c'], array['apple', 'banana', 'cherry']);
-- kvmset
-- --------
--
-- (1 row)
create or replace function kvmset(keynames varchar[], valuestrings text[]) returns void as $$
declare
keyname varchar;
i int := 1;
begin
if array_length(keynames, 1) = array_length(valuestrings, 1) then
foreach keyname in array keynames loop
update keyval.strings set value = valuestrings[i], updated_at = now() where key = keyname;
if not found then
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestrings[i], now(), now());
end if;
i := i + 1;
end loop;
else
raise exception 'The size of the "keynames" and "valuestrings" arguments must match!' using errcode = 'array_subscript_error';
end if;
end;
$$ language 'plpgsql';
-- KVMSETNX: Sets all keys to their respective string values, if all of the keys specified have not been set already and returns TRUE.
-- If any of the specified keys have already been set to a string value, this function will do nothing and return FALSE instead.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuestrings text[]
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvmsetnx(array['a', 'b', 'c'], array['apple', 'banana', 'cherry']);
-- kvmsetnx
-- ----------
-- t
-- (1 row)
-- EXAMPLE 1:
-- select * from kvmsetnx(array['a', 'd', 'e'], array['apricot', 'date', 'eggplant']);
-- kvmsetnx
-- ----------
-- f
-- (1 row)
create or replace function kvmsetnx(keynames varchar[], valuestrings text[]) returns boolean as $$
declare
result boolean := true;
keyname varchar;
i int := 1;
begin
if array_length(keynames, 1) = array_length(valuestrings, 1) then
perform key from keyval.strings where key = any(keynames) limit 1;
if found then
result := false;
else
foreach keyname in array keynames loop
update keyval.strings set value = valuestrings[i], updated_at = now() where key = keyname;
if not found then
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestrings[i], now(), now());
end if;
i := i + 1;
end loop;
end if;
else
raise exception 'The size of the "keynames" and "valuestrings" arguments must match!' using errcode = 'array_subscript_error';
end if;
return result;
end;
$$ language 'plpgsql';
-- KVMSETNXE: Sets all keys to their respective string values, if all of the keys specified have not been set already.
-- If any of the specified keys have already been set to a string value, this function will do nothing and raise an error.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuestrings text[]
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvmsetnx(array['a', 'b', 'c'], array['apple', 'banana', 'cherry']);
-- kvmsetnxe
-- -----------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvmsetnx(array['a', 'd', 'e'], array['apricot', 'date', 'eggplant']);
-- ERROR: One or more of the keynames provided already exist!
create or replace function kvmsetnxe(keynames varchar[], valuestrings text[]) returns void as $$
begin
if not kvmsetnx(keynames, valuestrings) then
raise exception 'One or more of the keynames provided already exist!' using errcode = 'unique_violation';
end if;
end;
$$ language 'plpgsql';
-- KVSET: Sets the key to hold a string value.
-- If key already holds a value, it is overwritten instead.
-- ARG1: keyname varchar
-- ARG2: valuestring text
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvset('abc', 'hello world');
-- kvset
-- -------
--
-- (1 row)
create or replace function kvset(keyname varchar, valuestring text) returns void as $$
begin
update keyval.strings set value = valuestring, updated_at = now() where key = keyname;
if not found then
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
end if;
end;
$$ language 'plpgsql';
-- KVSETNX: Sets the key to hold a string value, if the key does not exist, and returns TRUE.
-- If the key already has a value set, no change is made and FALSE is returned instead.
-- ARG1: keyname varchar
-- ARG2: valuestring text
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvsetnx('abc', 'hello world');
-- kvsetnx
-- ---------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvsetnx('abc', 'howdy partner');
-- kvsetnx
-- ---------
-- f
-- (1 row)
create or replace function kvsetnx(keyname varchar, valuestring text) returns boolean as $$
declare
result boolean := true;
begin
begin
insert into keyval.strings (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
exception when unique_violation then
result := false;
end;
return result;
end;
$$ language 'plpgsql';
-- KVSETNXE: Sets the key to hold a string value, if the key does not exist.
-- If the key already has a value set, no change is made and an raise an error.
-- ARG1: keyname varchar
-- ARG2: valuestring text
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvsetnx('abc', 'hello world');
-- kvsetnxe
-- ----------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvsetnxe('abc', 'howdy partner');
-- ERROR: The keyname provided already exists!
create or replace function kvsetnxe(keyname varchar, valuestring text) returns void as $$
begin
if not kvsetnx(keyname, valuestring) then
raise exception 'The keyname provided already exists!' using errcode = 'unique_violation';
end if;
end;
$$ language 'plpgsql';
-------------------------
-- Start Number Functions
-------------------------
-- KVNDEL: Deletes the number value held by the key and returns TRUE.
-- If the key does not exist, FALSE is returned instead.
-- ARG1: keyname varchar
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvndel('abc');
-- kvndel
-- --------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvndel('nonexistent');
--
-- kvndel
-- --------
-- f
-- (1 row)
create or replace function kvndel(keyname varchar) returns boolean as $$
declare
result boolean := false;
begin
delete from keyval.numbers where key = keyname;
if found then
result := true;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVNDELE: Deletes the number value held by the key.
-- If the key does not exist, an error is raised instead.
-- ARG1: keyname varchar
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvdele('abc');
-- kvndele
-- ---------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvndele('nonexistent');
-- ERROR: The keyname provided does not exists!
create or replace function kvndele(keyname varchar) returns void as $$
begin
if not kvndel(keyname) then
raise exception 'The keyname provided does not exist!' using errcode = 'no_data_found';
end if;
end;
$$ language 'plpgsql';
-- KVNGET: Returns the number value of the key.
-- If the key does not exist, NULL is returned instead.
-- ARG1: keyname varchar
-- RTRN: text
--
-- EXAMPLE 1:
-- select * from kvnget('abc');
-- kvnget
-- --------
-- 5
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnget('nonexistent');
-- kvnget
-- --------
-- <NULL>
-- (1 row)
create or replace function kvnget(keyname varchar) returns int as $$
declare
result int;
begin
select value from keyval.numbers where key = keyname into result;
return result;
end;
$$ language 'plpgsql';
-- KVNGETSET: Sets the key to hold a number value and returns the old value stored.
-- If no value was previously stored, NULL is returned instead.
-- ARG1: keyname varchar
-- ARG2: valuenumber int
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvgetset('abc', 3);
-- kvngetset
-- -----------
-- <NULL>
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvgetset('abc', 7);
-- kvngetset
-- -----------
-- 3
-- (1 row)
create or replace function kvngetset(keyname varchar, valuenumber int) returns int as $$
declare
result int;
begin
select value from keyval.numbers where key = keyname into result;
if found then
update keyval.numbers set value = valuenumber, updated_at = now() where key = keyname;
else
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuenumber, now(), now());
end if;
return result;
end;
$$ language 'plpgsql';
-- KVNINCRBY: Increments the value stored at the key by the number given.
-- If the key does not have a value, the number given becomes the new value instead.
-- ARG1: keyname varchar
-- ARG2: valuenumber int
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvnincrby('abc', 5);
-- kvnincrby
-- -----------
-- 5
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnincrby('abc', 3);
-- kvnincrby
-- -----------
-- 8
-- (1 row)
create or replace function kvnincrby(keyname varchar, valuenumber int) returns int as $$
declare
result int;
begin
update keyval.numbers set value = (value + valuenumber), updated_at = now() where key = keyname returning value into result;
if result is null then
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuenumber, now(), now());
result := valuenumber;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVNINCR: Increments the value stored at the key by 1.
-- If the key does not have a value, the new value becomes 1 instead.
-- ARG1: keyname varchar
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvincr('abc');
-- kvnincr
-- ---------
-- 9
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvincr('nonexistent');
-- kvnincr
-- ---------
-- 1
-- (1 row)
create or replace function kvnincr(keyname varchar) returns int as $$
begin
return kvnincrby(keyname, 1);
end;
$$ language 'plpgsql';
-- KVNDECRBY: Decrements the value stored at the key by the number given.
-- If the key does not have a value, the number given becomes the new negative value instead.
-- ARG1: keyname varchar
-- ARG2: valuenumber int
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvndecrby('abc', 2);
-- kvndecrby
-- -----------
-- 7
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvndecrby('nonexistent', 3);
-- kvndecrby
-- -----------
-- -3
-- (1 row)
create or replace function kvndecrby(keyname varchar, valuenumber int) returns int as $$
begin
return kvnincrby(keyname, (valuenumber - (valuenumber * 2)));
end;
$$ language 'plpgsql';
-- KVNDECR: Decrements the value stored at the key by 1.
-- If the key does not have a value, the new value becomes -1 instead.
-- ARG1: keyname varchar
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvndecr('abc');
-- kvndecr
-- ---------
-- 6
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvndecr('nonexistent');
-- kvndecr
-- ---------
-- -1
-- (1 row)
create or replace function kvndecr(keyname varchar) returns int as $$
begin
return kvndecrby(keyname, 1);
end;
$$ language 'plpgsql';
-- KVNMGET: Returns the key and number values of all specified keys.
-- For any keys specified that do not have a string value, NULL is returned instead.
-- ARG1: keynames varchar[]
-- RTRN: table(key varchar, value int)
--
-- EXAMPLE 1:
-- select * from kvnmget(array['abc', 'nonexistent', 'def', 'nonexistent']);
-- key | value
-- -------------+--------
-- abc | 3
-- nonexistent | <NULL>
-- def | 7
-- nonexistent | <NULL>
-- (4 rows)
create or replace function kvnmget(keynames varchar[]) returns table(key varchar, value int) as $$
begin
return query with
keys as (select unnest(keynames))
select keys.unnest, numbers.value from keys
left outer join keyval.numbers on numbers.key = keys.unnest;
end;
$$ language 'plpgsql';
-- KVNMSET: Sets all keys to their respective number values.
-- For any keys that already hold a value, they will be overwritten instead.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuenumbers int[]
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvnmset(array['a', 'b', 'c'], array[1, 2, 3]);
-- kvnmset
-- ---------
--
-- (1 row)
create or replace function kvnmset(keynames varchar[], valuenumbers int[]) returns void as $$
declare
keyname varchar;
i int := 1;
begin
if array_length(keynames, 1) = array_length(valuenumbers, 1) then
foreach keyname in array keynames loop
update keyval.numbers set value = valuenumbers[i], updated_at = now() where key = keyname;
if not found then
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuenumbers[i], now(), now());
end if;
i := i + 1;
end loop;
else
raise exception 'The size of the "keynames" and "valuenumbers" arguments must match!' using errcode = 'array_subscript_error';
end if;
end;
$$ language 'plpgsql';
-- KVNMSETNX: Sets all keys to their respective number values, if all of the keys specified have not been set already and returns TRUE.
-- If any of the specified keys have already been set to a number value, this function will do nothing and return FALSE instead.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuenumbers int[]
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvnmsetnx(array['a', 'b', 'c'], array[1, 2, 3]);
-- kvnmsetnx
-- -----------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnmsetnx(array['a', 'd', 'e'], array[4, 5, 6]);
-- kvnmsetnx
-- -----------
-- f
-- (1 row)
create or replace function kvnmsetnx(keynames varchar[], valuenumbers int[]) returns boolean as $$
declare
result boolean := true;
keyname varchar;
i int := 1;
begin
if array_length(keynames, 1) = array_length(valuenumbers, 1) then
perform key from keyval.numbers where key = any(keynames) limit 1;
if found then
result := false;
else
foreach keyname in array keynames loop
update keyval.numbers set value = valuenumbers[i], updated_at = now() where key = keyname;
if not found then
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuenumbers[i], now(), now());
end if;
i := i + 1;
end loop;
end if;
else
raise exception 'The size of the "keynames" and "valuenumbers" arguments must match!' using errcode = 'array_subscript_error';
end if;
return result;
end;
$$ language 'plpgsql';
-- KVNMSETNX: Sets all keys to their respective number values, if all of the keys specified have not been set already.
-- If any of the specified keys have already been set to a number value, this function will do nothing and raise an error.
-- If more keys then values are given, an error will be raised.
-- If more values then keys are given, an error will be raised.
-- ARG1: keynames varchar[]
-- ARG2: valuenumbers int[]
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvnmsetnxe(array['a', 'b', 'c'], array[1, 2, 3]);
-- kvnmsetnxe
-- ------------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnmsetnxe(array['a', 'd', 'e'], array[4, 5, 6]);
-- ERROR: One or more of the keynames provided already exist!
create or replace function kvnmsetnxe(keynames varchar[], valuenumbers int[]) returns void as $$
begin
if not kvnmsetnx(keynames, valuenumbers) then
raise exception 'One or more of the keynames provided already exist!' using errcode = 'no_data_found';
end if;
end;
$$ language 'plpgsql';
-- KVNSET: Sets the key to hold a number value.
-- If key already holds a value, it is overwritten instead.
-- ARG1: keyname varchar
-- ARG2: valuestring int
-- RTRN: void
--
-- EXAMPLE 1:
-- select * from kvnset('abc', 'hello world');
-- kvnset
-- --------
--
-- (1 row)
create or replace function kvnset(keyname varchar, valuestring int) returns void as $$
begin
update keyval.numbers set value = valuestring, updated_at = now() where key = keyname;
if not found then
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
end if;
end;
$$ language 'plpgsql';
-- KVNSETNX: Sets the key to hold a number value, if the key does not exist, and returns TRUE.
-- If the key already has a value set, no change is made and FALSE is returned instead.
-- ARG1: keyname varchar
-- ARG2: valuestring int
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvnsetnx('abc', 3);
-- kvnsetnx
-- ----------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnsetnx('abc', 7);
-- kvnsetnx
-- ----------
-- f
-- (1 row)
create or replace function kvnsetnx(keyname varchar, valuestring int) returns boolean as $$
declare
result boolean := true;
begin
begin
insert into keyval.numbers (key, value, created_at, updated_at) values (keyname, valuestring, now(), now());
exception when unique_violation then
result := false;
end;
return result;
end;
$$ language 'plpgsql';
-- KVNSETNXE: Sets the key to hold a number value, if the key does not exist.
-- If the key already has a value set, no change is made and an raise an error.
-- ARG1: keyname varchar
-- ARG2: valuenumber int
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvnsetnxe('abc', 3);
-- kvnsetnxe
-- -----------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvnsetnxe('abc', 7);
-- ERROR: The keyname provided already exists!
create or replace function kvnsetnxe(keyname varchar, valuenumber int) returns void as $$
begin
if not kvnsetnx(keyname, valuenumber) then
raise exception 'The keyname provided already exists!' using errcode = 'unique_violation';
end if;
end;
$$ language 'plpgsql';
-----------------------
-- Start List Functions
-----------------------
-- KVLDEL: Deletes the entire list held by the key and returns TRUE.
-- If the key does not exist, FALSE is returned instead.
-- ARG1: keyname varchar
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvldel('abc');
-- kvldel
-- --------
-- t
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvldel('nonexistent');
-- kvldel
-- --------
-- f
create or replace function kvldel(keyname varchar) returns boolean as $$
declare
result boolean := true;
begin
delete from keyval.lists where key = keyname;
if not found then
result := false;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVLDEL: Deletes the entire list held by the key.
-- If the key does not exist, an error is raised instead.
-- ARG1: keyname varchar
-- RTRN: boolean
--
-- EXAMPLE 1:
-- select * from kvldel('abc');
-- kvldel
-- --------
--
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvldel('nonexistent');
-- ERROR: The keyname provided does not exist!
create or replace function kvldele(keyname varchar) returns void as $$
begin
if not kvldel(keyname) then
raise exception 'The keyname provided does not exist!' using errcode = 'no_data_found';
end if;
end;
$$ language 'plpgsql';
-- KVLINDEX: When given a valuestring, the index first element found at the specified list is returned.
-- If the specified list does not have the valuestring, NULL is returned instead.
-- If there is no list stored at the key, NULL is also returned instead.
--
-- EXAMPLE 1:
-- select * from kvlindex('greeting', 'world');
-- kvlindex
-- ----------
-- 2
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvlindex('greeting', 'banana');
-- kvlindex
-- ----------
--
-- (1 row)
--
-- EXAMPLE 3:
-- select * from kvlindex('nonexistent', 'nonexistent');
-- kvlindex
-- ----------
--
-- (1 row)
create or replace function kvlindex(keyname varchar, valuestring text, out kvlindex int) as $$
begin
with
list as (select unnest(value) from keyval.lists where key = keyname),
list_with_index as (select row_number() over (), unnest from list)
select row_number from list_with_index where unnest = valuestring limit 1 into kvlindex;
end;
$$ language 'plpgsql';
-- KVLLEN: Returns the length of the list value of the key.
-- If no value was previously stored, NULL is returned instead.
-- ARG1: keyname varchar
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvllen('tripple');
-- kvllen
-- --------
-- 3
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvllen('nonexistent');
-- kvllen
-- --------
--
-- (1 row)
create or replace function kvllen(keyname varchar) returns int as $$
declare
result int;
begin
select array_length(value, 1) from keyval.lists where key = keyname into result;
if not found then
result := null;
end if;
return result;
end;
$$ language 'plpgsql';
-- KVLGET: Returns the string value stored in the list index at the key specified.
-- If no value was found at the list or they key, NULL is returned instead.
-- ARG1: keyname varchar
-- ARG2: listindex int
-- RTRN: int
--
-- EXAMPLE 1:
-- select * from kvlget('fruits', 2);
-- kvlget
-- --------
-- banana
-- (1 row)
--
-- EXAMPLE 2:
-- select * from kvlget('fruits', 999);
-- kvlget
-- --------
--
-- (1 row)
--
-- EXAMPLE 3:
-- select * from kvllen('nonexistent', 1);
-- kvllen
-- --------