Question about rounding the points in a Geometry.

  • Here's a POLYGON from my MS SQL 2008 database that I pulled to use here as an example:

    POLYGON ((-64.8040519990027 18.366768000647426, -64.8011230006814 18.367451999336481, -64.797389999032021 18.369273999705911, -64.8034599982202 18.368359999731183,

    ...trunkated for readability...

    -64.703370001167059 18.301725000143051, -64.703745998442173 18.29857200011611, -64.7031709998846 18.298143999651074))

    Notice how many digits are involved in each x/y coordinate, this happens after I run STUnion() or STBuffer() on the polygon. Originally, each x/y coordinate was up to six decimal places before running one of these functions on it. And it is important that I use these two functions for my application. However, I'm dealing with a lot of polygons and the extra digits are creating way too much overhead in my app.

    My question: Does anyone know a way to round each x/y coordinate to the nearest, say, six decimal places? Where the first point, "-64.8040519990027 18.366768000647426" can be converted to "-64.804051 18.366768" and so on for the rest of the points. Or is there any way to truncate the points to the sixth digit (where it just cuts off the excess digits without rounding). I've been searching for a solution to this for days and haven't found anything yet. I figured posting on here would be a good shot.

    Any help in this area would be truly appreciated.

    Thanks

  • P.S. - I'm sure I could convert the POLYGON to text (using STAsText), parse through each number to round each coordinate, and then convert it back to a geometry (using STPolyFromText) but I'm hoping there's a more efficient way to do it.

  • If I understand the Geometry construct correctly, (and I'm not claiming to be an expert here, this is just based on frustrating experiences) the latitude and longitude values are stored internally as 'float', and reducing the accuracy is not going to solve your 'overhead' problem. I think there is a different issue here that you may want to address, and that is the number of additional points introduced into a geography/geometry by using STBuffer() - as a quick example try running the following code:

    DECLARE @g geometry;

    SET @g = geometry::STGeomFromText('POLYGON((0 2, 2 0, 4 2, 0 2))', 0);

    SELECT @g.STNumPoints() as PointCount,

    @g.STBuffer(0.00001).STNumPoints() as countAfterBuffer;

    One solution to your 'overhead' could be to just rein in the number of points created by the .STBuffer() function by following it with .Reduce(n) (depending on your requirements for using STBuffer in the first place, you will need to play around with values of n to get a reasonable number of points without sacrificing accuracy of the geometry)

    DECLARE @g geometry;

    SET @g = geometry::STGeomFromText('POLYGON((0 2, 2 0, 4 2, 0 2))', 0);

    SELECT @g.STNumPoints() as PointCount,

    @g.STBuffer(0.00001).STNumPoints() as countAfterBuffer,

    @g.STBuffer(0.00001).Reduce(0.01).STNumPoints() as countAfterReduce;

    I suspect that reducing the number of points in your buffered geometries will give a better performance increase than rounding the accuracy of the points. See how it goes, if it is still necessary to truncate the points after trying this, then maybe I can help. I am currently working on 'dismantling' aggregated geometries to feed into HTML for google maps, and encountered a similar issue. I used the following code snippet to generate the HTML string to create the polygon, with accuracy of the points rounded to 6 decimal places by converting float to STR ... which is also the only way I could find to get a FLOAT value into a CHAR format.

    DECLARE @g geometry;

    SET @g = geometry::STGeomFromText('POLYGON((0 2, 2 0, 4 2, 0 2))', 0);

    SELECT 'var L=google.maps.LatLng;'

    UNION ALL

    SELECT 'var polyg = ['

    UNION ALL

    SELECT 'new L(' + str(@g.STPointN(n).STY, 10,6)+','

    + str(@g.STPointN(n).STX, 10,6) +'),'

    from dbo.Tally where N < @g.STNumPoints()

    UNION ALL

    SELECT 'new L(' + str(@g.STPointN(n).STY, 10,6)+','

    + str(@g.STPointN(n).STX, 10,6) +')'

    from dbo.Tally where N = @g.STNumPoints()

    UNION ALL

    SELECT '];'

    Note: the code snippet above uses a 'tally table' to walk through the points of the geometry, but it is only working for geometries with a single polygon - ie @g.STNumGeometries() = 1 ... if anyone could point me to a way of using tally tables to process nested loops I would be very grateful. I need to generate the above sequence for each polygon in @g.STGeometryN(x) (where x <= @g.STNumGeometries()) then add a couple of lines of code after each polygon to add it to the map. Thanks.

  • zerko (1/17/2013)


    ... if anyone could point me to a way of using tally tables to process nested loops I would be very grateful. I need to generate the above sequence for each polygon in @g.STGeometryN(x) (where x <= @g.STNumGeometries()) then add a couple of lines of code after each polygon to add it to the map. Thanks.

    Could you do something like:

    FROM dbo.Tally a

    CROSS APPLY dbo.Tally b

    And then use a.n for the inner loop and b.n as the outer loop of the nested loops?


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Thanks Dwain,

    OK it's not pretty because of all the slicing and dicing of the geometries into sub-geometries, then points, then X's and Y's then assembling into a formatted string, then adding pre- and post - text strings, (which I've removed from the code here, but still not talking correctly to the google maps API) then adding sort orders so the text lines came out in the right sequence ...

    BUT ...

    for my first venture into the world of Cross Apply, it did work!

    DECLARE @g geometry;

    --Create a multi-polygon geometry

    SET @g = geometry::STGeomFromText('POLYGON((0 2, 2 0, 4 2, 0 2))', 0)

    SELECT @g = @g.STUnion(geometry::STGeomFromText('POLYGON((3 3, 3 4, 4 4, 3 3))',0));

    IF @g.STNumGeometries() > 1 PRINT 'Multi-polygon detected';

    SELECT c.LineText FROM dbo.tally a

    CROSS APPLY

    (SELECT 0 as N, 'var polyg = [' as LineText UNION ALL

    -- this line appears first, so sort order is zero

    SELECT b.N, 'new L(' + str(@g.STGeometryN(a.N).STPointN(b.N).STY, 10,6)+','

    + str(@g.STGeometryN(a.N).STPointN(n).STX, 10,6) +'),'

    FROM dbo.Tally b where b.N < @g.STGeometryN(a.N).STNumPoints()

    UNION ALL

    SELECT b.N, 'new L(' + str(@g.STGeometryN(a.N).STPointN(b.N).STY, 10,6)+','

    + str(@g.STGeometryN(a.N).STPointN(n).STX, 10,6) +')'

    FROM dbo.Tally b where b.N = @g.STGeometryN(a.N).STNumPoints()

    -- above select is for the last line of the list, no trailing comma

    -- following lines sort to appear after each geometry definition list

    UNION ALL Select @g.STGeometryN(a.N).STNumPoints() + 1, '];'

    UNION ALL Select @g.STGeometryN(a.N).STNumPoints() + 2, '//map cmds here//;'

    ) c

    WHERE a.N <= @g.STNumGeometries() --and a.N = 1

    order by a.N, c.N;

    As an added bonus, it also works if I throw a single polygon geometry at it.

  • Glad to hear my off-the-cuff idea worked!

    Thanks for the feedback as I don't believe I've actually tried it myself. 🙂


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

  • Hi

    If you are working with Lat/Lon coordinates, you probably should use the Geography data type rather than the Geometry. Unfortunately these data types do use float to store the coordinates with the inherent issues that they have. Basically any method that returns a geometry will likely cause slight shifts to the points. The one that annoys me the most is MakeValid(). The good news is 2012 uses a higher precision float than 2008, but you still get the shift all be it smaller.

    Zerko, another thing you may want to consider when breaking apart your polygons is polygons with interior rings (donuts). I usually break the polygons into parts and then into rings.

    Here's an example

    CREATE TABLE #rings (RegisterID int not null, PartNum int not null, RingNum int not null, Ring Geometry, NumPoints int);

    ALTER TABLE #rings ADD CONSTRAINT rings_pk PRIMARY KEY (RegisterId, PartNum, RingNum);

    ;WITH

    e1(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    ),

    e2(N) AS (SELECT 1 FROM E1 a, E1 b), --100

    --e3(N) AS (SELECT 1 FROM E2 a, E2 b), --10000

    cteTally(N) AS (

    SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) N

    FROM e2

    ),

    -- Get Individual polygons from Geometry

    GetPolygonParts AS (

    SELECT RegisterID,

    RegisteredExtent.STGeometryN(t.N) Part,

    RegisteredExtent.STGeometryN(t.N).STNumPoints() NumPoints,

    t.N PartNum

    FROM Register a

    CROSS APPLY (select TOP(a.RegisteredExtent.STNumGeometries()) n from cteTally z ) t

    WHERE RegisteredExtent is not null

    ),

    -- Split to internal and external rings

    GetRings AS (

    SELECT a.RegisterID, a.PartNum, 0 RingNum,

    Part.STExteriorRing() Ring, Part.STExteriorRing().STNumPoints() NumPoints

    FROM GetPolygonParts a

    UNION ALL

    SELECT a.RegisterID, a.PartNum, t.N RingNum,

    Part.STInteriorRingN(t.N) Ring, Part.STInteriorRingN(t.N).STNumPoints() NumPoints

    FROM GetPolygonParts a

    CROSS APPLY (select TOP(a.Part.STNumInteriorRing()) n from cteTally z ) t

    )

    INSERT INTO #rings SELECT * FROM GetRings

    CREATE TABLE #coords (RegisterID int not null, PartNum int not null, RingNum int not null, X float not null, Y float not null)

    ALTER TABLE #coords ADD CONSTRAINT int_pk PRIMARY KEY (RegisterId, PartNum, RingNum, x, y);

    ;WITH

    e1(N) AS (SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1

    ),

    e2(N) AS (SELECT 1 FROM E1 a, E1 b), --100

    e3(N) AS (SELECT 1 FROM E2 a, E2 b), --10000

    cteTally(N) AS (

    SELECT ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) N

    FROM e3

    ),

    GetRingCoords AS (

    SELECT RegisterID, p.PartNum, p.RingNum

    ,p.Ring.STPointN(t.N).STX X, p.Ring.STPointN(t.N).STY Y

    FROM #rings p

    CROSS APPLY (select TOP (p.NumPoints - 1) n from cteTally z) t

    )

    INSERT INTO #coords SELECT * FROM GetRingCoords

    Putting them together into another format from that should be relatively easy. I found it worked better with the TOP clause in the cross apply.

    I use a double cast to put the coordinates into a varchar ... CAST(CAST(@x AS NUMERIC(10,6)) AS VARCHAR(11))

    -Micky

Viewing 7 posts - 1 through 6 (of 6 total)

You must be logged in to reply to this topic. Login to reply