Bonjour,

J'ai développé une procédure stocké pour l'insertion des clients dans une base Sage L100 à partir d'une autre base de données , maintenant je veux rendre ma procédure un peu générique et réutilisable dans d'autres situations, c'est à dire rendre la la source des données paramétrable (dans ma proc c'est la view vClientWave) via un paramètre de type table est c'est la bonne solution déjà? et comment pourrais je faire l'appel de la proc après (crée une table temporaire et la passer en paramètre ?)


Autres propositions aussi svp pour améliorer mon code et mes connaissances (fonctionnellement ça marche sans problème mais surement j'ai fait quelques bétises quelques part... )

Merci à vous

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
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
 
 
CREATE PROCEDURE [dbo].[sp_IntegrationClient]
AS
 
 
/****************************************************************************************
sp_IntegrationClient v1.0 
 
Procedure stocke pour integrer les nouveaux clients WaveSoft=>Sage
 
Author : ICH
Company : AP
History : 
	     21/09/2018 => Création de la procedure
 
 
 
 
 
*****************************************************************************************/
 
         BEGIN
             SET NOCOUNT ON;
		   SET LANGUAGE [Français];  
 
             DECLARE @recipients varchar(max)= '';
             DECLARE @copy_recipients varchar(max)= '';
             DECLARE @body varchar(max);
             DECLARE @subject varchar(max);
             DECLARE @profile_name varchar(max)= 'AdminSQL';
             DECLARE @dt_debut datetime= SYSDATETIME();
		   --
             DECLARE @tab TABLE
(CT_Num        varchar(17) ,
 CT_Intitule   varchar(35) ,
 CT_Adresse    varchar(35) ,
 CT_CodePostal varchar(9) ,
 CT_Ville      varchar(35) ,
 CT_Pays       varchar(35) ,
 CT_Telephone  varchar(21)
);
             BEGIN
                 BEGIN TRY
                     BEGIN TRANSACTION;
 
 
			  -- Insertion des clients
                     INSERT INTO F_COMPTET
(
                            CT_Num ,
                            CT_Intitule ,
                            CT_Type ,
                            CG_NumPrinc ,
                            CT_Qualite ,
                            CT_Classement ,
                            CT_Contact ,
                            CT_Adresse ,
                            CT_Complement ,
                            CT_CodePostal ,
                            CT_Ville ,
                            CT_CodeRegion ,
                            CT_Pays ,
                            CT_Raccourci ,
                            BT_Num ,
                            N_Devise ,
                            CT_Ape ,
                            CT_Identifiant ,
                            CT_Siret ,
                            CT_Statistique01 ,
                            CT_Statistique02 ,
                            CT_Statistique03 ,
                            CT_Statistique04 ,
                            CT_Statistique05 ,
                            CT_Statistique06 ,
                            CT_Statistique07 ,
                            CT_Statistique08 ,
                            CT_Statistique09 ,
                            CT_Statistique10 ,
                            CT_Commentaire ,
                            CT_Encours ,
                            CT_Assurance ,
                            CT_NumPayeur ,
                            N_Risque ,
                            CO_No ,
                            N_CatTarif ,
                            CT_Taux01 ,
                            CT_Taux02 ,
                            CT_Taux03 ,
                            CT_Taux04 ,
                            N_CatCompta ,
                            N_Period ,
                            CT_Facture ,
                            CT_BLFact ,
                            CT_Langue ,
                            N_Expedition ,
                            N_Condition ,
                            CT_DateCreate ,
                            CT_Saut ,
                            CT_Lettrage ,
                            CT_ValidEch ,
                            CT_Sommeil ,
                            DE_No ,
                            CT_ControlEnc ,
                            CT_NotRappel ,
                            N_Analytique ,
                            CT_Telephone ,
                            CT_Telecopie ,
                            CT_EMail ,
                            CT_Site ,
                            CT_Coface ,
                            CT_Surveillance ,
                            CT_SvDateCreate ,
                            CT_SvFormeJuri ,
                            CT_SvEffectif ,
                            CT_SvCA ,
                            CT_SvResultat ,
                            CT_SvIncident ,
                            CT_SvDateIncid ,
                            CT_SvPrivil ,
                            CT_SvRegul ,
                            CT_SvCotation ,
                            CT_SvDateMaj ,
                            CT_SvObjetMaj ,
                            CT_SvDateBilan ,
                            CT_SvNbMoisBilan ,
                            N_AnalytiqueIFRS ,
                            CT_PrioriteLivr ,
                            CT_LivrPartielle ,
                            MR_No ,
                            CT_NotPenal ,
                            EB_No ,
                            CT_DateFermeDebut ,
                            CT_DateFermeFin ,
                            CT_FactureElec ,
                            CT_TypeNIF ,
                            CT_RepresentInt ,
                            CT_RepresentNIF ,
                            CT_EdiCodeType ,
                            CT_EdiCode ,
                            CT_EdiCodeSage ,
                            CT_ProfilSoc ,
                            CT_StatutContrat ,
                            CT_DateMAJ ,
                            CT_EchangeRappro ,
                            CT_EchangeCR ,
                            PI_NoEchange ,
                            CT_BonAPayer ,
                            CT_DelaiTransport ,
                            CT_DelaiAppro ,
                            CT_LangueISO2 ,
                            CT_AnnulationCR ,
                            CT_CessionCreance ,
                            CT_Facebook ,
                            CT_LinkedIn ,
                            CT_ExclureTrait ,
                            CT_GDPR ,
                            CT_Prospect
)
                     OUTPUT
                            inserted.CT_Num ,
                            SUBSTRING(inserted.CT_Intitule , 1 , 35) ,
                            SUBSTRING(inserted.CT_Adresse , 1 , 35) ,
                            SUBSTRING(inserted.CT_CodePostal , 1 , 9) ,
                            SUBSTRING(inserted.CT_Ville , 1 , 35) ,
                            SUBSTRING(inserted.CT_Pays , 1 , 35) ,
                            SUBSTRING(inserted.CT_Telephone , 1 , 21)
                            INTO @tab(
                                 CT_Num ,
                                 CT_Intitule ,
                                 CT_Adresse ,
                                 CT_CodePostal ,
                                 CT_Ville ,
                                 CT_Pays ,
                                 CT_Telephone)
                            SELECT
                                   c.TIRCODE AS                        CT_Num ,
                                   SUBSTRING(c.TIRSOCIETE , 1 , 35) AS CT_Intitule ,
                                   0 AS                                CT_Type ,
                                   '411100' AS                         CG_NumPrinc ,
                                   CAST('' AS varchar(1)) AS           CT_Qualite ,
                                   SUBSTRING(c.TIRSOCIETE , 1 , 17) AS CT_Classement ,
                                   CAST('' AS varchar(1)) AS           CT_Contact ,
                                   SUBSTRING(c.ADRL1 , 1 , 35) AS      CT_Adresse ,
                                   CAST('' AS varchar(1)) AS           CT_Complement ,
                                   c.ADRCODEPOSTAL AS                  CT_CodePostal ,
                                   c.ADRVILLE AS                       CT_Ville ,
                                   CAST('' AS varchar(1)) AS           CT_CodeRegion ,
                                   c.ADRPAYS AS                        CT_Pays ,
                                   CAST('' AS varchar(1)) AS           CT_Raccourci ,
                                   CAST('' AS varchar(1)) AS           BT_Num ,
                                   0 AS                                N_Devise ,
                                   0 AS                                CT_Ape ,
                                   CAST('' AS varchar(1)) AS           CT_Identifiant ,
                                   CAST('' AS varchar(1)) AS           CT_Siret ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique01 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique02 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique03 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique04 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique05 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique06 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique07 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique08 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique09 ,
                                   CAST('' AS varchar(1)) AS           CT_Statistique10 ,
                                   CAST('' AS varchar(1)) AS           CT_Commentaire ,
                                   0 AS                                CT_Encours ,
                                   0 AS                                CT_Assurance ,
                                   c.TIRCODE AS                        CT_NumPayeur ,
                                   1 AS                                N_Risque ,
                                   0 AS                                CO_No ,
                                   1 AS                                N_CatTarif ,
                                   0 AS                                CT_Taux01 ,
                                   0 AS                                CT_Taux02 ,
                                   0 AS                                CT_Taux03 ,
                                   0 AS                                CT_Taux04 ,
                                   1 AS                                N_CatCompta ,
                                   1 AS                                N_Period ,
                                   1 AS                                CT_Facture ,
                                   0 AS                                CT_BLFact ,
                                   0 AS                                CT_Langue ,
                                   1 AS                                N_Expedition ,
                                   1 AS                                N_Condition ,
                                   CAST(GETDATE() AS date) AS          CT_DateCreate ,
                                   1 AS                                CT_Saut ,
                                   1 AS                                CT_Lettrage ,
                                   0 AS                                CT_ValidEch ,
                                   0 AS                                CT_Sommeil ,
                                   0 AS                                DE_No ,
                                   0 AS                                CT_ControlEnc ,
                                   0 AS                                CT_NotRappel ,
                                   0 AS                                N_Analytique ,
                                   SUBSTRING(c.Telephone , 1 , 21) AS  CT_Telephone ,
                                   CAST('' AS varchar(1)) AS           CT_Telecopie ,
                                   CAST('' AS varchar(1)) AS           CT_EMail ,
                                   CAST('' AS varchar(1)) AS           CT_Site ,
                                   CAST('' AS varchar(1)) AS           CT_Coface ,
                                   0 AS                                CT_Surveillance ,
                                   CAST('01/01/1753' AS date) AS       CT_SvDateCreate ,
                                   CAST('' AS varchar(1)) AS           CT_SvFormeJuri ,
                                   CAST('' AS varchar(1)) AS           CT_SvEffectif ,
                                   0 AS                                CT_SvCA ,
                                   0 AS                                CT_SvResultat ,
                                   0 AS                                CT_SvIncident ,
                                   CAST('01/01/1753' AS date) AS       CT_SvDateIncid ,
                                   0 AS                                CT_SvPrivil ,
                                   CAST('' AS varchar(1)) AS           CT_SvRegul ,
                                   CAST('' AS varchar(1)) AS           CT_SvCotation ,
                                   CAST('01/01/1753' AS date) AS       CT_SvDateMaj ,
                                   CAST('' AS varchar(1)) AS           CT_SvObjetMaj ,
                                   CAST('01/01/1753' AS date) AS       CT_SvDateBilan ,
                                   0 AS                                CT_SvNbMoisBilan ,
                                   0 AS                                N_AnalytiqueIFRS ,
                                   0 AS                                CT_PrioriteLivr ,
                                   0 AS                                CT_LivrPartielle ,
                                   0 AS                                MR_No ,
                                   0 AS                                CT_NotPenal ,
                                   0 AS                                EB_No ,
                                   CAST('01/01/1753' AS date) AS       CT_DateFermeDebut ,
                                   CAST('01/01/1753' AS date) AS       CT_DateFermeFin ,
                                   0 AS                                CT_FactureElec ,
                                   0 AS                                CT_TypeNIF ,
                                   CAST('' AS varchar(1)) AS           CT_RepresentInt ,
                                   CAST('' AS varchar(1)) AS           CT_RepresentNIF ,
                                   0 AS                                CT_EdiCodeType ,
                                   CAST('' AS varchar(1)) AS           CT_EdiCode ,
                                   CAST('' AS varchar(1)) AS           CT_EdiCodeSage ,
                                   0 AS                                CT_ProfilSoc ,
                                   0 AS                                CT_StatutContrat ,
                                   CAST('01/01/1753' AS date) AS       CT_DateMAJ ,
                                   0 AS                                CT_EchangeRappro ,
                                   1 AS                                CT_EchangeCR ,
                                   0 AS                                PI_NoEchange ,
                                   0 AS                                CT_BonAPayer ,
                                   0 AS                                CT_DelaiTransport ,
                                   0 AS                                CT_DelaiAppro ,
                                   CAST('' AS varchar(1)) AS           CT_LangueISO2 ,
                                   1 AS                                CT_AnnulationCR ,
                                   0 AS                                CT_CessionCreance ,
                                   CAST('' AS varchar(1)) AS           CT_Facebook ,
                                   CAST('' AS varchar(1)) AS           CT_LinkedIn ,
                                   0 AS                                CT_ExclureTrait ,
                                   0 AS                                CT_GDPR ,
                                   0 AS                                CT_Prospect
                            FROM
                                 vClientWave AS c;
 
 
 
 
-- Insertion Log Client
                     INSERT INTO AP_IntegLog
(
                            DT_Debut ,
                            DT_Fin ,
                            Integ_Comment ,
                            Integ_NbRow ,
                            Integ_Stat
)
                     VALUES
(@dt_debut ,
 GETDATE() ,
 'Insertion Clients' ,
 @@rowcount ,
 1
);
                     SET @dt_debut = SYSDATETIME();
                     -- Insertion des adresses de livraison
                     INSERT INTO F_LIVRAISON
(
                            LI_no ,
                            CT_Num ,
                            LI_Intitule ,
                            LI_Adresse ,
                            LI_Complement ,
                            LI_CodePostal ,
                            LI_Ville ,
                            LI_CodeRegion ,
                            LI_Pays ,
                            LI_Contact ,
                            N_Expedition ,
                            N_Condition ,
                            LI_Principal ,
                            LI_Telephone ,
                            LI_Telecopie ,
                            LI_EMail
)
                            SELECT
                                   NEXT VALUE FOR sq_F_Livraison AS      LI_No ,
                                   c.CT_Num AS                           CT_Num ,
                                   SUBSTRING(c.CT_Intitule , 1 , 35) AS  LI_Intitule ,
                                   SUBSTRING(c.CT_Adresse , 1 , 35) AS   LI_Adresse ,
                                   CAST('' AS varchar(1)) AS             LI_Complement ,
                                   SUBSTRING(c.CT_CodePostal , 1 , 9) AS LI_CodePostal ,
                                   SUBSTRING(c.CT_Ville , 1 , 35) AS     LI_Ville ,
                                   CAST('' AS varchar(1)) AS             LI_CodeRegion ,
                                   SUBSTRING(c.CT_Pays , 1 , 35) AS      LI_Pays ,
                                   CAST('' AS varchar(1)) AS             LI_Contact ,
                                   1 AS                                  N_Expedition ,
                                   1 AS                                  N_Condition ,
                                   1 AS                                  LI_Principal ,
                                   SUBSTRING(c.CT_Telephone , 1 , 21) AS LI_Telephone ,
                                   CAST('' AS varchar(1)) AS             LI_Telecopie ,
                                   CAST('' AS varchar(1)) AS             LI_EMail
                            FROM
                                 @tab AS c;  
 
 
-- Insertion Log livraison
                     INSERT INTO AP_IntegLog
(
                            DT_Debut ,
                            DT_Fin ,
                            Integ_Comment ,
                            Integ_NbRow ,
                            Integ_Stat
)
                     VALUES
(@dt_debut ,
 GETDATE() ,
 'Insertion Adresse Livraison' ,
 @@rowcount ,
 1
);
 
 
 
			--	 Insertion Affectation Client - CompteG
 
                     SET @dt_debut = SYSDATETIME();
                     INSERT INTO F_COMPTETG
(
                            CT_Num ,
                            CG_Num
)
                            SELECT
                                   c.CT_Num AS CT_Num ,
                                   '411100' AS CG_Num
                            FROM
                                 @tab AS c;  
 
 
-- Insertion Log Compteg
                     INSERT INTO AP_IntegLog
(
                            DT_Debut ,
                            DT_Fin ,
                            Integ_Comment ,
                            Integ_NbRow ,
                            Integ_Stat
)
                     VALUES
(@dt_debut ,
 GETDATE() ,
 'Insertion Comptet - Compteg' ,
 @@rowcount ,
 1
);
                     COMMIT TRANSACTION;
                     SET @body = 'Résultat : Intégration des clients effectuée avec succès ';
                     SET @body+=CHAR(13);
                     SET @body+='Nombre de ligne : ';
                     SET @body+= ( SELECT
                                          CAST(COUNT(*) AS varchar(20))
                                   FROM
                                        @tab );
                     SET @subject = '[Success] Intégration Clients Toopty WaveSoft=>Sage';
				-- 
 
                 END TRY
                 BEGIN CATCH
                     ROLLBACK TRANSACTION;
                     INSERT INTO AP_IntegLog
(
                            DT_Debut ,
                            DT_Fin ,
                            Integ_Comment ,
                            Integ_NbRow ,
                            Integ_Stat
)
                     VALUES
(@dt_debut ,
 GETDATE() ,
 ERROR_MESSAGE() ,
 0 ,
 0
);
 
                     SET @body = 'Resultat : Erreur d''integration des clients ';
                     SET @body+=CHAR(13);
                     SET @body+='Détail de l''erreur : ';
                     SET @body+=CHAR(13);
                     SET @body+= ( SELECT
                                          CAST(ERROR_NUMBER() AS varchar(5))+' - '+CAST(ERROR_MESSAGE() AS varchar(max)) AS ErrorMessage );
                     SET @subject = '[Fail] Intégration Clients';
                 END CATCH;
             END;
 
		   -- Envoi de mail 
             EXEC msdb.dbo.sp_send_dbmail
                  @profile_name = @profile_name ,
                  @recipients = @recipients ,
                  @copy_recipients = @copy_recipients ,
                  @body = @body ,
                  @subject = @subject;
         END;
GO