PL/pgSQL Array Listing
Somebody asked me how to navigate a collection in PostgreSQL’s PL/pgSQL and whether they supported table and varray data types, like Oracle’s PL/SQL. The most important thing to correct was that PostgreSQL supports only array types.
The only example that I found with a google search used a FOREACH-loop, like this:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 | DO $$ DECLARE /* An array of integers. */ list int[] = array[1,2,3,4,5]; /* Define a local variable for array members. */ i int; BEGIN /* Loop through the integers. */ FOREACH i IN ARRAY list LOOP RAISE NOTICE '[%]', i; END LOOP; END; $$; |
It prints:
NOTICE: [1] NOTICE: [2] NOTICE: [3] NOTICE: [4] NOTICE: [5] |
As I suspected the student didn’t want to use a FOREACH-loop. The student wanted to use a for-loop, which was much closer to the Oracle PL/SQL syntax with which they were most familiar. That example is:
1 2 3 4 5 6 7 8 9 10 11 12 | DO $$ DECLARE /* An array of integers. */ list int[] = array[1,2,3,4,5]; BEGIN /* Loop through the integers. */ FOR i IN 1..5 LOOP RAISE NOTICE '[%]', list[i]; END LOOP; END; $$; |
However, it’s bad form to use a literal for the upper number in a range for-loop, and you should use the CARDINALITY function in PostgreSQL because there is no collection API, like Oracle’s COUNT method. There is an ARRAY_LENGTH function but it’s really only necessary when you use a multidimensional array.
The modified code is:
1 2 3 4 5 6 7 8 9 10 11 12 | DO $$ DECLARE -- An array of integers. list int[] = array[1,2,3,4,5]; BEGIN /* Loop through the integers. */ FOR i IN 1..CARDINALITY(list) LOOP RAISE NOTICE '[%]', list[i]; END LOOP; END; $$; |
If you use the ARRAY_LENGTH function, line #8 would look like:
7 8 | /* Loop through the integers, and determines the length of the first dimension. */ FOR i IN 1..ARRAY_LENGTH(list,1) LOOP |
As always, I hope this helps those looking for a clear solution to basic activities.