欧美bbbwbbbw肥妇,免费乱码人妻系列日韩,一级黄片

SQL中Group分組獲取Top N方法實(shí)現(xiàn)可首選row_number

 更新時(shí)間:2013年03月10日 17:42:51   作者:  
統(tǒng)計(jì)每個(gè)城市的最新10個(gè)產(chǎn)品本文采用了游標(biāo)方法/Count查詢/cross apply方法/row_number方法等等對(duì)比不難發(fā)現(xiàn)Group獲取Top N場(chǎng)景時(shí),可以首選row_number,游標(biāo)cursor其次,另外兩個(gè)就基本不考慮了
有產(chǎn)品表,包含id,name,city,addtime四個(gè)字段,因報(bào)表需要按城市分組,統(tǒng)計(jì)每個(gè)城市的最新10個(gè)產(chǎn)品,便向該表中插入了100萬數(shù)據(jù),做了如下系列測(cè)試:
復(fù)制代碼 代碼如下:

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秒左右,速度最快。
復(fù)制代碼 代碼如下:

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秒以上,已經(jīng)很慢了。
復(fù)制代碼 代碼如下:

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分鐘時(shí),取消任務(wù)執(zhí)行了;第二次執(zhí)行到13分鐘時(shí),沒有hold住又直接停止了,實(shí)在無法忍受。
復(fù)制代碼 代碼如下:

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、采用游標(biāo)方法,這個(gè)最后測(cè)試的,執(zhí)行了5次,每次都是10秒完成,感覺還不錯(cuò)。
復(fù)制代碼 代碼如下:

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

通過上述對(duì)比不難發(fā)現(xiàn),在面臨Group獲取Top N場(chǎng)景時(shí),可以首選row_number,游標(biāo)cursor其次,另外兩個(gè)就基本不考慮了,數(shù)據(jù)量大的時(shí)候根本沒法使用。

相關(guān)文章

最新評(píng)論