Bonjour,

Ne disposant pas d'expert Oracle sur mon projet, je vous demande conseil...
J'ai une procédure stockée dont le rôle est de remplir un champ (REGION_CODE) dans une table (PBILL_INVOICE_DETAIL)
Pour cela la procédure telle qu'elle est codée actuellement passe par 5 update successifs (avec des clauses where différentes bien entendus)

Je pense que si je passe par un curseur et que je traite mes lignes une par une (avec un CASE ou une serie de IF) je devrais être capable de faire le même travail 5 fois plus vite... (enfin peut être)

La seule chose qui me gêne c'est que je ne pourrais plus gérer la log de la même façon... (puisque là il inscrit la log cas par cas)

Me trompes je ???

ah oui je suis sous Oracle 9i

Ci-joint le code de la procedure incriminée...

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
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
CREATE OR REPLACE PROCEDURE GET_PU_UPD_REGION_CODE (
 
  v_group_bills         IN  NUMBER)
IS
  d_system_date         DATE;
iNbLines NUMBER;
BEGIN
 
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Begin proc upd region code', NULL);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region code for pre-rated', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
------------------------------------------------------------------------
--           Update of Region Code
------------------------------------------------------------------------
-- Updating region codes in PBILL_INVOICE_DETAIL for pre-rated services
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INV_DET_TYPE_CODE_INDEX)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE   = (SELECT /*+ RULE
                                         INDEX (n NRC_XNRC_TRACK_NDX)
                                     */
                                  MAX(n.CIR_NRR_RATE)
                              FROM
                                  NRC n
                              WHERE
                                      pbid.SUBTYPE_CODE = n.TYPE_ID_NRC
                                  AND pbid.SUBSCR_NO = n.SUBSCR_NO
                                  AND pbid.SUBSCR_NO_RESETS = n.SUBSCR_NO_RESETS
                                  AND pbid.TRACKING_ID = n.TRACKING_ID
                                  AND pbid.TRACKING_ID_SERV = n.TRACKING_ID_SERV)
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
	AND pbid.type_code = 3
        AND pbid.REGION_CODE IS NULL
	AND (
		pbid.subtype_code IN (
			SELECT
				prc.type_id_nrc
			FROM PRE_RATED_CHARGES prc
                        WHERE decode_region_code = 1
			)
		OR
		pbid.PRODUCT_LINE_ID IN (
			SELECT
				prs.PRODUCT_LINE_ID
			FROM PRE_RATED_SERVICES prs
			)
		);
 
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region code pre-rated', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region exception 1 (shared)', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Updating region code from PBILL_INVOICE_DETAIL (exceptions 1 shared)
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INVOICE_DETAIL_IND_BILL)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE = (SELECT  /*+ RULE
                                        INDEX (ej2 PK_EMF_JOIN2)
                                        INDEX (sre1 PK_SITA_REGION_EXCEPTIONS1)
                                    */
                                    sre1.REGION_CODE
                            FROM
                                SITA_REGION_EXCEPTIONS1 sre1,
                                EMF_JOIN2 ej2
                            WHERE
                                    sre1.PRODUCT_LINE_ID = pbid.PRODUCT_LINE_ID
                                AND pbid.TYPE_CODE IN (2, 3, 7)
                                AND sre1.SHARED  = 'S'
                                AND ej2.SHARED = 'S'
                                AND ej2.SUBSCR_NO = pbid.SUBSCR_NO
                                AND ej2.SUBSCR_NO_RESETS = pbid.SUBSCR_NO_RESETS)
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
        AND pbid.REGION_CODE IS NULL;
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, ...
...
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Updating region code from PBILL_INVOICE_DETAIL (exceptions 1 non shared)
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INVOICE_DETAIL_IND_BILL)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE = (SELECT  /*+ RULE
                                        INDEX (ej2 PK_EMF_JOIN2)
                                        INDEX (sre1 PK_SITA_REGION_EXCEPTIONS1)
                                    */
                                    sre1.REGION_CODE
                            FROM
                                SITA_REGION_EXCEPTIONS1 sre1,
                                EMF_JOIN2 ej2
                            WHERE
                                    sre1.PRODUCT_LINE_ID = pbid.PRODUCT_LINE_ID
                                AND pbid.TYPE_CODE IN (2, 3, 7)
                                AND pbid.TYPE_CODE = sre1.TYPE_CODE
                                AND sre1.CHARGE_CODE = pbid.SUBTYPE_CODE
                                AND (sre1.SHARED <> 'S' OR sre1.SHARED IS NULL)
                                AND ej2.SUBSCR_NO = pbid.SUBSCR_NO
                                AND ej2.SUBSCR_NO_RESETS = pbid.SUBSCR_NO_RESETS)
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
        AND pbid.REGION_CODE IS NULL;
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region exception 1 (non shared)', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region exception 2', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Updating region code from PBILL_INVOICE_DETAIL (exceptions 2)
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INVOICE_DETAIL_IND_BILL)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE =  (SELECT /*+ RULE ORDERED
                                       INDEX (sre2 PK_SITA_REGION_EXCEPTIONS2)
                                       INDEX (ccv PK_COUNTRY_CODE_VALUES)
                                   */
                                   sre2.REGION_CODE
                            FROM
                                 COUNTRY_CODE_VALUES ccv,
								                 SITA_REGION_EXCEPTIONS2 sre2
                            WHERE
                                  (sre2.PRODUCT_LINE_ID = pbid.PRODUCT_LINE_ID
                        	    OR sre2.PRODUCT_LINE_ID = 0)
                               AND sre2.SITA_COUNTRY_CODE = ccv.SHORT_DISPLAY
                               AND ccv.COUNTRY_CODE = pbid.COUNTRY_CODE
							                 AND ccv.LANGUAGE_CODE = 1)
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
        AND pbid.REGION_CODE IS NULL;
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region exception 2', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region exception 3', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Updating region code from PBILL_INVOICE_DETAIL (exceptions 3)
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INVOICE_DETAIL_IND_BILL)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE = (SELECT /*+ RULE
                                       INDEX (sre3 PK_SITA_REGION_EXCEPTIONS3)
                                   */
                                  sre3.REGION_CODE
                            FROM
                                  SITA_REGION_EXCEPTIONS3 sre3
                            WHERE sre3.PRODUCT_LINE_ID = pbid.PRODUCT_LINE_ID)
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
        AND pbid.REGION_CODE IS NULL;
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region exception 3', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region default', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Updating region code from PBILL_INVOICE_DETAIL (all remaining)
BEGIN
    UPDATE  /*+ ORDERED use_nl(pbid)
                INDEX (pbid PBILL_INVOICE_DETAIL_IND_BILL)
            */
    PBILL_INVOICE_DETAIL pbid
    SET pbid.REGION_CODE = (SELECT /*+ RULE
                                       INDEX (src SITA_REGION_CODES_IDX)
                                   */
                                    NVL(MIN(src.SITA_REGION_CODE), 670)
                            FROM
                                    SITA_REGION_CODES src
                            WHERE
                                    src.COUNTRY_CODE = pbid.COUNTRY_CODE
                                AND src.BILLABLE = 'Y'
                                AND src.PHYSICAL_FLAG = 'P')
    WHERE
        (INDEX_BILL_REF, INDEX_BILL_REF_RESETS) IN
						 (
						 SELECT /*+ RULE
                           INDEX (tmp_list TEMP_BIP_LST_IDX1)
                       */
                       tmp_list.INDEX_BILL_REF,
                       tmp_list.INDEX_BILL_REF_RESETS
               FROM    TEMP_BIP_LST tmp_list
               WHERE
                       tmp_list.GROUP_ID = v_group_bills)
        AND pbid.REGION_CODE IS NULL;
 
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region default', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region INC', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Update region codes for SITA INC: general case
BEGIN
 
UPDATE /*+ RULE ROWID(pbid)*/
	PBILL_INVOICE_DETAIL pbid
SET pbid.REGION_CODE = (
	SELECT src.SITA_REGION_CODE
	FROM SITA_REGION_CODES src
	WHERE src.COUNTRY_CODE = pbid.COUNTRY_CODE
	AND src.BILLABLE = 'Y' AND src.DEFAULT_INC_FLAG = 1
	)
WHERE pbid.ROWID IN (
	SELECT /*+ ORDERED use_nl(pbi) use_nl(ev) use_nl(pbid)
		INDEX (pbid2 PBILL_INVOICE_DETAIL_IND_BILL)
		INDEX (pbi pk_pbill_invoice)
		INDEX (tmp_list TEMP_BIP_LST_IDX1)
		INDEX (ev PK_ENTITY_VALUES)
	        */
		pbid2.ROWID
	FROM
		TEMP_BIP_LST tmp_list,
		PBILL_INVOICE pbi,
		ENTITY_VALUES ev,
		PBILL_INVOICE_DETAIL pbid2
	WHERE
	    tmp_list.GROUP_ID = v_group_bills
	AND tmp_list.INDEX_BILL_REF = pbi.INDEX_BILL_REF
	AND tmp_list.INDEX_BILL_REF_RESETS = pbi.INDEX_BILL_REF_RESETS
	AND pbid2.INDEX_BILL_REF = pbi.INDEX_BILL_REF
	AND pbid2.INDEX_BILL_REF_RESETS = pbi.INDEX_BILL_REF_RESETS
	AND pbi.entity_code = ev.ENTITY_CODE
	AND ev.PROVIDER = 'INC'
	AND EXISTS (
		SELECT 1
		FROM SITA_REGION_CODES src
		WHERE src.BILLABLE = 'Y'
		AND src.DEFAULT_INC_FLAG = 1
		AND src.COUNTRY_CODE = pbid2.country_code
		)
	AND NOT EXISTS (
		SELECT
		1
		FROM PRE_RATED_SERVICES prs
		WHERE prs.product_line_id = pbid2.product_line_id
		AND prs.product_line_id != 453
		)
	AND EXISTS (
			   	SELECT 1
			   	FROM   	PRE_RATED_CHARGES prc
				WHERE	prc.type_id_nrc = pbid2.subtype_code
				AND 	prc.decode_inc_region_code = 1
				)
	);
 
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region INC', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region INC group', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Update region codes for SITA INC: product group exception
BEGIN
UPDATE /*+ RULE ROWID(pbid)*/
   PBILL_INVOICE_DETAIL pbid
SET pbid.REGION_CODE = (
	SELECT /*+ ORDERED INDEX(pbi pk_pbill_invoice) INDEX(pl PRODUCT_LINES_PK) INDEX(sre sita_rgn_except_inc_idx_perf1) */
		   sre.REGION_CODE
	FROM PBILL_INVOICE pbi, PRODUCT_LINES pl, SITA_REGION_EXCEPTIONS_INC sre
	WHERE pbi.INDEX_BILL_REF = pbid.INDEX_BILL_REF
	AND pbi.INDEX_BILL_REF_RESETS = pbid.INDEX_BILL_REF_RESETS
	AND sre.ENTITY_CODE = pbi.ENTITY_CODE
	AND pbid.PRODUCT_LINE_ID = pl.PRODUCT_LINE_ID
	AND pl.PRODUCT_GROUP_ID = sre.PRODUCT_GROUP_ID
	AND sre.PRODUCT_LINE_ID IS NULL
	)
WHERE pbid.ROWID IN (
	SELECT /*+ ORDERED use_nl(pbi) use_nl(pbid)
		INDEX (tmp_list TEMP_BIP_LST_IDX1)
		INDEX (pbid2 PBILL_INVOICE_DETAIL_IND_BILL)
		INDEX (pbi pk_pbill_invoice)
		INDEX(pl PRODUCT_LINES_PK)
		*/
		pbid2.ROWID
	FROM    TEMP_BIP_LST tmp_list,
		PBILL_INVOICE pbi,
		SITA_REGION_EXCEPTIONS_INC sre,
		PRODUCT_LINES pl,
		PBILL_INVOICE_DETAIL pbid2
	WHERE
	    tmp_list.GROUP_ID = v_group_bills
	AND tmp_list.INDEX_BILL_REF = pbi.INDEX_BILL_REF
	AND tmp_list.INDEX_BILL_REF_RESETS = pbi.INDEX_BILL_REF_RESETS
	AND pbi.INDEX_BILL_REF = pbid2.INDEX_BILL_REF
	AND pbi.INDEX_BILL_REF_RESETS = pbid2.INDEX_BILL_REF_RESETS
	AND sre.ENTITY_CODE = pbi.ENTITY_CODE
	AND pbid2.PRODUCT_LINE_ID = pl.PRODUCT_LINE_ID
	AND pl.PRODUCT_GROUP_ID = sre.PRODUCT_GROUP_ID
	AND sre.PRODUCT_LINE_ID IS NULL
	);
 
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region INC group', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'Region INC pl', NULL);
COMMIT;
 
SAVEPOINT UPD_REGION_CODE;
 
-- Update region codes for SITA INC: product line exception
BEGIN
UPDATE /*+ RULE ROWID(pbid) */ PBILL_INVOICE_DETAIL pbid
SET pbid.REGION_CODE = (
	SELECT /*+ ORDERED INDEX(pbi pk_pbill_invoice) INDEX(sre sita_rgn_except_inc_idx_perf1) */
	  sre.REGION_CODE
	FROM
		PBILL_INVOICE pbi,
		SITA_REGION_EXCEPTIONS_INC sre
	WHERE pbi.INDEX_BILL_REF = pbid.INDEX_BILL_REF
	AND pbi.INDEX_BILL_REF_RESETS = pbid.INDEX_BILL_REF_RESETS
	AND sre.ENTITY_CODE = pbi.ENTITY_CODE
	AND pbid.PRODUCT_LINE_ID = sre.PRODUCT_LINE_ID)
WHERE pbid.ROWID IN (
	SELECT /*+ RULE ORDERED use_nl(pbi) use_nl(pbid)
		INDEX(tmp_list TEMP_BIP_LST_IDX1)
		INDEX(pbi PK_PBILL_INVOICE)
		INDEX(pbid PBILL_INVOICE_IND_BILL)
		*/
		pbid2.ROWID
	FROM 	TEMP_BIP_LST tmp_list,
		PBILL_INVOICE pbi,
		SITA_REGION_EXCEPTIONS_INC sre,
		PBILL_INVOICE_DETAIL pbid2
	WHERE pbi.INDEX_BILL_REF = pbid2.INDEX_BILL_REF
	AND pbi.INDEX_BILL_REF_RESETS = pbid2.INDEX_BILL_REF_RESETS
	AND sre.ENTITY_CODE = pbi.ENTITY_CODE
	AND pbid2.PRODUCT_LINE_ID = sre.PRODUCT_LINE_ID
	AND tmp_list.GROUP_ID = v_group_bills
	AND tmp_list.INDEX_BILL_REF = pbi.INDEX_BILL_REF
	AND tmp_list.INDEX_BILL_REF_RESETS = pbi.INDEX_BILL_REF_RESETS
	);
 
iNbLines:=SQL%ROWCOUNT;
EXCEPTION
  WHEN OTHERS THEN
	ROLLBACK TO UPD_REGION_CODE;
    RAISE;
    RETURN;
END;
 
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End region INC pl', iNbLines);
INSERT INTO BILL_TRANSFER_LOG ( GROUP_ID, DATE_TIME, MSG_TYPE, MSG_TEXT, NB_LINES )
VALUES (v_group_bills,  SYSDATE, 'I', 'End proc upd region code', NULL);
 
COMMIT;
 
END;
/