Bonjour,

Je suis chargé d'extraire certaines données, par mois, d'une table contenant des données de ventes.

J'ai fait une procédure stockée et la résultat obtenu est ok. Par contre, j'aimerais accélérer le temps d'exécution est, pour le mois où il y a le plus de ventes, de 33 secondes.

Il s'agit d'une vieille table (probablement transposée en sql serveur depuis un ancien système de stockage sans repenser la structure) avec plein de colonnes (une table obèse je crois que ça s'appelle). Bref, j'ai déjà fait quelques aménagements (ajout d'un id et quelques index) qui rendent les recherches courantes suffisamment performante.

Par contre ici, je sèche un peu... J'ai toujours du mal à savoir quelles colonnes mettre dans l'index et quelles colonnes mettre dans la clause include.

Voici la table en question :
Code : Sélectionner tout - Visualiser dans une fenêtre à part
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
USE [Tickets]
GO
 
/****** Object:  Table [dbo].[tblTransactions]    Script Date: 08/30/2012 11:48:50 ******/
SET ANSI_NULLS ON
GO
 
SET QUOTED_IDENTIFIER ON
GO
 
SET ANSI_PADDING ON
GO
 
SET ARITHABORT ON
GO
 
CREATE TABLE [dbo].[tblTransactions](
    [id] [int] IDENTITY(1,1) NOT NULL,
    [date_dt] [datetime] NULL,
    [year]  AS (left([date],(4))) PERSISTED,
    [date] [char](8) NOT NULL,
    [siege] [char](3) NOT NULL,
    [ray] [char](4) NULL,
    [type] [char](1) NULL,
    [eanart] [char](13) NOT NULL,
    [pu] [money] NOT NULL,
    [qt] [money] NULL,
    [ca] [money] NULL,
    [rab] [money] NULL,
    [escp] [money] NULL,
    [lm] [char](1) NULL,
    [nocre] [char](4) NULL,
    [caisse] [char](3) NOT NULL,
    [ticket] [char](4) NOT NULL,
    [cartebanque] [char](16) NULL,
    [carteclient] [char](16) NULL,
    [gib] [char](3) NULL,
    [time] [char](4) NULL,
    [typecart] [char](1) NULL,
    [typefim] [char](1) NULL,
    [typerab] [char](1) NULL,
    [typeray] [char](1) NULL,
 CONSTRAINT [PK_tblTransactions] PRIMARY KEY NONCLUSTERED 
(
    [id] ASC
)WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [INDEX]
) ON [PRIMARY]
 
GO
 
SET ANSI_PADDING OFF
GO
Voici la requête :
Code : Sélectionner tout - Visualiser dans une fenêtre à part
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
USE [Tickets]
GO
/****** Object:  StoredProcedure [dbo].[UP_TILL_ANALYSIS]    Script Date: 08/30/2012 11:48:28 ******/
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
ALTER PROCEDURE [dbo].[UP_TILL_ANALYSIS] 
@Strsiege char(3),@DtdebA Datetime,@DtfinA Datetime,@DtdebP Datetime,@DtfinP Datetime
AS
BEGIN
    SET NOCOUNT ON;
--année précédente
    with T1(siege, date, caisse, ticket, ca_brut, ca_net, tot_rab, nb_art)
    as(
        select
            siege,
            cast(floor(cast(date_dt as float)) as datetime) as 'date',
            caisse,
            ticket,
            sum(ca) as 'ca_brut',
            sum(ca-rab) as 'ca_net',
            sum(rab) as 'tot_rab',
            sum(qt) as 'nb_art'
        from
            dbo.tblTransactions
        where
            siege = @Strsiege
            and date_dt between @DtdebP and @DtfinP
        group by
            siege,
            cast(floor(cast(date_dt as float)) as datetime),
            caisse,
            ticket
        ),
 
        T2 (siege, date, caisse, etage, nb_ticket, sum_ca_brut, avg_ca_brut, sum_ca_net, avg_ca_net, sum_tot_rab, avg_tot_rab, nb_art, pu_moyen,actprev)
        as(
            select 
                t.siege,
                t.date,
                t.caisse,
                c.etage,
                count(*) as 'nb_ticket',
                sum(ca_brut) as 'sum_ca_brut',
                avg(ca_brut) as 'avg_ca_brut',
                sum(ca_net) as 'sum_ca_net',
                avg(ca_net) as 'avg_ca_net',
                sum(tot_rab) as 'sum_tot_rab',
                avg(tot_rab) as 'avg_tot_rab',
                sum(nb_art) as 'nb_art',
                sum(ca_brut)/case sum(nb_art) when 0 then 1 else sum(nb_art) end as 'pu_moyen',
                'P' as 'actprev'
            from 
                T1 T
                inner join tb_caisses C
                on    T.siege = C.siege
                and T.caisse = C.caisse
            group by
                t.siege,
                t.date,
                t.caisse,
                c.etage
            ),--année actuelle
 
     T3(siege, date, caisse, ticket, ca_brut, ca_net, tot_rab, nb_art)
     as(
        select
            siege,
            cast(floor(cast(date_dt as float)) as datetime) as 'date',
            caisse,
            ticket,
            sum(ca) as 'ca_brut',
            sum(ca-rab) as 'ca_net',
            sum(rab) as 'tot_rab',
            sum(qt) as 'nb_art'
        from
            dbo.tblTransactions
        WHERE
            siege = @Strsiege
            and date_dt between @DtdebA and @DtfinA
        group by
            siege,
            cast(floor(cast(date_dt as float)) as datetime),
            caisse,
            ticket
        ),
 
        T4 (siege, date, caisse, etage, nb_ticket, sum_ca_brut, avg_ca_brut, sum_ca_net, avg_ca_net, sum_tot_rab, avg_tot_rab, nb_art, pu_moyen,actprev)
        as(
            select 
                t.siege,
                t.date,
                t.caisse,
                c.etage,
                count(*) as 'nb_ticket',
                sum(ca_brut) as 'sum_ca_brut',
                avg(ca_brut) as 'avg_ca_brut',
                sum(ca_net) as 'sum_ca_net',
                avg(ca_net) as 'avg_ca_net',
                sum(tot_rab) as 'sum_tot_rab',
                avg(tot_rab) as 'avg_tot_rab',
                sum(nb_art) as 'nb_art',
                sum(ca_brut)/case sum(nb_art) when 0 then 1 else sum(nb_art) end as 'pu_moyen',
                'A' as 'actprev'
            from 
                T3 T
                    inner join tb_caisses C
                    on    T.siege = C.siege
                    and T.caisse = C.caisse
            group by
                t.siege,
                t.date,
                t.caisse,
                c.etage
            )
 
--query
select
        t2.siege,
        t2.date,
        t2.caisse,
        t2.etage,
        t2.nb_ticket,
        t2.sum_ca_brut,
        t2.avg_ca_brut,
        t2.sum_ca_net,
        t2.avg_ca_net,
        t2.nb_art,
        t2.pu_moyen,
        t2.sum_ca_net/t2.nb_ticket as 'ticket moyen',
        t2.actprev
from
        T2 
 
union all
 
select
        t4.siege,
        t4.date,
        t4.caisse,
        t4.etage,
        t4.nb_ticket,
        t4.sum_ca_brut,
        t4.avg_ca_brut,
        t4.sum_ca_net,
        t4.avg_ca_net,
        t4.nb_art,
        t4.pu_moyen,
        t4.sum_ca_net/t4.nb_ticket as 'ticket moyen',
        t4.actprev
from    
        T4
order by
        actprev,
        siege,
        etage,
        caisse,
        date
 
END
Et voici ce que j'ai créé comme index mais sans résultat. J'ai forcément du merdé quelque part...
Code : Sélectionner tout - Visualiser dans une fenêtre à part
1
2
3
4
5
6
7
8
9
10
11
12
USE [Tickets]
GO
 
/****** Object:  Index [IX_TILL_ANALYSIS]    Script Date: 08/30/2012 11:49:43 ******/
CREATE NONCLUSTERED INDEX [IX_TILL_ANALYSIS] ON [dbo].[tblTransactions] 
(
    [date_dt] DESC,
    [siege] ASC
)
INCLUDE ( [caisse],
[ticket]) WITH (PAD_INDEX  = OFF, STATISTICS_NORECOMPUTE  = OFF, SORT_IN_TEMPDB = OFF, IGNORE_DUP_KEY = OFF, DROP_EXISTING = OFF, ONLINE = OFF, ALLOW_ROW_LOCKS  = ON, ALLOW_PAGE_LOCKS  = ON) ON [INDEX]
GO