I really need help with the below query written in MySQL I want to convert in Oracle pl/sql. I read some Oracle text document and I suppose that for MATCH AGAINST
in MySQL I can use CONTAINS
in Oracle, but I have a problem converting the columns score, score0 and score1.
SELECT table_id,
MATCH(text) AGAINST('grand hotel') AS score,
MATCH(text) AGAINST('grand') AS score0,
MATCH(text) AGAINST('hotel') AS score1
FROM tbl
WHERE MATCH(text) AGAINST('grand hotel')
ORDER BY score ASC
I suppose the documentation you refer in your question is Oracle Text and that you're already somewhat familiar with the feature. You also give no reason why PL/SQL should be involved so below is a simple plain SQL example that should address your question:
The data
create table so32 as
select 1 as id, 'Lorem grand ipsum dolor sit amet, consectetur adipiscing elit. Cras faucibus.' as text from dual union all
select 2 as id, 'Lorem ipsum hotel dolor sit amet, consectetur adipiscing elit. Cras faucibus.' as text from dual union all
select 3 as id, 'Lorem ipsum dolor sit amet, grand consectetur adipiscing elit. Cras faucibus.' as text from dual union all
select 4 as id, 'Lorem ipsum dolor sit amet, consectetur hotel adipiscing elit. Cras faucibus.' as text from dual union all
select 5 as id, 'Lorem ipsum dolor sit amet, consectetur adipiscing elit grand. Cras faucibus.' as text from dual union all
select 6 as id, 'Lorem ipsum dolor sit amet grand hotel, consectetur adipiscing elit. Cras faucibus.' as text from dual
;
Oracle Text index
create index so32_index on so32(text) indextype is ctxsys.context;
The query
select id,
score(1) as grand,
score(2) as hotel,
score(3) as grandhotel
from so32
where contains(text, 'grand', 1) > 0
or contains(text, 'hotel', 2) > 0
or contains(text, 'grand hotel', 3) > 0
order by score(3), score(2), score(1)
;
Results
ID GRAND HOTEL GRANDHOTEL
---------- ---------- ---------- ----------
1 4 0 0
3 4 0 0
5 4 0 0
4 0 4 0
2 0 4 0
6 4 4 4
6 rows selected.
Hope this helps !