Thread: How to count the number of items in an Array?
Hi,
I have googled, but I can't find how to count the number of items in an Array in Plpgsql.
Someone can give me a clue on that?
Best Regads,
Andre Lopes <lopes80andre@gmail.com> wrote: > Hi, > > I have googled, but I can't find how to count the number of items in an Array > in Plpgsql. > > Someone can give me a clue on that? Sure, you can use array_upper() - array_lower(): Zeit: 0,205 ms test=*# select array_upper(array[1,2,3],1) - array_lower(array[1,2,3],1); ?column? ---------- 2 (1 Zeile) or: test=*# select array_upper(array[1,2,3],1) - array_lower(array[1,2,3],1) + 1; ?column? ---------- 3 (1 Zeile) Or, if your array starts with the first element, simple: test=*# select array_upper(array[1,2,3,NULL,5],1); array_upper ------------- 5 (1 Zeile) Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
Hi,
Thanks for the reply.
My problem is that I can't have the array with all items. I need to read from a table and store in an Array the values.
I have this:
[code]
CREATE OR REPLACE FUNCTION "public"."apr_update_newsletter_distritos" ("pEMAIL" varchar, "pID_WEBSITE_RECOLHA" varchar) RETURNS void AS
$body$
DECLARE
pEMAIL alias for $1; -- vai ser preciso
pID_WEBSITE_RECOLHA alias for $2; -- vai ser preciso
vDISTRITOS_NA_TABELA varchar[];
vDISTRITOS_NA_TABELA_CONST varchar[];
vd integer;
vas varchar;
BEGIN
-- ### Vou gravar num array os registos da chave em q se vai mexer
-- vou entao passar os registos para o array vDISTRITOS_NA_TABELA
FOR vDISTRITOS_NA_TABELA IN
SELECT array[id_distrito] FROM am_newsletter_distritos
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
LOOP
RAISE NOTICE 'value: %', vDISTRITOS_NA_TABELA;
END LOOP;
-- array 2 string
select array_to_string(vDISTRITOS_NA_TABELA, ',') into vas;
RAISE NOTICE 'string with items of array: %', vas;
-- Vou contar o número dos registos do array
-- select array_upper(vDISTRITOS_NA_TABELA, 1) into vd;
-- RAISE NOTICE 'num array: %', vd;
END;
$body$
LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
$body$
DECLARE
pEMAIL alias for $1; -- vai ser preciso
pID_WEBSITE_RECOLHA alias for $2; -- vai ser preciso
vDISTRITOS_NA_TABELA varchar[];
vDISTRITOS_NA_TABELA_CONST varchar[];
vd integer;
vas varchar;
BEGIN
-- ### Vou gravar num array os registos da chave em q se vai mexer
-- vou entao passar os registos para o array vDISTRITOS_NA_TABELA
FOR vDISTRITOS_NA_TABELA IN
SELECT array[id_distrito] FROM am_newsletter_distritos
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
LOOP
RAISE NOTICE 'value: %', vDISTRITOS_NA_TABELA;
END LOOP;
-- array 2 string
select array_to_string(vDISTRITOS_NA_TABELA, ',') into vas;
RAISE NOTICE 'string with items of array: %', vas;
-- Vou contar o número dos registos do array
-- select array_upper(vDISTRITOS_NA_TABELA, 1) into vd;
-- RAISE NOTICE 'num array: %', vd;
END;
$body$
LANGUAGE 'plpgsql' VOLATILE CALLED ON NULL INPUT SECURITY INVOKER;
[/code]
This select returns me 4 values:
[code]
SELECT array[id_distrito] FROM am_newsletter_distritos
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
[/code]
The values are '11, 12,16, 16'. I haven't found a way to store this as an array to the variable vDISTRITOS_NA_TABELA. Someone can give me a clue on how to do that?
Best Regards,
On Sun, Feb 21, 2010 at 8:38 AM, Andreas Kretschmer <akretschmer@spamfence.net> wrote:
Sure, you can use array_upper() - array_lower():Andre Lopes <lopes80andre@gmail.com> wrote:
> Hi,
>
> I have googled, but I can't find how to count the number of items in an Array
> in Plpgsql.
>
> Someone can give me a clue on that?
Zeit: 0,205 ms
test=*# select array_upper(array[1,2,3],1) - array_lower(array[1,2,3],1);
?column?
----------
2
(1 Zeile)
or:
test=*# select array_upper(array[1,2,3],1) - array_lower(array[1,2,3],1) + 1;
?column?
----------
3
(1 Zeile)
Or, if your array starts with the first element, simple:
test=*# select array_upper(array[1,2,3,NULL,5],1);
array_upper
-------------
5
(1 Zeile)
Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Andre Lopes <lopes80andre@gmail.com> wrote: > Hi, > > Thanks for the reply. > > My problem is that I can't have the array with all items. I need to read from a > table and store in an Array the values. Not sure if i understand you, but how about: test=*# select * from foo; a --- 1 3 5 7 (4 Zeilen) Zeit: 0,203 ms test=*# select array_agg(a) from foo; array_agg ----------- {1,3,5,7} (1 Zeile) The function returns a column as an array. Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
One more time, thanks for the reply. I'am using postgre 8.3. I think I don't have the array_agg(), there is another way of doing it?
Best Regards,
On Sun, Feb 21, 2010 at 2:46 PM, Andreas Kretschmer <akretschmer@spamfence.net> wrote:
> Thanks for the reply.Not sure if i understand you, but how about:
>
> My problem is that I can't have the array with all items. I need to read from a
> table and store in an Array the values.
test=*# select * from foo;
a
---
1
3
5
7
(4 Zeilen)
Zeit: 0,203 ms
test=*# select array_agg(a) from foo;
array_agg
-----------
{1,3,5,7}
(1 Zeile)
The function returns a column as an array.
Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general
Andre Lopes <lopes80andre@gmail.com> wrote: > One more time, thanks for the reply. I'am using postgre 8.3. I think I don't > have the array_agg(), there is another way of doing it? Sure. The doc contains an example for a user-defined aggregate-function: http://www.postgresql.org/docs/8.4/interactive/xaggr.html It works with versions prior 8.4. test=*# CREATE AGGREGATE array_accum (anyelement) test-# ( test(# sfunc = array_append, test(# stype = anyarray, test(# initcond = '{}' test(# ); CREATE AGGREGATE Zeit: 44,645 ms test=*# select array_accum(a) from foo; array_accum ------------- {1,3,5,7} (1 Zeile) Andreas -- Really, I'm not out to destroy Microsoft. That will just be a completely unintentional side effect. (Linus Torvalds) "If I was god, I would recompile penguin with --enable-fly." (unknown) Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
Hi,
Thanks for the reply.
I have done it in this way:
[code]
FOR vDISTRITOS_NA_TABELA IN
SELECT array[id_distrito] FROM am_newsletter_distritos
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
LOOP
vDISTRITOS_NA_TABELA_CONST := vDISTRITOS_NA_TABELA_CONST || vDISTRITOS_NA_TABELA;
END LOOP;
SELECT array[id_distrito] FROM am_newsletter_distritos
WHERE email = pEMAIL and id_website_recolha = pID_WEBSITE_RECOLHA
LOOP
vDISTRITOS_NA_TABELA_CONST := vDISTRITOS_NA_TABELA_CONST || vDISTRITOS_NA_TABELA;
END LOOP;
[/code]
Best Regards,
On Sun, Feb 21, 2010 at 3:25 PM, Andreas Kretschmer <akretschmer@spamfence.net> wrote:
> One more time, thanks for the reply. I'am using postgre 8.3. I think I don'tSure.
> have the array_agg(), there is another way of doing it?
The doc contains an example for a user-defined aggregate-function:
http://www.postgresql.org/docs/8.4/interactive/xaggr.html
It works with versions prior 8.4.
test=*# CREATE AGGREGATE array_accum (anyelement)
test-# (
test(# sfunc = array_append,
test(# stype = anyarray,
test(# initcond = '{}'
test(# );
CREATE AGGREGATE
Zeit: 44,645 ms
test=*# select array_accum(a) from foo;
array_accum
-------------{1,3,5,7}
(1 Zeile)Andreas
--
Really, I'm not out to destroy Microsoft. That will just be a completely
unintentional side effect. (Linus Torvalds)
"If I was god, I would recompile penguin with --enable-fly." (unknown)
Kaufbach, Saxony, Germany, Europe. N 51.05082°, E 13.56889°
--
Sent via pgsql-general mailing list (pgsql-general@postgresql.org)
To make changes to your subscription:
http://www.postgresql.org/mailpref/pgsql-general