ST_PointN takes an ST_LineString and an integer index and returns a point that is the nth vertex in the ST_LineString's path.
Oracle
sde.st_pointn (ln1 sde.st_linestring, index integer)
PostgreSQL
st_pointn (ln1 st_linestring, index integer)
The pointn_test table is created with the gid column, which uniquely identifies each row, and the ln1 ST_LineString column. The INSERT statements insert two linestring values. The first linestring doesn't have z-coordinates or measures, while the second linestring has both.
Oracle
CREATE TABLE pointn_test (gid integer, ln1 sde.st_geometry);
INSERT INTO pointn_test VALUES (
1,
sde.st_linefromtext ('linestring (10.02 20.01, 23.73 21.92, 30.10 40.23)', 0)
);
INSERT INTO pointn_test VALUES (
2,
sde.st_linefromtext ('linestring zm(10.02 20.01 5.0 7.0, 23.73 21.92 6.5 7.1, 30.10 40.23 6.9 7.2)', 0)
);
PostgreSQL
CREATE TABLE pointn_test (gid integer, ln1 st_geometry);
INSERT INTO pointn_test VALUES (
1,
st_linestring ('linestring (10.02 20.01, 23.73 21.92, 30.10 40.23)', 0)
);
INSERT INTO pointn_test VALUES (
2,
st_linestring ('linestring zm(10.02 20.01 5.0 7.0, 23.73 21.92 6.5 7.1, 30.10 40.23 6.9 7.2)', 0)
);
The query lists the gid column and the second vertex of each linestring. The first row results in an ST_Point without a z-coordinate or measure, while the second row results in an ST_Point with a z-coordinate and a measure. The ST_PointN function will also include a z-coordinate or measure value if they exist in the source linestring.
Oracle
SELECT gid, sde.st_astext (sde.st_pointn (ln1, 2)) The_2ndvertex
FROM pointn_test;
GID The_2ndvertex
1 POINT (23.73 21.92)
2 POINT ZM (23.73 21.92 6.5 7.1)
PostgreSQL
SELECT gid, st_astext (st_pointn (ln1, 2)) AS The_2ndvertex
FROM pointn_test;
gid the_2ndvertex
1 POINT (23.73 21.92)
2 POINT ZM (23.73 21.92 6.5 7.1)