有產品表,包含id,name,city,addtime四個字段,因報表需要按城市分組,統(tǒng)計每個城市的最新10個產品,便向該表中插入了100萬數(shù)據(jù),做了如下系列測試:
復制代碼 代碼如下:
CREATE TABLE [dbo].[products](
[id] [int] IDENTITY(1,1) NOT NULL,
[name] [nvarchar](50) NULL,
[addtime] [datetime] NULL,
[city] [nvarchar](10) NULL,
CONSTRAINT [PK_products] PRIMARY KEY CLUSTERED
(
[id] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]
1、采用row_number方法,執(zhí)行5次,平均下來8秒左右,速度最快。
復制代碼 代碼如下:
select no, id,name,city
from (select no =row_number() over (partition by city order by addtime desc), * from products)t
where no 11 order by city asc,addtime desc
2、采用cross apply方法,執(zhí)行了3次,基本都在3分5秒以上,已經很慢了。
復制代碼 代碼如下:
select distinct b.id,b.name,b.city from products a
cross apply (select top 10 * from products where city = a.city order by addtime desc) b
3、采用Count查詢,只執(zhí)行了兩次,第一次執(zhí)行到5分鐘時,取消任務執(zhí)行了;第二次執(zhí)行到13分鐘時,沒有hold住又直接停止了,實在無法忍受。
復制代碼 代碼如下:
select id,name,city from products a
where ( select count(city) from products where a.city = city and addtime>a.addtime) 10
order by city asc,addtime desc
4、采用游標方法,這個最后測試的,執(zhí)行了5次,每次都是10秒完成,感覺還不錯。
復制代碼 代碼如下:
declare @city nvarchar(10)
create table #Top(id int,name nvarchar(50),city nvarchar(10),addtime datetime)
declare mycursor cursor for
select distinct city from products order by city asc
open mycursor
fetch next from mycursor into @city
while @@fetch_status =0
begin
insert into #Top
select top 10 id,name,city,addtime from products where city = @city
fetch next from mycursor into @city
end
close mycursor
deallocate mycursor
Select * from #Top order by city asc,addtime desc
drop table #Top
通過上述對比不難發(fā)現(xiàn),在面臨Group獲取Top N場景時,可以首選row_number,游標cursor其次,另外兩個就基本不考慮了,數(shù)據(jù)量大的時候根本沒法使用。
您可能感興趣的文章:- sql分組后二次匯總(處理表重復記錄查詢和刪除)的實現(xiàn)方法
- SQL SERVER 分組求和sql語句
- 顯示同一分組中的其他元素的sql語句
- sql獲取分組排序后數(shù)據(jù)的腳本
- SQL進行排序、分組、統(tǒng)計的10個新技巧分享
- SQL分組排序去重復的小實例
- 以數(shù)據(jù)庫字段分組顯示數(shù)據(jù)的sql語句(詳細介紹)
- Sql Server:多行合并成一行,并做分組統(tǒng)計的兩個方法
- Sql Server 分組統(tǒng)計并合計總數(shù)及WITH ROLLUP應用
- SQL語句分組獲取記錄的第一條數(shù)據(jù)的方法
- sqlserver巧用row_number和partition by分組取top數(shù)據(jù)
- 一句Sql把縱向表轉為橫向表,并分別分組求平均和總平均值
- sql 分組查詢問題
- SQLserver 實現(xiàn)分組統(tǒng)計查詢(按月、小時分組)
- 分組后分組合計以及總計SQL語句(稍微整理了一下)