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



Thanks Mike. I already have that e-book for lunch time reading (again). Cross & Lateral need a few more reads to sink in.

Just due to time, I'm going to crank this out in RPG before I leave today.


________________________________________
From: MIDRANGE-L <midrange-l-bounces@xxxxxxxxxxxx> on behalf of Mike Jones <mike.jones.sysdev@xxxxxxxxx>
Sent: Wednesday, November 25, 2015 1:39 PM
To: midrange-l@xxxxxxxxxxxx
Subject: Re: SQL "like" from a subselect (Roger Harman)

Hi Roger,

I tend to use this design pattern for matches like that, when there is more
than one row to match, and I want to pick only one row match out of many.
This give you the flexibility to pick which single row out of many matches
to include in the set:

select A.*, SN.SRCHNAME
from TABLE_A A
cross join lateral (
select SN.SRCHNAME
from NAMEFILE SN
where lower(A.UPTEXT) like SN.SRCHNAME
order by [add column(s) here to prioritize which matching row to select]
--or remove the order by to randomly pick one row
fetch first row only --pick only one row
) as SN

Note: CROSS JOIN will discard rows from TABLE_A without a match. Use LEFT
JOIN instead if you want all TABLE_A rows in the set, regardless if a match
is present or not.

Add this to the query if you want a count of the matches:

cross join lateral (
select count(*) as MATCH_COUNT
from NAMEFILE SN
where lower(A.UPTEXT) like SN.SRCHNAME
) as CNT

...along with adding CNT.MATCH_COUNT to the SELECT column list.

This mini eBook will teach you everything you're likely to want to know
about this technique:
https://drive.google.com/file/d/0B86kLoHq8E_PeVlhNmZORmpBUjA/view?usp=sharing

Mike


date: Wed, 25 Nov 2015 19:38:54 +0000
from: Roger Harman <roger.harman@xxxxxxxxxxx>
subject: SQL "like" from a subselect

I'm trying to match employee names (first or last) to text in the user
profile. ?It's just a rough match to help operations in a task.

I have all the first & last names in a file and the user profile info in
another.

I've tried "where lower(UPTEXT) like (select srchname from namefile)" but
it fails with SQL0811 "Result of SELECT more than one row".

The search names are in the form of "%roger%". ?I can match singles in
STRSQL.

I can whip up an RPG with %scan() but curious if?I can?make the subselect
work. ?There are hundreds of profiles and thousands of employees.

Thanks in advance.


Roger Harman
COMMON Certified Application Developer - ILE RPG on IBM i on Power
OCEAN User Group

--
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: http://lists.midrange.com/mailman/listinfo/midrange-l
or email: MIDRANGE-L-request@xxxxxxxxxxxx
Before posting, please take a moment to review the archives
at http://archive.midrange.com/midrange-l.


As an Amazon Associate we earn from qualifying purchases.

This thread ...

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.