You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Now you are ready to use fields such as Geo.PostGIS.Geometry in your schemas.
For example, I want to create the type "LINESTRING" with GEOGRAPHY and the 4326 projection (the one used by the GPS), so in a migration:
NB: if you are looking for distances between geometries in your dataset, for example a nearest neighbour search, you may want to use a special spatial index GIST. This will accelerate the spatial queries (at the cost of space in your db) and allow the usage of the distance operator <->.
Tested on finding among 1000 geometries the nearest geometries within a given distance to a point. The results for the first search give a response of < 100ms, and then < 10ms for consecutive searches.
# migrationdefupdo...execute("CREATE INDEX events_gix ON events USING GIST (coordinates);")end
You are also likely to use GeoJSON format (but not restricted to). You can render this format with Postgis. An example of query using the distance <-> operator, the ST_Distance function, the ST_MakePoint function and rendering in GeoJSON format. You will be able to send this data directly to a Javascript library (LeafletJS or maplibre) and render the GeoJSON format easily.
If you don't want GeoJSON formatted results but rather use your schema, prepare this query:
SELECTevents.id, events.user_id, users.email, events.ad1, events.ad2, events.date, events.color, events.coordinates,
events.coordinates<-> ST_MakePoint($1,$2) AS sphere_graphy
FROM events
INNER JOIN users ONevents.user_id=users.idINNER JOIN event_participants AS ep onevents.id=ep.event_idWHEREevents.date>= $4::dateANDevents.date<= $5::dateAND
ST_Distance(ST_MakePoint($1,$2),events.coordinates) < $3;
And run this query with Ecto and load the results using your schema: (note that the Postgres placeholders $i are interpolated with a list, the second argument of Repo.query function).
I understand you have a DIY method and calculate the distance yourself and check against the whole ETS/DB. You could have saved on computations in your calc_distance by doing a flat world approximation since you are working locally instead of doing spherique computations. I did use Postgres functions. It is programmed in C so way faster than the old Erlang. I observed that the query becomes quickly more efficient as you submit more queries, and very quickly the response time is almost independent of the number of new entries (talking < 20ms for 500 entries). This means it builds up a spatial GIST index very efficiently but I understood this is costly in terms of disk space.
Guide on how to use
Postgis
withPhoenix
Once you created the Postgis extension,
you may want to use the package
geo_postgis
to use the types Postgis provides as fields in migration and schemaAdd it to your mix:
Configure it. In the "config.exs", if you use
Jason
, declare:and declare the Postgis types:
so create a module
my_app/postgres_types.ex
:Now you are ready to use fields such as
Geo.PostGIS.Geometry
in your schemas.For example, I want to create the type "LINESTRING" with GEOGRAPHY and the 4326 projection (the one used by the GPS), so in a migration:
NB: if you are looking for distances between geometries in your dataset, for example a nearest neighbour search, you may want to use a special spatial index GIST. This will accelerate the spatial queries (at the cost of space in your db) and allow the usage of the distance operator <->.
Tested on finding among 1000 geometries the nearest geometries within a given distance to a point. The results for the first search give a response of < 100ms, and then < 10ms for consecutive searches.
and in your schema, you can use it:
You are also likely to use GeoJSON format (but not restricted to). You can render this format with Postgis. An example of query using the distance
<->
operator, theST_Distance
function, theST_MakePoint
function and rendering inGeoJSON
format. You will be able to send this data directly to a Javascript library (LeafletJS
ormaplibre
) and render the GeoJSON format easily.If you don't want GeoJSON formatted results but rather use your schema, prepare this query:
And run this query with Ecto and load the results using your schema: (note that the Postgres placeholders
$i
are interpolated with a list, the second argument ofRepo.query
function).The text was updated successfully, but these errors were encountered: