SqlServer 2005 T-SQL Query 學(xué)習(xí)筆記(4)
CREATE TABLE dbo.Nums(n INT NOT NULL PRIMARY KEY);
DECLARE @max AS INT, @rc AS INT;
SET @max = 1000000;
SET @rc = 1;
INSERT INTO Nums VALUES(1);
WHILE @rc * 2 <= @max
BEGIN
INSERT INTO dbo.Nums SELECT n + @rc FROM dbo.Nums;
SET @rc = @rc * 2;
END
INSERT INTO dbo.Nums
SELECT n + @rc FROM dbo.Nums WHERE n + @rc <= @max;
這種方式非常巧妙,它并不是一個一個的循環(huán)插入,而是一次插入很多行,{1},{2},{3,4},{5,6,7,8}。。。
為什么這樣會快呢?
是因為它節(jié)省了跟比較其他可用解決方案進(jìn)行比較和記錄這些日志的時間。
然后,作者給了一個CTE的遞歸的解決方案:
DECLARE @n AS BIGINT;
SET @n = 1000000;
WITH Nums AS
(
SELECT 1 AS n
UNION ALL
SELECT n + 1 FROM Nums WHERE n < @n
)
SELECT n FROM Nums
OPTION(MAXRECURSION 0);--為了移除默認(rèn)100的遞歸限制
有個更優(yōu)的CTE的解決方案,就是先生成很多行,然后用ROW_NUMBER進(jìn)行計算,再選擇ROW_NUMBER這列的值就可以了。
DECLARE @n AS BIGINT;
SET @n = 1000000;
WITH Base AS
(
SELECT 1 AS n
UNION ALL
SELECT n + 1 FROM Base WHERE n < CEILING(SQRT(@n))
),
Expand AS
(
SELECT 1 AS c
FROM Base AS B1, Base AS B2
),
Nums AS
(
SELECT ROW_NUMBER() OVER(ORDER BY c) AS n
FROM Expand
)
SELECT n FROM Nums WHERE n <= @n
OPTION(MAXRECURSION 0);
利用笛卡爾積進(jìn)行不斷的累加,達(dá)到了22n行。
最后,作者給出了一個函數(shù),用于生成這樣的數(shù)字表:
CREATE FUNCTION dbo.fn_nums(@n AS BIGINT) RETURNS TABLE
AS
RETURN
WITH
L0 AS(SELECT 1 AS c UNION ALL SELECT 1),
L1 AS(SELECT 1 AS c FROM L0 AS A, L0 AS B),
L2 AS(SELECT 1 AS c FROM L1 AS A, L1 AS B),
L3 AS(SELECT 1 AS c FROM L2 AS A, L2 AS B),
L4 AS(SELECT 1 AS c FROM L3 AS A, L3 AS B),
L5 AS(SELECT 1 AS c FROM L4 AS A, L4 AS B),
Nums AS(SELECT ROW_NUMBER() OVER(ORDER BY c) AS n FROM L5)
SELECT n FROM Nums WHERE n <= @n;
GO
相關(guān)文章
SQL Server 2005 DTS導(dǎo)入平面數(shù)據(jù)出現(xiàn)錯誤解決方案
SQL Server 2005 DTS導(dǎo)入平面數(shù)據(jù)源時,總是被截斷,無法執(zhí)行的錯誤解決方案2012-11-11sqlserver巧用row_number和partition by分組取top數(shù)據(jù)
SQL Server 2005后之后,引入了row_number()函數(shù),row_number()函數(shù)的分組排序功能使這種操作變得非常簡單2011-12-12SQL Server 2005恢復(fù)數(shù)據(jù)庫詳細(xì)圖文教程
這篇文章主要介紹了SQL Server 2005恢復(fù)數(shù)據(jù)庫詳細(xì)圖文教程,需要的朋友可以參考下2014-11-11sql server2005實現(xiàn)數(shù)據(jù)庫讀寫分離介紹
對于負(fù)載均衡,筆者經(jīng)常接觸的當(dāng)屬Oracle的負(fù)載均衡機制。下面我們重點介紹Sql Server 2005是如何實現(xiàn)負(fù)載均衡的,感興趣的朋友可以參考下哈2013-06-06SQLSERVER 2005中使用sql語句對xml文件和其數(shù)據(jù)的進(jìn)行操作(很全面)
由于數(shù)據(jù)庫對xml數(shù)據(jù)直接處理有很多優(yōu)勢,05也對這方面加強了功能。下面是一些實例代碼,大家可以參考下。2010-06-06SQL Server 2005 中使用 Try Catch 處理異常
本文主要對比了Sql Server 2000和Sql Server 2005對異常處理的方法,Sql Server 2005 之后的TRY CATCH捕捉異常,更類似C#、JAVA等語言,更容易被程序員理解。2016-05-05SQL2005 ROW_NUMER實現(xiàn)分頁的兩種常用方式
SQL2005利用ROW_NUMER實現(xiàn)分頁的兩種常用方式2009-07-07SQLServer2005 沒有日志文件(*.ldf) 只有數(shù)據(jù)文件(*.mdf) 恢復(fù)數(shù)據(jù)庫的方法
SQLServer2005 沒有日志文件(*.ldf) 只有數(shù)據(jù)文件(*.mdf) 恢復(fù)數(shù)據(jù)庫的方法2011-12-12解決SQL2005備份數(shù)據(jù)庫.dat或bak還原時的結(jié)構(gòu)錯誤的解決方法
已備份數(shù)據(jù)庫的磁盤上結(jié)構(gòu)版本為611. 服務(wù)器支持版本539, 無法還原或升級此數(shù)據(jù)庫,RESTORE DATABASE 操作異常終止。2011-02-02