Go to content Go to navigation and search

Home

Current SQL Server Blog Articles


Search

Browse

RSS / Atom

Email me

textpattern

Creative Commons License
All Blog Articles, Data Models and Free Source Code by Simon Greener, The SpatialDB Advisor is licensed under a Creative Commons Attribution-ShareAlike 3.0 Unported License.

Tip #3: What object is that?

Saturday November 24 2007 at 04:22

In Oracle, if I want to know what type of SDO_Geometry object is stored in a column I can do the following:

gis@XE> select a.geom.get_gtype(), count(*)
  2  from tas_lga a
  3* group by a.geom.get_gtype();
A.GEOM.GET_GTYPE()   COUNT(*)
------------------ ----------
                 3          9
                 7         20

However, we have to be able to “interpret” the returned value from get_gtype() in order to understand what the numbers mean. So, let’s “tart up” the output …

gis@XE>  select case a.geom.get_gtype()
  2         when 1 then 'Point'
  3         when 2 then 'Linestring'
  4         when 3 then 'Polygon'
  5         when 4 then 'Collection'
  6         when 5 then 'MultiPoint'
  7         when 6 then 'MultiLineString'
  8         when 7 then 'MultiPolygon'
  9         when 8 then 'MultiCollection' end as gtype
 10         count(*) as Total
 11    from TAS_LGA a
 12*  group by a.geom.get_gtype();
GTYPE             TOTAL
--------------- ----------
Polygon                  9
MultiPolygon            20

But for SQL Server 2008 there is an OGC 1.1 SQL method called STGeometryType() that will return the geography type as follows:

select a.geom.STGeometryType() as gtype,
       COUNT(*) as Total
 from dbo.TAS_LGA a
group by a.geom.STGeometryType();
gtype Total
MULTIPOLYGON 20
POLYGON 9

Adding in dimensionality

Often though we want to know something about the dimensionality of a geometry column. This is pretty easy thing to query out in both databases.

Oracle

With Oracle there are two different geometry functions you can use to query the dimensionality of an sdo_geometry object. One – Get_Dims() – is Oracle specific; the other is part of the SQL3/MM standard – ST_CoordDim():

gis@XE> select a.geom.get_dims(), a.geom.st_coorddim(), count(*)
  2  from TAS_LGA a
  3* group by  a.geom.get_dims(), a.geom.st_coorddim()
gis@XE> /
A.GEOM.GET_DIMS() A.GEOM.ST_COORDDIM()   COUNT(*)
----------------- -------------------- ----------
                2                    2         29

SQL Server 2008

select A.geom.STDimension() as dimension,
       count(*) as Total
  from dbo.TAS_LGA A
group by A.geom.STDimension();
dimension Total
2 29

I hope these tips are useful.

Creative Commons License

post this at del.icio.uspost this at Diggpost this at Technoratipost this at Redditpost this at Farkpost this at Yahoo! my webpost this at Windows Livepost this at Google Bookmarkspost this to Twitter

Comment [1]

One more tip regarding gtypes: you can use the InstanceOf() method to test where the type lies in the OGC hierarchy. E.g.:

declare @g geography
set @g = geography::STGeomFromText(‘LINESTRING[44 0, 45 0]’, 4326)
select @g.InstanceOf(‘geometry’) —returns 1
select @g.InstanceOf(‘curve’) —returns 1
select @g.InstanceOf(‘polygon’) —returns 0

(You need to replace the square brackets above with parenthesis – for some reason if I use parenthesis there the system eats my coordinates.)

Cheers,
-Isaac

Isaac Kunen · 24 November 2007, 04:37 · #