|
|
Archives of the TeradataForum
Message Posted: Thu, 18 Jan 2001 @ 16:12:12 GMT
Subj: | | Re: OR in a WHERE clause |
|
From: | | Rudel Simard |
Thank you for your suggestion Claybourne, we try to figure out an other way to create single report than do 2 separate reports. It will
be less expensive for the 'developer report maintenance'.
I understand the way Teradata does for the utilisation of the index and the statistics on the tables are good. I use EXPLAIN often to
understand the way Teradata works with the NUPI, statistics... I give you, Frank, the 2 explains to help your understanding of my
problem.
I really appreciate your help, thank for your support
EXPLAIN
SELECT T1."COL1_NUSI" (NAMED "c1" ) ,
T2."COL2_NUSI" (NAMED "c2" ) FROM
( DONNE.TABLE2 T2 LEFT OUTER JOIN DONNE.TABLE1 T1 ON
T2."COL3_NUPI" = T1."COL3_NUPI")
WHERE (1 = 1 AND 25113 = T2."COL2_NUSI" OR
1 = 2 AND '123' = T1."COL1_NUSI" ) and
T2.COL4_NUSI BETWEEN 990101 AND 991231;
*** Help information returned. 29 rows.
*** Total elapsed time was 1 second.
Explanation -------------------------------------------------- | |
| 1) | First, we lock a distinct DONNE."pseudo table" for read on a RowHash to prevent global deadlock for DONNE.T1.
| |
| 2) | Next, we lock a distinct DONNE."pseudo table" for read on a RowHash to prevent global deadlock for DONNE.T2.
| |
| 3) | We lock DONNE.T1 for read, and we lock DONNE.T2 for read.
| |
| 4) | We do an all-AMPs JOIN step from DONNE.T1 by way of a RowHash match scan with no residual conditions, which is joined to DONNE.T2
with a condition of ("((DONNE.T2.COL2_NUSI = 25113) OR (1 = 2 )) AND ((DONNE.T2.COL4_NUSI <= DATE '1999-12-31') AND ((DONNE.T2.COL4_NUSI >=
DATE '1999-01-01') AND ((1 = 2) OR (1 = 1 ))))"). DONNE.T1 and DONNE.T2 are right outer joined using a merge join, with a join condition of
("DONNE.T2.COL3_NUPI = DONNE.T1.COL3_NUPI"). The input tables DONNE.T1 and DONNE.T2 will not be cached in memory. The result goes into
Spool 2, which is built locally on the AMPs. The result spool file will not be cached in memory. The size of Spool 2 is estimated with low
confidence to be 63,308,472 rows. The estimated time for this step is 1 hour and 9 minutes.
| |
| 5) | We do an all-AMPs RETRIEVE step from Spool 2 (Last Use) by way of an all-rows scan with a condition of ("((1 = 1) OR
(Spool_2.COL1_NUSI = '123')) AND ((Spool_2.COL2_NUSI = 25113) OR (Spool_2.COL1_NUSI = '123'))") into Spool 1, which is built locally on the
AMPs. The result spool file will not be cached in memory. The size of Spool 1 is estimated with low confidence to be 63,308,472 rows. The
estimated time for this step is 6 minutes and 32 seconds.
| |
| 6) | Finally, we send out an END TRANSACTION step to all AMPs involved in processing the request.
| |
| -> | The contents of Spool 1 are sent back to the user as the result of statement 1. The total estimated time is 1 hour and 15 minutes.
| |
EXPLAIN
SELECT T1."COL1_NUSI" (NAMED "c1" ) ,
T2."COL2_NUSI" (NAMED "c2" ) FROM
( TABLE2 T2 LEFT OUTER JOIN TABLE1 T1 ON
T2."COL3_NUPI" = T1."COL3_NUPI")
WHERE (1 = 1 AND 25113 = T2."COL2_NUSI") and
T2.COL4_NUSI BETWEEN 990101 AND 991231;
*** Help information returned. 20 rows.
*** Total elapsed time was 1 second.
Explanation -------------------------------------------------- | |
| 1) | First, we lock a distinct DONNE."pseudo table" for read on a RowHash to prevent global deadlock for DONNE.T1.
| |
| 2) | Next, we lock a distinct DONNE."pseudo table" for read on a RowHash to prevent global deadlock for DONNE.T2.
| |
| 3) | We lock DONNE.T1 for read, and we lock DONNE.T2 for read.
| |
| 4) | We do an all-AMPs JOIN step from DONNE.T2 by way of index # 20 "DONNE.T2.COL2_NUSI = 25113" with a residual condition of
("(DONNE.T2.COL4_NUSI <= DATE '1999-12-31') AND ((DONNE.T2.COL4_NUSI >= DATE '1999-01-01') AND (1 = 1 ))"), which is joined to DONNE.T1.
DONNE.T2 and DONNE.T1 are left outer joined using a merge join, with a join condition of ("DONNE.T2.COL3_NUPI = DONNE.T1.COL3_NUPI"). The
input tables DONNE.T2 and DONNE.T1 will not be cached in memory. The result goes into Spool 1, which is built locally on the AMPs. The
size of Spool 1 is estimated with low confidence to be 24,844 rows. The estimated time for this step is 2 minutes and 7 seconds.
| |
| 5) | Finally, we send out an END TRANSACTION step to all AMPs involved in processing the request.
| |
| -> | The contents of Spool 1 are sent back to the user as the result of statement 1. The total estimated time is 2 minutes and 7 seconds.
| |
Rudel Simard
R�gie de l'assurance-maladie du Qu�bec
DBA de l'environnement informationnel
| |