Results 1 to 5 of 5
  1. #1
    Join Date
    Sep 2013
    Posts
    23

    Unanswered: update sql using a view and a table

    Hi, wondering where i am going wrong if someone can help me with this please?

    UPDATE RE_EZPAY_AT_AGENCY_DAILY
    SET RE_EZPAY_AT_AGENCY_DAILY.STATUS = 'R'
    INNER JOIN VE_MEMBER
    ON RE_EZPAY_AT_AGENCY_DAILY.MEMBER_NO = VE_MEMBER.MEMBER_NO
    WHERE VE_MEMBER.MEMBER_JOIN_DATE < SYSDATE - 365;

  2. #2
    Join Date
    Feb 2004
    Location
    In front of the computer
    Posts
    15,579
    Provided Answers: 54
    Oracle does not support JOIN operations in an UPDATE statement, but you can get the same effect using a subquery:
    Code:
    UPDATE RE_EZPAY_AT_AGENCY_DAILY
       SET STATUS = 'R'
       WHERE VE_MEMBER.MEMBER_JOIN_DATE < sysdate -365
          AND STATUS = 'O'
          AND EXISTS (SELECT 1
             FROM VE_MEMBER
             WHERE RE_EZPAY_AT_AGENCY_DAILY.MEMBER_NO = VE_MEMBER.MEMBER_NO);
    -PatP
    In theory, theory and practice are identical. In practice, theory and practice are unrelated.

  3. #3
    Join Date
    Sep 2013
    Posts
    23
    Thanks Pat! very helpful tip about the new post too, i'm new to this

  4. #4
    Join Date
    Feb 2004
    Location
    In front of the computer
    Posts
    15,579
    Provided Answers: 54
    No problem! Everybody that participates is new at some point.

    I've been new for so long that I'm old!

    -PatP
    In theory, theory and practice are identical. In practice, theory and practice are unrelated.

  5. #5
    Join Date
    Jan 2004
    Location
    Croatia, Europe
    Posts
    4,094
    Provided Answers: 4
    Maybe just a suggestion. This:
    Code:
    WHERE VE_MEMBER.MEMBER_JOIN_DATE < sysdate -365
    is supposed to check dates which were earlier than "last year"? If so, perhaps you should consider using ADD_MONTHS instead, which means that the above code would look like
    Code:
    WHERE VE_MEMBER.MEMBER_JOIN_DATE < add_months(sysdate, -12)
    because "365" (as a number of days) doesn't take care about leap years.

    Also, keep in mind that SYSDATE is a function that returns date AND time, so code might even evaluate to
    Code:
    WHERE VE_MEMBER.MEMBER_JOIN_DATE < add_months(trunc(sysdate), -12)

Posting Permissions

  • You may not post new threads
  • You may not post replies
  • You may not post attachments
  • You may not edit your posts
  •