20309 发表于 2017-12-13 16:53:10

®Geovin Du Dream Park™

---------------------------------------------------------------------  
-- Road System道路
  
---------------------------------------------------------------------
  

  
-- Listing 9-3: DDL & Sample Data for Cities, Roads
  
SET NOCOUNT ON;
  
USE tempdb;
  
GO
  
IF OBJECT_ID('dbo.Roads') IS NOT NULL
  
DROP TABLE dbo.Roads;
  
GO
  
IF OBJECT_ID('dbo.Cities') IS NOT NULL
  
DROP TABLE dbo.Cities;
  
GO
  

  
CREATE TABLE dbo.Cities
  
(
  
cityidCHAR(3)   NOT NULL PRIMARY KEY,
  
city    VARCHAR(30) NOT NULL,
  
regionVARCHAR(30) NULL,
  
country VARCHAR(30) NOT NULL
  
);
  

  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('ATL', 'Atlanta', 'GA', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('ORD', 'Chicago', 'IL', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('DEN', 'Denver', 'CO', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('IAH', 'Houston', 'TX', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('MCI', 'Kansas City', 'KS', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('LAX', 'Los Angeles', 'CA', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('MIA', 'Miami', 'FL', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('MSP', 'Minneapolis', 'MN', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('JFK', 'New York', 'NY', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('SEA', 'Seattle', 'WA', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('SFO', 'San Francisco', 'CA', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('ANC', 'Anchorage', 'AK', 'USA');
  
INSERT INTO dbo.Cities(cityid, city, region, country)
  
VALUES('FAI', 'Fairbanks', 'AK', 'USA');
  

  
CREATE TABLE dbo.Roads
  
(
  
city1       CHAR(3) NOT NULL REFERENCES dbo.Cities,
  
city2       CHAR(3) NOT NULL REFERENCES dbo.Cities,
  
distance INT   NOT NULL,
  
PRIMARY KEY(city1, city2),
  
CHECK(city1 < city2),
  
CHECK(distance > 0)
  
);
  

  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ANC', 'FAI', 359);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ATL', 'ORD', 715);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ATL', 'IAH', 800);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ATL', 'MCI', 805);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ATL', 'MIA', 665);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('ATL', 'JFK', 865);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'IAH', 1120);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'MCI', 600);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'LAX', 1025);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'MSP', 915);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'SEA', 1335);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('DEN', 'SFO', 1270);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('IAH', 'MCI', 795);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('IAH', 'LAX', 1550);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('IAH', 'MIA', 1190);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('JFK', 'ORD', 795);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('LAX', 'SFO', 385);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('MCI', 'ORD', 525);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('MCI', 'MSP', 440);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('MSP', 'ORD', 410);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('MSP', 'SEA', 2015);
  
INSERT INTO dbo.Roads(city1, city2, distance) VALUES('SEA', 'SFO', 815);
  
GO
  

  

  

  
SELECT * FROM dbo.Roads
  
GO
  

  
WITH Roads2--每对城市生成行
  
AS
  
(
  
SELECT city1 AS from_city,city2 AS to_city FROM dbo.Roads
  
UNION ALL
  
SELECT city2,city2 FROM dbo.Roads
  
),
  
RoadPaths AS
  
(
  
--返回第一级别的所有可到达的城市对
  
SELECT from_city,to_city,
  
CAST('.'+from_city+'.'+to_city+'.' AS VARCHAR(max)) AS path
  
FROM Roads2
  
UNION ALL
  
SELECT F.from_city,T.to_city,--返回下一级别的可到达的城市对
  
CAST(F.path+T.to_city+'.' AS VARCHAR(MAX)) --路径需要验明循环
  
FROM RoadPaths AS F
  
JOIN Roads2 AS T
  
ON CASE WHEN F.path LIKE '%.'+T.to_city+'.%' --如果to_city出现在from_city的路径中,则检测到循环
  
THEN 1 ELSE 0 END =0
  
AND F.to_city =T.from_city
  
)
  
SELECT DISTINCT from_city,to_city FROM RoadPaths;--返回Roads 的传递包
  
GO
  

  

  

  
---------------------------------------------------------------------
  
-- Undirected Cyclic Graph
  
---------------------------------------------------------------------
  

  
-- Listing 9-38: Transitive Closure of Roads (Undirected Cyclic Graph) 传递闭包
  
WITH Roads2 -- Two rows for each pair (f-->t, t-->f)
  
AS
  
(
  
SELECT city1 AS from_city, city2 AS to_city FROM dbo.Roads
  
UNION ALL
  
SELECT city2, city1 FROM dbo.Roads
  
),
  
RoadPaths AS
  
(
  
-- Return all first-level reachability pairs
  
SELECT from_city, to_city,

  
-- path is needed to>  
CAST('.' + from_city + '.' + to_city + '.' AS VARCHAR(MAX)) AS path
  
FROM Roads2
  

  
UNION ALL
  

  
-- Return next-level reachability pairs
  
SELECT F.from_city, T.to_city,
  
CAST(F.path + T.to_city + '.' AS VARCHAR(MAX))
  
FROM RoadPaths AS F
  
JOIN Roads2 AS T
  
-- if to_city appears in from_city's path, cycle detected
  
ON CASE WHEN F.path LIKE '%.' + T.to_city + '.%'
  
THEN 1 ELSE 0 END = 0
  
AND F.to_city = T.from_city
  
)
  
-- Return Transitive Closure of Roads
  
SELECT DISTINCT from_city, to_city
  
FROM RoadPaths;
  
GO
  

  
-- Listing 9-39: Creation Script for the fn_RoadsTC UDF
  
IF OBJECT_ID('dbo.fn_RoadsTC') IS NOT NULL
  
DROP FUNCTION dbo.fn_RoadsTC;
  
GO
  

  
CREATE FUNCTION dbo.fn_RoadsTC() RETURNS @RoadsTC TABLE (
  
from_city VARCHAR(3) NOT NULL,
  
to_city   VARCHAR(3) NOT NULL,
  
PRIMARY KEY (from_city, to_city)
  
)
  
AS
  
BEGIN
  
DECLARE @added as INT;
  

  
INSERT INTO @RoadsTC(from_city, to_city)
  
SELECT city1, city2 FROM dbo.Roads;
  

  
SET @added = @@rowcount;
  

  
INSERT INTO @RoadsTC
  
SELECT city2, city1 FROM dbo.Roads
  

  
SET @added = @added + @@rowcount;
  

  
WHILE @added > 0 BEGIN
  

  
INSERT INTO @RoadsTC
  
SELECT DISTINCT TC.from_city, R.city2
  
FROM @RoadsTC AS TC
  
JOIN dbo.Roads AS R
  
ON R.city1 = TC.to_city
  
WHERE NOT EXISTS
  
(SELECT * FROM @RoadsTC AS TC2
  
WHERE TC2.from_city = TC.from_city
  
AND TC2.to_city = R.city2)
  
AND TC.from_city <> R.city2;
  

  
SET @added = @@rowcount;
  

  
INSERT INTO @RoadsTC
  
SELECT DISTINCT TC.from_city, R.city1
  
FROM @RoadsTC AS TC
  
JOIN dbo.Roads AS R
  
ON R.city2 = TC.to_city
  
WHERE NOT EXISTS
  
(SELECT * FROM @RoadsTC AS TC2
  
WHERE TC2.from_city = TC.from_city
  
AND TC2.to_city = R.city1)
  
AND TC.from_city <> R.city1;
  

  
SET @added = @added + @@rowcount;
  
END
  
RETURN;
  
END
  
GO
  

  
-- Use the fn_RoadsTC UDF--传递闭包函数
  
SELECT * FROM dbo.fn_RoadsTC();
  
GO
  

  
-- Listing 9-40: All paths and distances in Roads (15262 rows)返回所有路径和距离
  
WITH Roads2
  
AS
  
(
  
SELECT city1 AS from_city, city2 AS to_city, distance FROM dbo.Roads
  
UNION ALL
  
SELECT city2, city1, distance FROM dbo.Roads
  
),
  
RoadPaths AS
  
(
  
SELECT from_city, to_city, distance,
  
CAST('.' + from_city + '.' + to_city + '.' AS VARCHAR(MAX)) AS path
  
FROM Roads2
  

  
UNION ALL
  

  
SELECT F.from_city, T.to_city, F.distance + T.distance,
  
CAST(F.path + T.to_city + '.' AS VARCHAR(MAX))
  
FROM RoadPaths AS F
  
JOIN Roads2 AS T
  
ON CASE WHEN F.path LIKE '%.' + T.to_city + '.%'
  
THEN 1 ELSE 0 END = 0
  
AND F.to_city = T.from_city
  
)
  
-- Return all paths and distances
  
SELECT * FROM RoadPaths;
  
GO
  

  

  
-- Listing 9-41: Shortest paths in Roads 返回最短路径
  
WITH Roads2
  
AS
  
(
  
SELECT city1 AS from_city, city2 AS to_city, distance FROM dbo.Roads
  
UNION ALL
  
SELECT city2, city1, distance FROM dbo.Roads
  
),
  
RoadPaths AS
  
(
  
SELECT from_city, to_city, distance,
  
CAST('.' + from_city + '.' + to_city + '.' AS VARCHAR(MAX)) AS path
  
FROM Roads2
  

  
UNION ALL
  

  
SELECT F.from_city, T.to_city, F.distance + T.distance,
  
CAST(F.path + T.to_city + '.' AS VARCHAR(MAX))
  
FROM RoadPaths AS F
  
JOIN Roads2 AS T
  
ON CASE WHEN F.path LIKE '%.' + T.to_city + '.%'
  
THEN 1 ELSE 0 END = 0
  
AND F.to_city = T.from_city
  
),
  
RoadsMinDist -- Min distance for each pair in TC 每对城市的最短距离
  
AS
  
(
  
SELECT from_city, to_city, MIN(distance) AS mindist
  
FROM RoadPaths
  
GROUP BY from_city, to_city
  
)
  
-- Return shortest paths and distances 返回最短路径和距离
  
SELECT RP.*
  
FROM RoadsMinDist AS RMD
  
JOIN RoadPaths AS RP
  
ON RMD.from_city = RP.from_city
  
AND RMD.to_city = RP.to_city
  
AND RMD.mindist = RP.distance;
  
GO
  

  

  

  
-- Listing 9-42: Load Shortest Road Paths Into a Table 把最短路径保存到表
  
WITH Roads2
  
AS
  
(
  
SELECT city1 AS from_city, city2 AS to_city, distance FROM dbo.Roads
  
UNION ALL
  
SELECT city2, city1, distance FROM dbo.Roads
  
),
  
RoadPaths AS
  
(
  
SELECT from_city, to_city, distance,
  
CAST('.' + from_city + '.' + to_city + '.' AS VARCHAR(MAX)) AS path
  
FROM Roads2
  

  
UNION ALL
  

  
SELECT F.from_city, T.to_city, F.distance + T.distance,
  
CAST(F.path + T.to_city + '.' AS VARCHAR(MAX))
  
FROM RoadPaths AS F
  
JOIN Roads2 AS T
  
ON CASE WHEN F.path LIKE '%.' + T.to_city + '.%'
  
THEN 1 ELSE 0 END = 0
  
AND F.to_city = T.from_city
  
),
  
RoadsMinDist
  
AS
  
(
  
SELECT from_city, to_city, MIN(distance) AS mindist
  
FROM RoadPaths
  
GROUP BY from_city, to_city
  
)
  
SELECT RP.*
  
INTO dbo.RoadPaths
  
FROM RoadsMinDist AS RMD
  
JOIN RoadPaths AS RP
  
ON RMD.from_city = RP.from_city
  
AND RMD.to_city = RP.to_city
  
AND RMD.mindist = RP.distance;
  


  
CREATE UNIQUE CLUSTERED INDEX>  
ON dbo.RoadPaths(from_city, to_city);
  
GO
  

  
-- Return shortest path between Los Angeles and New York 测试查询最短路径
  
SELECT * FROM dbo.RoadPaths
  
WHERE from_city = 'LAX' AND to_city = 'JFK';
  
GO
  

  
-- Listing 9-43: Creation Script for the fn_RoadsTC UDF
  
IF OBJECT_ID('dbo.fn_RoadsTC') IS NOT NULL
  
DROP FUNCTION dbo.fn_RoadsTC;
  
GO
  
CREATE FUNCTION dbo.fn_RoadsTC() RETURNS @RoadsTC TABLE
  
(

  
uniquifier INT          NOT NULL>  
from_cityVARCHAR(3)   NOT NULL,
  
to_city    VARCHAR(3)   NOT NULL,
  
distance   INT          NOT NULL,
  
route      VARCHAR(MAX) NOT NULL,
  
PRIMARY KEY (from_city, to_city, uniquifier)
  
)
  
AS
  
BEGIN
  
DECLARE @added AS INT;
  

  
INSERT INTO @RoadsTC
  
SELECT city1 AS from_city, city2 AS to_city, distance,
  
'.' + city1 + '.' + city2 + '.'
  
FROM dbo.Roads;
  

  
SET @added = @@rowcount;
  

  
INSERT INTO @RoadsTC
  
SELECT city2, city1, distance, '.' + city2 + '.' + city1 + '.'
  
FROM dbo.Roads;
  

  
SET @added = @added + @@rowcount;
  

  
WHILE @added > 0 BEGIN
  
INSERT INTO @RoadsTC
  
SELECT DISTINCT TC.from_city, R.city2,
  
TC.distance + R.distance, TC.route + city2 + '.'
  
FROM @RoadsTC AS TC
  
JOIN dbo.Roads AS R
  
ON R.city1 = TC.to_city
  
WHERE NOT EXISTS
  
(SELECT * FROM @RoadsTC AS TC2
  
WHERE TC2.from_city = TC.from_city
  
AND TC2.to_city = R.city2
  
AND TC2.distance <= TC.distance + R.distance)
  
AND TC.from_city <> R.city2;
  

  
SET @added = @@rowcount;
  

  
INSERT INTO @RoadsTC
  
SELECT DISTINCT TC.from_city, R.city1,
  
TC.distance + R.distance, TC.route + city1 + '.'
  
FROM @RoadsTC AS TC
  
JOIN dbo.Roads AS R
  
ON R.city2 = TC.to_city
  
WHERE NOT EXISTS
  
(SELECT * FROM @RoadsTC AS TC2
  
WHERE TC2.from_city = TC.from_city
  
AND TC2.to_city = R.city1
  
AND TC2.distance <= TC.distance + R.distance)
  
AND TC.from_city <> R.city1;
  

  
SET @added = @added + @@rowcount;
  
END
  
RETURN;
  
END
  
GO
  

  
-- Return shortest paths and distances
  
SELECT from_city, to_city, distance, route
  
FROM (SELECT from_city, to_city, distance, route,
  
RANK() OVER (PARTITION BY from_city, to_city
  
ORDER BY distance) AS rk
  
FROM dbo.fn_RoadsTC()) AS RTC
  
WHERE rk = 1;
  
GO
  

  
-- Cleanup
  
DROP TABLE dbo.RoadPaths;
  
GO
  
页: [1]
查看完整版本: ®Geovin Du Dream Park™