forked from MRGhidini/SAP_Queries
-
Notifications
You must be signed in to change notification settings - Fork 0
/
Copy pathQRY Aging de Fornecedores - Novo.sql
170 lines (148 loc) · 6.8 KB
/
QRY Aging de Fornecedores - Novo.sql
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
162
163
164
165
166
167
168
169
170
/*Relatório Aging de Fornecedores */
/*select 1 from [DBO].[OPCH] T40 where T40.DocDate <= '[%0]' and T40.DocDueDate > = '[%1]' and T40.DocDueDate <= '[%2]' and T40.CardName = '[%3]' */
declare @DataBase datetime, @DataVencIni datetime, @DataVencFim datetime, @CardName varchar(100)
set @DataBase = '[%0]'
set @DataVencIni = '[%1]'
set @DataVencFim = '[%2]'
set @CardName = isnull('[%3]','')
SELECT MAX(T0.[ShortName]) 'Código Fornecedor',
MAX(T4.CardName) 'Nome Fornecedor',
ISNULL((CASE max(T0.TransType)
WHEN 30 THEN 'LCM'
WHEN 13 THEN 'NF de Saida'
WHEN 14 THEN 'Dev. NF de Saida'
WHEN 15 THEN 'Entrega'
WHEN 16 THEN 'Devolução'
WHEN 18 THEN 'NF de Entrada'
WHEN 19 THEN 'Dev. NF de Entrada'
WHEN 20 THEN 'Recebimento de Mercadoria'
WHEN 21 THEN 'Devolução de Mercadoria'
WHEN 69 THEN 'Despesas de Importação'
WHEN 60 THEN 'Saída de Mercadoria'
WHEN 59 THEN 'Entrada de Mercadoria'
WHEN 46 THEN 'Contas a Pagar'
WHEN 24 THEN 'Contas a Receber'
WHEN 162 THEN 'Reavaliação de Estoque'
WHEN 67 THEN 'Transferencia de Estoque'
WHEN 203 THEN 'Adiantamento a Cliente'
WHEN 204 THEN 'Adiantamento a Fornecedor'
END),'') 'Tipo Doc',
MAX(T0.[BaseRef]) 'No. Doc SAP',
MAX(T0.[LineMemo]) 'Observações / No. NF',
MAX(T0.[SourceLine]) 'No. da Prestação',
MAX(T0.[RefDate]) 'Data de Lançamento',
MAX(T0.[TaxDate]) 'Data do Documento',
MAX(T0.[DueDate]) 'Data de Vencimento',
MAX(T0.[BalDueCred]) + SUM(T1.[ReconSum]) 'Saldo',
MAX(T0.[Account]) 'Conta',
T0.[TransId] 'No. LCM',
T0.[Line_ID] 'No. da Linha LCM'
FROM [dbo].[JDT1] T0 INNER JOIN
[dbo].[ITR1] T1 ON T1.[TransId] = T0.[TransId] AND T1.[TransRowId] = T0.[Line_ID] INNER JOIN
[dbo].[OITR] T2 ON T2.[ReconNum] = T1.[ReconNum] INNER JOIN
[dbo].[OJDT] T3 ON T3.[TransId] = T0.[TransId] INNER JOIN
[dbo].[OCRD] T4 ON T4.[CardCode] = T0.[ShortName] LEFT OUTER JOIN
[dbo].[B1_JournalTransSourceView] T5 ON T5.[ObjType] = T0.[TransType] AND T5.[DocEntry] = T0.[CreatedBy] AND (T5.[TransType] <> 'I' OR (T5.[TransType] = 'I' AND T5.[InstlmntID] = T0.[SourceLine] ))
WHERE (T0.DueDate >= isnull(@DataVencIni,'') or ISNULL(@DataVencIni,'') = '')
and (T0.DueDate <= isnull(@DataVencFim,'') or ISNULL(@DataVencFim,'') = '')
and (T4.CardName like '%'+@CardName+'%' or @CardName = '')
and T0.[RefDate] <= @DataBase AND T0.[RefDate] <= @DataBase
AND T4.[CardType] = 'S'
AND T2.[ReconDate] > @DataBase
AND T1.[IsCredit] = 'C'
GROUP BY T0.[TransId], T0.[Line_ID], T0.[BPLName] HAVING MAX(T0.[BalFcCred]) <>- SUM(T1.[ReconSumFC]) OR MAX(T0.[BalDueCred]) <>- SUM(T1.[ReconSum])
UNION ALL
SELECT
MAX(T0.[ShortName]),
MAX(T4.CardName),
ISNULL((CASE max(T0.TransType)
WHEN 30 THEN 'LCM'
WHEN 13 THEN 'NF de Saida'
WHEN 14 THEN 'Dev. NF de Saida'
WHEN 15 THEN 'Entrega'
WHEN 16 THEN 'Devolução'
WHEN 18 THEN 'NF de Entrada'
WHEN 19 THEN 'Dev. NF de Entrada'
WHEN 20 THEN 'Recebimento de Mercadoria'
WHEN 21 THEN 'Devolução de Mercadoria'
WHEN 69 THEN 'Despesas de Importação'
WHEN 60 THEN 'Saída de Mercadoria'
WHEN 59 THEN 'Entrada de Mercadoria'
WHEN 46 THEN 'Contas a Pagar'
WHEN 24 THEN 'Contas a Receber'
WHEN 162 THEN 'Reavaliação de Estoque'
WHEN 67 THEN 'Transferencia de Estoque'
WHEN 203 THEN 'Adiantamento a Cliente'
WHEN 204 THEN 'Adiantamento a Fornecedor'
END),''),
MAX(T0.[BaseRef]),
MAX(T0.[LineMemo]),
MAX(T0.[SourceLine]),
MAX(T0.[RefDate]),
MAX(T0.[TaxDate]),
MAX(T0.[DueDate]),
- MAX(T0.[BalDueDeb]) - SUM(T1.[ReconSum]),
MAX(T0.[Account]),
T0.[TransId],
T0.[Line_ID]
FROM [dbo].[JDT1] T0 INNER JOIN [dbo].[ITR1] T1 ON T1.[TransId] = T0.[TransId] AND
T1.[TransRowId] = T0.[Line_ID] INNER JOIN [dbo].[OITR] T2 ON T2.[ReconNum] = T1.[ReconNum] INNER JOIN [dbo].[OJDT] T3 ON T3.[TransId] = T0.[TransId]
INNER JOIN [dbo].[OCRD] T4 ON T4.[CardCode] = T0.[ShortName] LEFT OUTER JOIN [dbo].[B1_JournalTransSourceView] T5 ON T5.[ObjType] = T0.[TransType] AND T5.[DocEntry] = T0.[CreatedBy] AND (T5.[TransType] <> 'I' OR (T5.[TransType] = 'I' AND T5.[InstlmntID] = T0.[SourceLine] ))
WHERE (T0.DueDate >= isnull(@DataVencIni,'') or ISNULL(@DataVencIni,'') = '') and
(T0.DueDate <= isnull(@DataVencFim,'') or ISNULL(@DataVencFim,'') = '') and
(T4.CardName like '%'+@CardName+'%' or @CardName = '') and
T0.[RefDate] <= @DataBase AND
T0.[RefDate] <= @DataBase AND
T4.[CardType] = 'S' AND
T2.[ReconDate] > @DataBase AND
T1.[IsCredit] = 'D'
GROUP BY T0.[TransId],
T0.[Line_ID],
T0.[BPLName]
HAVING MAX(T0.[BalFcDeb]) <>- SUM(T1.[ReconSumFC]) OR MAX(T0.[BalDueDeb]) <>- SUM(T1.[ReconSum])
UNION ALL
SELECT
MAX(T0.[ShortName]),
MAX(T2.CardName),
ISNULL((CASE max(T0.TransType)
WHEN 30 THEN 'LCM'
WHEN 13 THEN 'NF de Saida'
WHEN 14 THEN 'Dev. NF de Saida'
WHEN 15 THEN 'Entrega'
WHEN 16 THEN 'Devolução'
WHEN 18 THEN 'NF de Entrada'
WHEN 19 THEN 'Dev. NF de Entrada'
WHEN 20 THEN 'Recebimento de Mercadoria'
WHEN 21 THEN 'Devolução de Mercadoria'
WHEN 69 THEN 'Despesas de Importação'
WHEN 60 THEN 'Saída de Mercadoria'
WHEN 59 THEN 'Entrada de Mercadoria'
WHEN 46 THEN 'Contas a Pagar'
WHEN 24 THEN 'Contas a Receber'
WHEN 162 THEN 'Reavaliação de Estoque'
WHEN 67 THEN 'Transferencia de Estoque'
WHEN 203 THEN 'Adiantamento a Cliente'
WHEN 204 THEN 'Adiantamento a Fornecedor'
END),''),
MAX(T0.[BaseRef]),
MAX(T0.[LineMemo]),
MAX(T0.[SourceLine]),
MAX(T0.[RefDate]),
MAX(T0.[TaxDate]),
MAX(T0.[DueDate]),
MAX(T0.[BalDueCred]) - MAX(T0.[BalDueDeb]),
MAX(T0.[Account]),
T0.[TransId],
T0.[Line_ID]
FROM [dbo].[JDT1] T0 INNER JOIN [dbo].[OJDT] T1 ON T1.[TransId] = T0.[TransId]
INNER JOIN [dbo].[OCRD] T2 ON T2.[CardCode] = T0.[ShortName]
LEFT OUTER JOIN [dbo].[B1_JournalTransSourceView] T3 ON T3.[ObjType] = T0.[TransType] AND T3.[DocEntry] = T0.[CreatedBy] AND (T3.[TransType] <> 'I' OR (T3.[TransType] = 'I' AND T3.[InstlmntID] = T0.[SourceLine] ))
WHERE (T0.DueDate >= isnull(@DataVencIni,'') or ISNULL(@DataVencIni,'') = '') and
(T0.DueDate <= isnull(@DataVencFim,'') or ISNULL(@DataVencFim,'') = '') and
(T2.CardName like '%'+@CardName+'%' or @CardName = '') and
T0.[RefDate] <= @DataBase AND
T0.[RefDate] <= @DataBase AND
T2.[CardType] = 'S' AND
(T0.[BalDueCred] <> T0.[BalDueDeb] OR T0.[BalFcCred] <> T0.[BalFcDeb] ) AND
NOT EXISTS (SELECT U0.[TransId], U0.[TransRowId] FROM [dbo].[ITR1] U0 INNER JOIN [dbo].[OITR] U1 ON U1.[ReconNum] = U0.[ReconNum] WHERE T0.[TransId] = U0.[TransId] AND T0.[Line_ID] = U0.[TransRowId] AND U1.[ReconDate] > @DataBase GROUP BY U0.[TransId], U0.[TransRowId]) GROUP BY T0.[TransId], T0.[Line_ID], T0.[BPLName]
Order by 'Data de Vencimento', 'Data de Lançamento'