Problems with RegTAP, ADQL, natural joins, and MS SQL Server

Theresa Dower dower at stsci.edu
Wed Feb 24 20:11:36 CET 2016


Hello,

As some of you know from prior discussions and database work of your own, there is an issue with the ADQL standard and the capabilities of MS SQL Server, namely that by design it does not support the NATURAL JOIN syntax. The design decision was based on the ambiguity in how the natural join finds keys in generic schemas. Even with known schemas such as RegTAP's, parsing and rewriting generic queries with natural joins is far from trivial.

At this time, TAP services at NAVO institutions and the Royal Observatory Edinburgh are using Microsoft SQL Server as a back end to TAP services. STScI and ROE are extending Gregory Mantele's Java ADQL parser for this work and will share it back to his project. STScI have put together a RegTAP service which will be operational before the Spring 2016 interop. (An ObsTAP service with basic spatial query support comes next.) The problem is that with our available resources we cannot support natural joins, yet they are used extensively by the example RegTAP queries in TOPCAT, the most commonly used TAP client.

For our testing, Sarah Weissman at ST created translations of example TOPCAT queries avoiding the natural join syntax. They are a longer and uglier, which is the general argument for the elegance of natural joins in the first place, but they do work. I've proposed to Mark Taylor that we could provide these in TOPCAT and I agreed with his suggestion that while we can certainly use them, we should bring this to the mailing list so you are all aware of the issue.

How do we want to balance using the more elegant query syntax in our specs  yet support major architectures that don't allow them? Should we avoid using them in documentation examples and/or provide sample translations? What do we add in terms of notes about the issue in future specs? Should we help out clients with an agreed-upon error note for unsupported functionality, given some TAP providers have a similar issue with unsupported geometry already? I think we should do all of this and I welcome thoughts on the issue.

For the morbidly curious, all of the example queries requiring translation for SQL Server and our substitutions follow. They are quite simple, just numerous.

--Theresa Dower

----------------------------------------------

TAP Access URLS:

SELECT ivoid, access_url
FROM rr.capability
NATURAL JOIN rr.interface
WHERE standard_id like 'ivo://ivoa.net/std/tap%'
  AND intf_type='vs:paramhttp'

SELECT ivoid, access_url
FROM rr.capability, rr.interface
WHERE rr.capability.ivoid = rr.interface.ivoid
AND standard_id like 'ivo://ivoa.net/std/tap%'
AND intf_type='vs:paramhttp'

SIA with spirals:

SELECT ivoid, access_url
FROM rr.capability
  NATURAL JOIN rr.resource
  NATURAL JOIN rr.interface
  NATURAL JOIN rr.res_subject
WHERE standard_id='ivo://ivoa.net/std/sia'
  AND intf_type='vs:paramhttp'
  AND (
    1=ivo_nocasematch(res_subject, '%spiral%')
    OR 1=ivo_hasword(res_description, 'spiral')
    OR 1=ivo_hasword(res_title, 'spiral'))

SELECT rr.capability.ivoid, access_url
FROM rr.capability, rr.resource, rr.interface, rr.res_subject
where rr.capability.ivoid = rr.resource.ivoid
AND rr.resource.ivoid = rr.interface.ivoid
AND rr.interface.ivoid = rr.res_subject.ivoid
AND standard_id='ivo://ivoa.net/std/sia'
AND intf_type='vs:paramhttp'
AND (
1=ivo_nocasematch(res_subject, '%spiral%')
OR 1=ivo_hasword(res_description, 'spiral')
OR 1=ivo_hasword(res_title, 'spiral'))

Infrared SIA:

SELECT ivoid, access_url
FROM rr.capability
  NATURAL JOIN rr.resource
  NATURAL JOIN rr.interface
WHERE standard_id='ivo://ivoa.net/std/sia'
  AND intf_type='vs:paramhttp'
  AND 1=ivo_hashlist_has('infrared', waveband)

SELECT rr.capability.ivoid, access_url
FROM rr.capability, rr.resource, rr.interface
AND rr.capability.ivoid = rr.resource.ivoid
AND rr.resource.ivoid = rr.interface.ivoid
AND standard_id='ivo://ivoa.net/std/sia'
AND intf_type='vs:paramhttp'
AND 1=ivo_hashlist_has('infrared', waveband)

ConeSearch with redshift:

SELECT ivoid, access_url
FROM rr.capability
  NATURAL JOIN rr.table_column
  NATURAL JOIN rr.interface
WHERE standard_id='ivo://ivoa.net/std/conesearch'
  AND intf_type='vs:paramhttp'
  AND ucd='src.redshift'

SELECT rr.capability.ivoid, access_url
FROM rr.capability, rr.table_column, rr.interface
where rr.capability.ivoid = rr.table_column.ivoid
AND rr.table_column.ivoid = rr.interface.ivoid
AND standard_id='ivo://ivoa.net/std/conesearch'
AND intf_type='vs:paramhttp'
AND ucd='src.redshift'

Records from registry:

SELECT access_url
FROM rr.interface
NATURAL JOIN rr.capability
NATURAL JOIN rr.res_detail
WHERE standard_id='ivo://ivoa.net/std/tap'
  AND intf_type='vs:paramhttp'
  AND detail_xpath='/capability/dataModel/@ivo-id'
  AND 1=ivo_nocasematch(detail_value,
    'ivo://ivoa.net/std/regtap#1.%')

SELECT ivoid FROM rr.resource
RIGHT OUTER JOIN (
SELECT 'ivo://' || detail_value || '%' AS pat
FROM rr.res_detail
WHERE detail_xpath='/managedAuthority'
AND ivoid='ivo://cds.vizier/registry')
AS authpatterns
ON (resource.ivoid LIKE authpatterns.pat)

Locate RegTAP services:

SELECT access_url
FROM rr.interface
NATURAL JOIN rr.capability
NATURAL JOIN rr.res_detail
WHERE standard_id='ivo://ivoa.net/std/tap'
  AND intf_type='vs:paramhttp'
  AND detail_xpath='/capability/dataModel/@ivo-id'
  AND 1=ivo_nocasematch(detail_value,
    'ivo://ivoa.net/std/regtap#1.%')

SELECT access_url
FROM rr.interface, rr.capability, rr.res_detail
where rr.interface.ivoid = rr.capability.ivoid
AND rr.capability.ivoid = rr.res_detail.ivoid
AND standard_id='ivo://ivoa.net/std/tap'
AND intf_type='vs:paramhttp'
AND detail_xpath='/capability/dataModel/@ivo-id'
AND 1=ivo_nocasematch(detail_value,
'ivo://ivoa.net/std/regtap#1.%')

TAP with Physics:

SELECT ivoid, access_url, name, ucd, column_description
FROM rr.capability
  NATURAL JOIN rr.interface
  NATURAL JOIN rr.table_column
  NATURAL JOIN rr.res_table
WHERE standard_id='ivo://ivoa.net/std/tap'
  AND intf_type='vs:paramhttp'
  AND 1=ivo_hasword(table_description, 'quasar')
  AND ucd='phot.mag;em.opt.v'

SELECT rr.capability.ivoid, access_url, name, ucd, column_description
FROM rr.capability, rr.interface, rr.table_column, rr.res_table
where rr.capability.ivoid = rr.interface.ivoid
and rr.interface.ivoid = rr.table_column.ivoid
and rr.table_column.ivoid = rr.res_table.ivoid
and standard_id='ivo://ivoa.net/std/tap'
AND intf_type='vs:paramhttp'
AND 1=ivo_hasword(table_description, 'quasar')
AND ucd='phot.mag;em.opt.v'

Theoretical SSA:

SELECT access_url
FROM rr.res_detail
  NATURAL JOIN rr.capability
  NATURAL JOIN rr.interface
WHERE detail_xpath='/capability/dataSource'
  AND intf_type='vs:paramhttp'
  AND standard_id='ivo://ivoa.net/std/ssa'
  AND detail_value='theory'

SELECT access_url
FROM rr.res_detail, rr.capability, rr.interface
where rr.res_detail.ivoid = rr.capability.ivoid
and rr.capability.ivoid = rr.interface.ivoid
and detail_xpath='/capability/dataSource'
AND intf_type='vs:paramhttp'
AND standard_id='ivo://ivoa.net/std/ssa'
AND detail_value='theory'

Find Contact Persons:

SELECT DISTINCT base_role, role_name, email
FROM rr.res_role
  NATURAL JOIN rr.interface
WHERE access_url='http://dc.zah.uni-heidelberg.de/tap'

SELECT DISTINCT access_url, base_role, role_name, email
FROM rr.res_role, rr.interface
where rr.res_role.ivoid = rr.interface.ivoid
and access_url='http://dc.zah.uni-heidelberg.de/tap'


-------------- next part --------------
An HTML attachment was scrubbed...
URL: <http://mail.ivoa.net/pipermail/registry/attachments/20160224/58d2f627/attachment.html>


More information about the registry mailing list