Home » SQL & PL/SQL » SQL & PL/SQL » update table attribute help!
update table attribute help! [message #689617] Thu, 22 February 2024 10:27 Go to next message
ramys
Messages: 1
Registered: February 2024
Junior Member
Hi,

I need help please. I am loving oracle syntax (not really). I am unable to update attribute from another table using below.
It doesn't show an error but didn't update "id"

It works only when I hard code values.

 
Update MyTable a 
Set a.ID = 
   (select b.objid from SourceTable b
   where b.DESCRIPTION= trim(a.description)
   and a.id =76
   )
where a.id =76;
commit;



Re: update table attribute help! [message #689618 is a reply to message #689617] Thu, 22 February 2024 10:46 Go to previous messageGo to next message
Michel Cadot
Messages: 68647
Registered: March 2007
Location: Nanterre, France, http://...
Senior Member
Account Moderator

Welcome to the forum.

Not sure what you want exactly and what are the relations between the 2 tables but this is something like:
merge 
  into MyTable a 
  using SourceTable b
  on ( b.DESCRIPTION = trim(a.description) /* and b.id = a.id ? */ )
when matched then update set id = b.objid
/
Assuming there is only one row in table B satisfying the condition "b.DESCRIPTION = trim(a.description)...".


And the moderator bit:
Always post your Oracle version, with 4 decimals (query v$version), as often solution depends on it.
With any SQL or PL/SQL question, please, post a working Test case: create table (including all constraints) and insert statements along with the result you want with these data then we will be able work with your tables and data. Explain with words and sentences the rules that lead to this result.

[Updated on: Fri, 23 February 2024 00:56]

Report message to a moderator

Re: update table attribute help! [message #689620 is a reply to message #689617] Thu, 22 February 2024 11:25 Go to previous messageGo to next message
John Watson
Messages: 8931
Registered: January 2010
Location: Global Village
Senior Member
Which release are you using? If 23c, you have the "Direct Joins for UPDATE and DELETE Statements" capability. Something like this:
FREE>
FREE> select * from emp order by deptno;

          EMPNO ENAME      JOB                   MGR HIREDATE              SAL            COMM          DEPTNO
--------------- ---------- --------- --------------- --------- --------------- --------------- ---------------
           7782 CLARK      MANAGER              7839 09-JUN-81            2450                              10
           7839 KING       PRESIDENT                 17-NOV-81            5000                              10
           7934 MILLER     CLERK                7782 23-JAN-82            1300                              10
           7566 JONES      MANAGER              7839 02-APR-81            2975                              20
           7902 FORD       ANALYST              7566 03-DEC-81            3000                              20
           7876 ADAMS      CLERK                7788 23-MAY-87            1100                              20
           7369 SMITH      CLERK                7902 17-DEC-80             800                              20
           7788 SCOTT      ANALYST              7566 19-APR-87            3000                              20
           7521 WARD       SALESMAN             7698 22-FEB-81            1250             500              30
           7844 TURNER     SALESMAN             7698 08-SEP-81            1500               0              30
           7499 ALLEN      SALESMAN             7698 20-FEB-81            1600             300              30
           7900 JAMES      CLERK                7698 03-DEC-81             950                              30
           7698 BLAKE      MANAGER              7839 01-MAY-81            2850                              30
           7654 MARTIN     SALESMAN             7698 28-SEP-81            1250            1400              30

14 rows selected.

FREE> update emp e set e.ename=d.dname
from dept d
where e.deptno=d.deptno
and d.loc='DALLAS';  2    3    4

5 rows updated.

FREE> select * from emp order by deptno;

          EMPNO ENAME      JOB                   MGR HIREDATE              SAL            COMM          DEPTNO
--------------- ---------- --------- --------------- --------- --------------- --------------- ---------------
           7782 CLARK      MANAGER              7839 09-JUN-81            2450                              10
           7839 KING       PRESIDENT                 17-NOV-81            5000                              10
           7934 MILLER     CLERK                7782 23-JAN-82            1300                              10
           7566 RESEARCH   MANAGER              7839 02-APR-81            2975                              20
           7902 RESEARCH   ANALYST              7566 03-DEC-81            3000                              20
           7876 RESEARCH   CLERK                7788 23-MAY-87            1100                              20
           7369 RESEARCH   CLERK                7902 17-DEC-80             800                              20
           7788 RESEARCH   ANALYST              7566 19-APR-87            3000                              20
           7521 WARD       SALESMAN             7698 22-FEB-81            1250             500              30
           7844 TURNER     SALESMAN             7698 08-SEP-81            1500               0              30
           7499 ALLEN      SALESMAN             7698 20-FEB-81            1600             300              30
           7900 JAMES      CLERK                7698 03-DEC-81             950                              30
           7698 BLAKE      MANAGER              7839 01-MAY-81            2850                              30
           7654 MARTIN     SALESMAN             7698 28-SEP-81            1250            1400              30

14 rows selected.

FREE>
Note that my example is using the SCOTT demonstration schema. If you stick with the supplied demos, it saves you the trouble of having to create a test case.
Re: update table attribute help! [message #689621 is a reply to message #689617] Thu, 22 February 2024 21:57 Go to previous message
flyboy
Messages: 1903
Registered: November 2006
Senior Member
Just for completeness, as the posted methods seem better (although the "Direct Joins for UPDATE and DELETE Statements" syntax seems weird to me), you were close to the corellated subquery, as described e.g. here: https://oracle-base.com/articles/misc/updates-based-on-queries
Update MyTable a 
Set a.ID = 
   (select b.objid from SourceTable b
   where b.DESCRIPTION= trim(a.description)
   and a.id = b.id
   )
where exists (
select b.objid from SourceTable b
   where b.DESCRIPTION= trim(a.description)
   and a.id = b.id
);
You shall omit the WHERE clause if OBJID in the non-matching MyTable rows shall be updated to NULL.
Previous Topic: Query having multiple subqueries to be simplified
Next Topic: BLOB Column with Zip File Convert to CLOB
Goto Forum:
  


Current Time: Sat Apr 27 16:09:44 CDT 2024