× The internal search function is temporarily non-functional. The current search engine is no longer viable and we are researching alternatives.
As a stop gap measure, we are using Google's custom search engine service.
If you know of an easy to use, open source, search engine ... please contact support@midrange.com.



Jack,

The initial performance issues are due to the fact that MS SQL server will
pull back all rows from the referenced tables and run the query locally
when using 4-part naming to a linked server.

The solution for that is to use the OPENQUERY() function to send the SQL to
the target server and have it run there and only pull back results.

Having said that, a stored proc on the i is a very good idea.

I found an exmaple of the web of using a SP
SELECT *
FROM
OPENQUERY([RemoteServer],DatabaseName.DatabaseOwner.StoredProcedureName)

Though I thing you might need
SELECT *
FROM OPENQUERY([RemoteServer],"CALL MYLIB.MYSTOREDPROC('parm')")

Sorry It's been a while..
Charles





On Thu, May 24, 2018 at 11:16 AM, Jack Prucha <Jack.Prucha@xxxxxxx> wrote:

We're using a windows based imaging system that has a MS SQL document
repository. As part of the workflow we connect to the iSeries application
files. We're implementing the imaging system to interact with our biggest
iSeries application and the response can be slow because of the file sizes.

We speeded up this slow SELECT by creating a View on the iSeries side
returning just one column and subsetting the results with a join:

ALTER PROCEDURE [dbo].[SP_LNValidateBorrowerSSN]
@BorrSSN nvarchar(9)
AS
BEGIN
SELECT
Case
When count(*) >= 1 Then 'Valid'
Else 'Invalid'
End as SSNValid
FROM [CFITESTLOANS].[IASPCFI].[SLSFILESMT].[SLBRREV1]
Where Borrower_SSN = @BorrSSN
END

The process is still pulling over too many records so we want to push all
the work onto the iSeries side. Our smartest DB2 sql programmer helped me
create this Stored Procedure:

P1 : BEGIN
DECLARE EDITBORROWERSSN_C1 CURSOR WITH RETURN FOR

SELECT CASE
WHEN ( SELECT DISTINCT 1
FROM SLSFILESMT . SLBRREV1
WHERE BORROWER_SSN = @BORROWER_SSN
) IS NULL THEN RESULT
ELSE 'Valid'
END
FROM TABLE
( VALUES ( 'Invalid' ) )
AS TVALUES ( RESULT ) ;

OPEN EDITBORROWERSSN_C1 ;

END

This runs instantly when called from Run SQL scripts - CALL SLBRRES01
('123456789'). I cannot, however, come up with the correct syntax to call
the DB2 SP (SLBRRES01) from MS SQL. This "runs" without returning anything
as I can't setup the parameters without syntax errors:

EXEC('@Result = [CFITESTLOANS].[IASPCFI].[SLSFILESMT].[SLBRRES01]')

I'm trying different scenarios I've read on Google so I might be way off.
It doesn't have to be an SP. Could be a UDF or whatever on the iSeries
side. If this can be set up to run quickly we can use the same method in
many places.

Can anyone offer some help with this?

TIA

Ps
iSeries 7.3
MS SQL 2016 r13.x



Jack Prucha
Programming Team Supervisor

College Foundation, Inc.

This email, including any documents, files, or previous email messages
attached to it, has been sent from an email account of College Foundation
Inc., (CFI) and may contain confidential, proprietary, or legally
privileged information belonging to CFI. If you are not the intended
recipient, any dissemination, distribution, or copying of this email or its
attachments is strictly prohibited. If you have received this email in
error, please immediately notify the sender by email and destroy the
original email and any attachments.
--
This is the Midrange Systems Technical Discussion (MIDRANGE-L) mailing list
To post a message email: MIDRANGE-L@xxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/midrange-l.

Please contact support@xxxxxxxxxxxx for any subscription related
questions.

Help support midrange.com by shopping at amazon.com with our affiliate
link: http://amzn.to/2dEadiD


As an Amazon Associate we earn from qualifying purchases.

This thread ...

Follow-Ups:
Replies:

Follow On AppleNews
Return to Archive home page | Return to MIDRANGE.COM home page

This mailing list archive is Copyright 1997-2024 by midrange.com and David Gibbs as a compilation work. Use of the archive is restricted to research of a business or technical nature. Any other uses are prohibited. Full details are available on our policy page. If you have questions about this, please contact [javascript protected email address].

Operating expenses for this site are earned using the Amazon Associate program and Google Adsense.