Re: How to pass a list of locations (longitude, latitude) to a PostgreSQL/PostGIS stored function? - Mailing list pgsql-general

From Tom Lane
Subject Re: How to pass a list of locations (longitude, latitude) to a PostgreSQL/PostGIS stored function?
Date
Msg-id 1284143.1742922449@sss.pgh.pa.us
Whole thread Raw
In response to How to pass a list of locations (longitude, latitude) to a PostgreSQL/PostGIS stored function?  (Alexander Farber <alexander.farber@gmail.com>)
Responses Re: How to pass a list of locations (longitude, latitude) to a PostgreSQL/PostGIS stored function?
Re: How to pass a list of locations (longitude, latitude) to a PostgreSQL/PostGIS stored function?
List pgsql-general
Alexander Farber <alexander.farber@gmail.com> writes:
> Then I am trying to add a function, which would receive a series of
> locations (longitude and latitude pairs in microdegrees) and return a list
> of lowercase 2-letter country codes, like "de", "pl", "lv":

>     CREATE OR REPLACE FUNCTION find_countries(locations BIGINT[][])
>     RETURNS TABLE (country TEXT) AS $$

Postgres isn't too friendly to representing a list of locations as
a 2-D array, because we generally don't treat arrays as being
arrays-of-arrays, so unnest produces a set of bigints not a set
of smaller arrays.  You might be best advised to create a composite
type like "location (long bigint, lat bigint)" and use an array of
that.  If you're really hot to use a 2-D array, the only construct
I can think of that's on board with unnesting that the way you need
is plpgsql's FOREACH SLICE syntax:

https://www.postgresql.org/docs/devel/plpgsql-control-structures.html#PLPGSQL-FOREACH-ARRAY

You could probably make a custom version of unnest that uses that
and then keep your query about the same.

            regards, tom lane



pgsql-general by date:

Previous
From: Christophe Pettus
Date:
Subject: Re: Replication slot WAL reservation
Next
From: Christophe Pettus
Date:
Subject: Re: Replication slot WAL reservation