SELECT NOTE_FILE_NAME,NOTE_CREATE_DATE,NOTE_TYPE,NOTE_TOPIC,NOTE_CONTENT_1,
NOTE_CONTENT_2,NOTE_CONTENT_3,NOTE_CONTENT_4,NOTE_CONTENT_5,NOTE_CONTENT_6,
NOTE_CONTENT_7,NOTE_CONTENT_8,NOTE_CONTENT_9,NOTE_CONTENT_10,INV_NO,
INV_PURCHASE_ORD_NO,INV_CUSTOMER_NO,INV_BILL_TO_NAME,INV_SHIP_TO_NAME,
INV_SHIP_VIA_CODE,INV_DATE
FROM NOTE_INV_VIEW WHERE
INV_CUSTOMER_NO = '651675' AND
NOTE_TYPE = 'SHIP' AND
NOTE_FILE_NAME = 'CPINVHDR' AND
NOTE_CREATE_DATE = 20171211
SELECT NOTE_FILE_NAME, NOTE_CREATE_DATE,NOTE_TYPE,NOTE_TOPIC,NOTE_CONTENT_1,
NOTE_CONTENT_2,NOTE_CONTENT_3,NOTE_CONTENT_4,NOTE_CONTENT_5,NOTE_CONTENT_6,
NOTE_CONTENT_7,NOTE_CONTENT_8,NOTE_CONTENT_9,NOTE_CONTENT_10,INV_NO,
INV_PURCHASE_ORD_NO,INV_CUSTOMER_NO,INV_BILL_TO_NAME,INV_SHIP_TO_NAME,
INV_SHIP_VIA_CODE,INV_DATE
FROM CPINVHDR, NOTES
WHERE INV_CUSTOMER_NO
= '651675'
AND NOTE_FILE_NAME = 'CPINVHDR'
AND NOTE_FILE_REF_NO = RIGHT(CONCAT('000000',CONVERT(INV_NO,SQL_CHAR)),6)
AND NOTE_TYPE = 'SHIP'
AND NOTE_CREATE_DATE = 20171211;
I changed the SELECT statement in the following way:
So the lessons from this example are: (A) Sometimes you need to perform your own join instead of using the existing view to get the best performance, and; (B) you need to form a strategy on how to use index to speed up your join.
Note that you can also use the following SQL SELECT statement, but the performance will not be good:
SELECT NOTE_FILE_NAME, NOTE_CREATE_DATE,NOTE_TYPE,NOTE_TOPIC,NOTE_CONTENT_1,
NOTE_CONTENT_2,NOTE_CONTENT_3,NOTE_CONTENT_4,NOTE_CONTENT_5,NOTE_CONTENT_6,
NOTE_CONTENT_7,NOTE_CONTENT_8,NOTE_CONTENT_9,NOTE_CONTENT_10,INV_NO,
INV_PURCHASE_ORD_NO,INV_CUSTOMER_NO,INV_BILL_TO_NAME,INV_SHIP_TO_NAME,
INV_SHIP_VIA_CODE,INV_DATE
FROM CPINVHDR, NOTES
WHERE INV_CUSTOMER_NO
= '651675'
AND NOTE_FILE_NAME = 'CPINVHDR'
AND CONVERT(NOTE_FILE_REF_NO,SQL_NUMERIC) = INV_NO
AND NOTE_TYPE = 'SHIP'
AND NOTE_CREATE_DATE = 20171211;
The reason this SELECT statement will not perform as well is because when the system joins from CPINVHDR to NOTES, it will not able to use the NOTE_FILE_REF_NO index due to the "CONVERT" function. As a result, it has to read through all the CPINVHDR notes and that is much more data to process and thus slows down the procedure. So the most important takeaway is that you need to understand how to help influence the PSQL relational engine to use the index so it can complete the operation quickly by reading through the smallest number of records.
EMK