September 30, 2012 at 9:37 am
Hello all,
I'm wondering if it is possible to do the following. I have a table with locations in the world.
All locations have the locationtype continent, country, state, city, neigbourhood or street.
Also i have a table that tell contains all parent locations of a location (e.g. the parent location of a state is a country) That table looks like:
LocationID, Locationname, ParentlocationID
The parentlocationID refers to the locationID of the parent Location.
Now I want to make a query that shows me all underlying locations of a given location. E.g. when i search for a location that is a country i get all states, cities, neigbourhoods and streets for that country. But when i search for a city it will show only all neighbourhoods and streets.
In addition to my question some examples:
CREATE TABLE [ParentRegionList](
[RegionID] [int] NOT NULL,
[RegionType] [nvarchar](50) NULL,
[RegionName] [nvarchar](255) NULL,
[ParentRegionID] [int] NULL
)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1,'Continent','Europe',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (2,'Continent','North America',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (500,'Country','The Netherlands',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (501,'Country','Germany',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (502,'Country','Belgium',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (550,'Country','United States of America',2)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (800,'State','New York',550)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1000,'City','New York',800)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1001,'City','Amsterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1002,'City','Rotterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1003,'City','Brussels',502)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5000,'Neighborhood','Amsterdam Center',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5001,'Neighborhood','The Pijp',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10001,'Street','Damrak',5000)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10002,'Street','Rue de Brussels',1003)
In this example the search variable 1 (Europe) has to show all records that are (in)direct (top down) connected to RegionID 1 so:
500 The Netherlands
501 Germany
502 Belgium
1001 Amsterdam
1002 Rotterdam
1003 Brussels
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
10002 Rue de Brussels
In this example the search variable 800 (state new york) has to show all records that are (in)direct (top down) connected to RegionID 800 so:
1000 New York
In this example the search variable 1001 (Amsterdam) has to show all records that are (in)direct (top down) connected to RegionID 1001 so:
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
Does somebody know how to solve this?
Any suggestions are welcome!!
Thanks!!
Mike
October 1, 2012 at 3:26 am
--======== TEST DATA ==========
IF OBJECT_ID('dbo.ParentRegionList') IS NOT NULL
DROP TABLE dbo.ParentRegionList;
CREATE TABLE [ParentRegionList](
[RegionID] [int] NOT NULL,
[RegionType] [nvarchar](50) NULL,
[RegionName] [nvarchar](255) NULL,
[ParentRegionID] [int] NULL
)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1,'Continent','Europe',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (2,'Continent','North America',0)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (500,'Country','The Netherlands',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (501,'Country','Germany',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (502,'Country','Belgium',1)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (550,'Country','United States of America',2)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (800,'State','New York',550)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1000,'City','New York',800)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1001,'City','Amsterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1002,'City','Rotterdam',500)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (1003,'City','Brussels',502)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5000,'Neighborhood','Amsterdam Center',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (5001,'Neighborhood','The Pijp',1001)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10001,'Street','Damrak',5000)
INSERT INTO [ParentRegionList] ([RegionID],[RegionType],[RegionName],[ParentRegionID]) VALUES (10002,'Street','Rue de Brussels',1003)
--SELECT * FROM [ParentRegionList];
--======== SUGGESTED SOLUTION ==========
-- You can use a recursive CTE for this:
DECLARE @RegionID Int = 1001;
;WITH SelectedLocations(RegionID, RegionType, RegionName, HierarchyLevel) AS
(
SELECT RegionID, RegionType, RegionName, 0 AS HierarchyLevel
FROM dbo.ParentRegionList
WHERE RegionID = @RegionID
UNION ALL
SELECT e.RegionID, e.RegionType, e.RegionName, HierarchyLevel + 1
FROM dbo.ParentRegionList AS e
INNER JOIN SelectedLocations d
ON e.ParentRegionID = d.RegionID
)
SELECT RegionID, RegionName, HierarchyLevel
FROM SelectedLocations
ORDER BY RegionID, HierarchyLevel;
/*
In this example the search variable 1 (Europe) has to show all records that are (in)direct (top down) connected to RegionID 1 so:
500 The Netherlands
501 Germany
502 Belgium
1001 Amsterdam
1002 Rotterdam
1003 Brussels
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
10002 Rue de Brussels
In this example the search variable 800 (state new york) has to show all records that are (in)direct (top down) connected to RegionID 800 so:
1000 New York
In this example the search variable 1001 (Amsterdam) has to show all records that are (in)direct (top down) connected to RegionID 1001 so:
5000 Amsterdam Center
5001 The Pijp
10001 Damrak
Does somebody know how to solve this?
Any suggestions are welcome!!
*/
October 1, 2012 at 3:33 am
Laurie beat me to it. Same as hers but no reason for the HiearchyLevel:
;WITH SearchHierarchy AS (
SELECT RegionID, RegionName, ParentRegionID
FROM [ParentRegionList]
WHERE RegionID = @Search
UNION ALL
SELECT a.RegionID, a.RegionName, a.ParentRegionID
FROM [ParentRegionList] a
INNER JOIN SearchHierarchy b ON a.ParentRegionID = b.RegionID
)
SELECT RegionID, RegionName
FROM SearchHierarchy
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
October 1, 2012 at 3:39 am
Laurie and Dwain,
Thanks for your help.... case solved!!!
Mike
Viewing 4 posts - 1 through 3 (of 3 total)
You must be logged in to reply to this topic. Login to reply