LISTSERV mailing list manager LISTSERV 16.5

Help for QSERV-L Archives


QSERV-L Archives

QSERV-L Archives


QSERV-L@LISTSERV.SLAC.STANFORD.EDU


View:

Message:

[

First

|

Previous

|

Next

|

Last

]

By Topic:

[

First

|

Previous

|

Next

|

Last

]

By Author:

[

First

|

Previous

|

Next

|

Last

]

Font:

Proportional Font

LISTSERV Archives

LISTSERV Archives

QSERV-L Home

QSERV-L Home

QSERV-L  April 2016

QSERV-L April 2016

Subject:

Re: spatial DB - quick question.

From:

Kian-Tat Lim <[log in to unmask]>

Reply-To:

General discussion for qserv (LSST prototype baseline catalog)

Date:

Wed, 6 Apr 2016 00:35:04 -0700

Content-Type:

text/plain

Parts/Attachments:

Parts/Attachments

text/plain (44 lines)

Srini,

> >So I have a catalog of 600 million stars. The data that I have is :
> >
> >ra, dec, muRa, muDec, …. some mag columns etc etc.
> >
> >I want to add a few columns,
> >
> >1. Add column for each row that tells me how many stars I have in the
> >neighborhood with distance x.
> >2. Add column for each row that tells me how many stars I have in the
> >neighborhood with distance x + 1.

This is essentially a spatial (self-)cross-match plus GROUP BY (or
subquery) and COUNT(*) aggregation.

SELECT A.id, COUNT(*) AS neighbors_x FROM Stars AS A, Stars AS B
WHERE A.id != B.id AND SPH_DIST(A.ra, A.dec, B.ra, B.dec) <= x
GROUP BY A.id

Executing this directly will typically be very inefficient, of course.

Adding RA and dec ranges to the WHERE clause (like B.ra BETWEEN A.ra - x
AND A.ra + x, but handling wraparound) could speed things up
significantly if you've B-tree indexed on RA and dec and your database
engine can handle the range indexing well.  I think MySQL does *not* do
this well, SQL Server does (hence its usage in SDSS), and I'm not sure
about PostGreSQL.  Computing zones (RA bands within dec stripes) or HTM
trixel indexes can also help optimize the query.  An R-tree index is
another possibility, but it may require that you transform to x,y,z
coordinates for best speed.

Qserv's chunk/subchunk scheme is supposed to make queries like this more
efficient.  You could try running on a single-node instance.

-- 
Kian-Tat Lim, LSST Data Management, [log in to unmask]

########################################################################
Use REPLY-ALL to reply to list

To unsubscribe from the QSERV-L list, click the following link:
https://listserv.slac.stanford.edu/cgi-bin/wa?SUBED1=QSERV-L&A=1

Top of Message | Previous Page | Permalink

Advanced Options


Options

Log In

Log In

Get Password

Get Password


Search Archives

Search Archives


Subscribe or Unsubscribe

Subscribe or Unsubscribe


Archives

March 2018
February 2018
January 2018
December 2017
August 2017
December 2016
November 2016
October 2016
September 2016
August 2016
July 2016
June 2016
May 2016
April 2016
March 2016
February 2016
January 2016
December 2015
November 2015
October 2015
September 2015
August 2015
July 2015
June 2015
May 2015
April 2015
March 2015
February 2015
January 2015
December 2014
November 2014
October 2014
September 2014
August 2014
July 2014
June 2014
May 2014
April 2014
March 2014
February 2014
January 2014
December 2013
November 2013
October 2013
September 2013
August 2013
July 2013
June 2013
May 2013
April 2013
March 2013
February 2013
January 2013
December 2012

ATOM RSS1 RSS2



LISTSERV.SLAC.STANFORD.EDU

Secured by F-Secure Anti-Virus CataList Email List Search Powered by the LISTSERV Email List Manager

Privacy Notice, Security Notice and Terms of Use