× 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.



Hi Liam,

Darryl and Birgitta are right - what you want to do is not possible the way you try it, and dynamic SQL is often used, to solve this problem.

But ... dynamic SQL ist not the only solution. You can also use the SYSTOOLS.SPLIT table function, to split your variable in individual values.

EXEC SQL SELECT LOC INTO :wLOC
FROM LOCATION
WHERE LTYP NOT IN ('F','H','I','O','B')
AND SUBA IN (
select trim(both '''' from varchar(element, 5))
from table(systools.split( :wSUBA , ','))
)
AND PALT = :wPALT;

If I recalled the syntax of SPLIT and TRIM correctly (I don't give a guarantee) then the sub-select should split your list

'AA ','AB ','AC ','AD ','AE'

into

'AA '
'AB '
'AC '
'AD '
'AE'

Now I thought, that the quotes were just for the list, and you wanted to compare without the quotes - so the TRIM function is used to strip of those quote chars.

And then - the IN operator works on the result table like with any other SQL sub-select.

Just try it out interactively.

HTH

Regards,
Daniel


Am 25.06.2023 um 14:32 schrieb Birgitta Hauser <Hauser@xxxxxxxxxxxxxxx>:

This IN (:wSUBA) will not work with static SQL.
Each option has to be passed as a variable, i.e. IN(:VAR1, :VAR2, :VAR3,
:VAR4)

... alternatively you can use dynamic SQL and then embed your variable in
the SQL statement to be prepared.

Mit freundlichen Grüßen / Best regards

Birgitta Hauser
Modernization – Education – Consulting on IBM i

IBM Champion since 2020

"Shoot for the moon, even if you miss, you'll land among the stars." (Les
Brown)
"If you think education is expensive, try ignorance." (Derek Bok)
"What is worse than training your staff and losing them? Not training them
and keeping them!"
"Train people well enough so they can leave, treat them well enough so they
don't want to. " (Richard Branson)
"Learning is experience … everything else is only information!" (Albert
Einstein)

-----Original Message-----
From: RPG400-L <rpg400-l-bounces@xxxxxxxxxxxxxxxxxx> On Behalf Of liam
henderson
Sent: Friday, 23 June 2023 18:23
To: rpg400-l@xxxxxxxxxxxxxxxxxx
Subject: SQL question on embedded varaibles

Hi,
I'm trying to use a variable to list some values that I want to use on an IN
statement on my WHERE clause but don't seem to able to get it quite right.
Interactive SQL returns a result but the program doesn't It returns
SQLSTATE='02000' SQLCODE=100

EXEC SQL
SELECT LOC INTO :wLOC
FROM LOCATION
WHERE LTYP NOT IN ('F','H','I','O','B') AND
SUBA IN (:wSUBA) AND
PALT = :wPALT

The string :wSUBA is formatted as 'AA ','AB ','AC ','AD ','AE'
I tried moving the brackets into the string but that didn't work I also
tried removing the quotes and just comma separating but that didn't work Is
what I'm doing even possible or do I need to split them out and check one by
one?
I'm probably doing something really stupid.
Any help much appreciated.
Regards.
Liam.
--
This is the RPG programming on IBM i (RPG400-L) mailing list To post a
message email: RPG400-L@xxxxxxxxxxxxxxxxxx To subscribe, unsubscribe, or
change list options,
visit: https://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives at
https://archive.midrange.com/rpg400-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related
questions.


--
This is the RPG programming on IBM i (RPG400-L) mailing list
To post a message email: RPG400-L@xxxxxxxxxxxxxxxxxx
To subscribe, unsubscribe, or change list options,
visit: https://lists.midrange.com/mailman/listinfo/rpg400-l
or email: RPG400-L-request@xxxxxxxxxxxxxxxxxx
Before posting, please take a moment to review the archives
at https://archive.midrange.com/rpg400-l.

Please contact support@xxxxxxxxxxxxxxxxxxxx for any subscription related questions.


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.