[ ] SQL Server |
create table dbo.Turnover
(
id int identity primary key,
dt datetime not null,
ProductID int not null,
StorehouseID int not null,
Operation smallint not null check (Operation in (-1,1)), -- +1 , -1
Quantity numeric(20,2) not null,
Cost money not null
)
Dt / / .
ProductID
StorehouseID
Operation 2
Quantity . , , , .
Cost .
if object_id('dbo.Turnover','U') is not null drop table dbo.Turnover;
go
with times as
(
select 1 id
union all
select id+1
from times
where id < 10*365*24*60 -- 10 * 365 * 24 * 60 = 10
)
, storehouse as
(
select 1 id
union all
select id+1
from storehouse
where id < 100 --
)
select
identity(int,1,1) id,
dateadd(minute, t.id, convert(datetime,'20060101',120)) dt,
1+abs(convert(int,convert(binary(4),newid()))%1000) ProductID, -- 1000 -
s.id StorehouseID,
case when abs(convert(int,convert(binary(4),newid()))%3) in (0,1) then 1 else -1 end Operation, -- , 3 2 1
1+abs(convert(int,convert(binary(4),newid()))%100) Quantity
into dbo.Turnover
from times t cross join storehouse s
option(maxrecursion 0);
go
--- 15 min
alter table dbo.Turnover alter column id int not null
go
alter table dbo.Turnover add constraint pk_turnover primary key (id) with(data_compression=page)
go
-- 6 min
select top(1000)
convert(datetime,convert(varchar(13),dt,120)+':00',120) as dt, --
ProductID,
StorehouseID,
sum(Operation*Quantity) as Quantity
from dbo.Turnover
group by
convert(datetime,convert(varchar(13),dt,120)+':00',120),
ProductID,
StorehouseID
12406
( : 1000)
SQL Server:
= 2096594 , = 321797 .
select top(1000)
convert(datetime,convert(varchar(13),dt,120)+':00',120) as dt, --
ProductID,
StorehouseID,
sum(Operation*Quantity) as Quantity,
sum(sum(Operation*Quantity)) over
(
partition by StorehouseID, ProductID
order by convert(datetime,convert(varchar(13),dt,120)+':00',120)
) as Balance
from dbo.Turnover
group by
convert(datetime,convert(varchar(13),dt,120)+':00',120),
ProductID,
StorehouseID
19329
( : 1000)
SQL Server:
= 2413155 , = 344631 .
create view dbo.TurnoverHour
with schemabinding as
select
convert(datetime,convert(varchar(13),dt,120)+':00',120) as dt, --
ProductID,
StorehouseID,
sum(isnull(Operation*Quantity,0)) as Quantity,
count_big(*) qty
from dbo.Turnover
group by
convert(datetime,convert(varchar(13),dt,120)+':00',120),
ProductID,
StorehouseID
go
create unique clustered index uix_TurnoverHour on dbo.TurnoverHour (StorehouseID, ProductID, dt)
with (data_compression=page) 19 minselect top(1000)
convert(datetime,convert(varchar(13),dt,120)+':00',120) as dt, --
ProductID,
StorehouseID,
sum(isnull(Operation*Quantity,0)) as Quantity
from dbo.Turnover
group by
convert(datetime,convert(varchar(13),dt,120)+':00',120),
ProductID,
StorehouseID
select top(1000)
convert(datetime,convert(varchar(13),dt,120)+':00',120) as dt, --
ProductID,
StorehouseID,
sum(isnull(Operation*Quantity,0)) as Quantity,
sum(sum(isnull(Operation*Quantity,0))) over
(
partition by StorehouseID, ProductID
order by convert(datetime,convert(varchar(13),dt,120)+':00',120)
) as Balance
from dbo.Turnover
group by
convert(datetime,convert(varchar(13),dt,120)+':00',120),
ProductID,
StorehouseID
SQL Server:
= 31 , = 116 .
( : 1000)
SQL Server:
= 0 , = 151 .
set dateformat ymd;
declare
@start datetime = '2015-01-02',
@finish datetime = '2015-01-03'
select *
from
(
select
dt,
StorehouseID,
ProductId,
Quantity,
sum(Quantity) over
(
partition by StorehouseID, ProductID
order by dt
) as Balance
from dbo.TurnoverHour with(noexpand)
where dt <= @finish
) as tmp
where dt >= @start
create index ix_dt on dbo.TurnoverHour (dt) include (Quantity) with(data_compression=page); --7 min
:
set dateformat ymd;
declare
@start datetime = '2015-01-02',
@finish datetime = '2015-01-03'
declare
@start_month datetime = convert(datetime,convert(varchar(9),@start,120)+'1',120)
select *
from
(
select
dt,
StorehouseID,
ProductId,
Quantity,
sum(Quantity) over
(
partition by StorehouseID, ProductID
order by dt
) as Balance
from dbo.TurnoverHour with(noexpand)
where dt between @start_month and @finish
) as tmp
where dt >= @start
order by StorehouseID, ProductID, dt
set dateformat ymd;
declare
@start datetime = '2015-01-02',
@finish datetime = '2015-01-03'
declare
@start_month datetime = convert(datetime,convert(varchar(9),@start,120)+'1',120)
select *
from
(
select
dt,
StorehouseID,
ProductId,
Quantity,
sum(Quantity) over
(
partition by StorehouseID, ProductID
order by dt
) as Balance
from dbo.TurnoverHour with(noexpand)
where dt between @start_month and @finish
) as tmp
where dt >= @start
order by StorehouseID, ProductID, dt
select *
from
(
select
dt,
StorehouseID,
ProductId,
Quantity,
sum(Quantity) over
(
partition by StorehouseID, ProductID
order by dt
) as Balance
from dbo.TurnoverHour with(noexpand,index=ix_dt)
where dt between @start_month and @finish
) as tmp
where dt >= @start
order by StorehouseID, ProductID, dt
SQL Server:
= 33860 , = 24247 .
( : 145608)
( : 1)
SQL Server:
= 6374 , = 1718 .
SQL Server:
= 0 , = 0 .
drop index ix_dt on dbo.TurnoverHour;
drop index uix_TurnoverHour on dbo.TurnoverHour;
set dateformat ymd;
create partition function pf_TurnoverHour(datetime) as range right for values (
'2006-01-01', '2006-02-01', '2006-03-01', '2006-04-01', '2006-05-01', '2006-06-01', '2006-07-01', '2006-08-01', '2006-09-01', '2006-10-01', '2006-11-01', '2006-12-01',
'2007-01-01', '2007-02-01', '2007-03-01', '2007-04-01', '2007-05-01', '2007-06-01', '2007-07-01', '2007-08-01', '2007-09-01', '2007-10-01', '2007-11-01', '2007-12-01',
'2008-01-01', '2008-02-01', '2008-03-01', '2008-04-01', '2008-05-01', '2008-06-01', '2008-07-01', '2008-08-01', '2008-09-01', '2008-10-01', '2008-11-01', '2008-12-01',
'2009-01-01', '2009-02-01', '2009-03-01', '2009-04-01', '2009-05-01', '2009-06-01', '2009-07-01', '2009-08-01', '2009-09-01', '2009-10-01', '2009-11-01', '2009-12-01',
'2010-01-01', '2010-02-01', '2010-03-01', '2010-04-01', '2010-05-01', '2010-06-01', '2010-07-01', '2010-08-01', '2010-09-01', '2010-10-01', '2010-11-01', '2010-12-01',
'2011-01-01', '2011-02-01', '2011-03-01', '2011-04-01', '2011-05-01', '2011-06-01', '2011-07-01', '2011-08-01', '2011-09-01', '2011-10-01', '2011-11-01', '2011-12-01',
'2012-01-01', '2012-02-01', '2012-03-01', '2012-04-01', '2012-05-01', '2012-06-01', '2012-07-01', '2012-08-01', '2012-09-01', '2012-10-01', '2012-11-01', '2012-12-01',
'2013-01-01', '2013-02-01', '2013-03-01', '2013-04-01', '2013-05-01', '2013-06-01', '2013-07-01', '2013-08-01', '2013-09-01', '2013-10-01', '2013-11-01', '2013-12-01',
'2014-01-01', '2014-02-01', '2014-03-01', '2014-04-01', '2014-05-01', '2014-06-01', '2014-07-01', '2014-08-01', '2014-09-01', '2014-10-01', '2014-11-01', '2014-12-01',
'2015-01-01', '2015-02-01', '2015-03-01', '2015-04-01', '2015-05-01', '2015-06-01', '2015-07-01', '2015-08-01', '2015-09-01', '2015-10-01', '2015-11-01', '2015-12-01',
'2016-01-01', '2016-02-01', '2016-03-01', '2016-04-01', '2016-05-01', '2016-06-01', '2016-07-01', '2016-08-01', '2016-09-01', '2016-10-01', '2016-11-01', '2016-12-01',
'2017-01-01', '2017-02-01', '2017-03-01', '2017-04-01', '2017-05-01', '2017-06-01', '2017-07-01', '2017-08-01', '2017-09-01', '2017-10-01', '2017-11-01', '2017-12-01',
'2018-01-01', '2018-02-01', '2018-03-01', '2018-04-01', '2018-05-01', '2018-06-01', '2018-07-01', '2018-08-01', '2018-09-01', '2018-10-01', '2018-11-01', '2018-12-01',
'2019-01-01', '2019-02-01', '2019-03-01', '2019-04-01', '2019-05-01', '2019-06-01', '2019-07-01', '2019-08-01', '2019-09-01', '2019-10-01', '2019-11-01', '2019-12-01');
go
create partition scheme ps_TurnoverHour as partition pf_TurnoverHour all to ([primary]);
go
:
create unique clustered index uix_TurnoverHour on dbo.TurnoverHour (StorehouseID, ProductID, dt) with (data_compression=page) on ps_TurnoverHour(dt); --- 19 min
, . :
set dateformat ymd;
declare
@start datetime = '2015-01-02',
@finish datetime = '2015-01-03'
declare
@start_month datetime = convert(datetime,convert(varchar(9),@start,120)+'1',120)
select *
from
(
select
dt,
StorehouseID,
ProductId,
Quantity,
sum(Quantity) over
(
partition by StorehouseID, ProductID
order by dt
) as Balance
from dbo.TurnoverHour with(noexpand)
where dt between @start_month and @finish
) as tmp
where dt >= @start
order by StorehouseID, ProductID, dt
option(recompile);
SQL Server:
= 7860 , = 1725 .
SQL Server:
= 0 , = 0 .
= 9.4