Skip to Main Content
  • Questions
  • SQL Query aggregation and subqueries

Breadcrumb

Question and Answer

Tom Kyte

Thanks for the question, Munzer.

Asked: March 17, 2002 - 2:09 pm UTC

Answered by: Tom Kyte - Last updated: April 24, 2016 - 6:19 am UTC

Category: ApplicationServer - Version: 8.1.7

Viewed 100K+ times! This question is

You Asked

Tom:

I have a table that initially stores information about items in a warehouse stored in different bins. Table look like this where manual inventories are done every 3 months. Effective date is the sysdate when record is inserted.

Inventory:

Item_no Qty Bin Effective_Date
AC006 10 DC001 2/1/2002
AC006 20 DC002 2/1/2002

AC006 100 DC001 5/1/2002
AC006 50 DC002 5/2/2002
AC006 30 DC003 5/3/2002
AC006 20 DC008 5/4/2002

I need to calculate two things:

1. Total Qty of an item in inventory in a given bin. which I basically did by taking qty of the item in inventory with the max(effective_Date)+total_received and stored in that bin since that max(effective_date) – total shipped from that bin since that max(effective_date).

2. Total qty of an item in inventory. Here I need to look at the highest effective date for an item at a bin. Bascially I need to run a SQL statement that gives me 200(sum last 4 recrods) for total of an item “AC006”. How do you formulate that statement and exclude all the previous inventories for that item that are out of date.

3. Also, let me say I have the following table. Would it still work where I basically stored the items in different bins.

Inventory:

Item_no Qty Bin Effective_Date
AC006 10 DC001 2/1/2002
AC006 20 DC002 2/1/2002

AC006 100 DC003 5/1/2002
AC006 50 DC004 5/2/2002

The answer here should be 150 and not 180.

Thank you,



and we said...

Ok, well

1) that sounds like you are giving me a statement of fact. I don't see a question there, only how you answered your own question.

2) Well, if we start with:

ops$tkyte@ORA817DEV.US.ORACLE.COM> select * from t;

ITEM_ QTY BIN EFFECTIVE_
----- ---------- ----- ----------
AC006 10 DC001 02/01/2002
AC006 20 DC002 02/01/2002
AC006 100 DC001 05/01/2002
AC006 50 DC002 05/02/2002
AC006 30 DC003 05/03/2002
AC006 20 DC008 05/04/2002
AC007 10 DC001 02/01/2002
AC007 20 DC002 02/01/2002
AC007 77 DC001 05/01/2002
AC007 32 DC002 05/02/2002
AC007 52 DC003 05/03/2002
AC007 33 DC008 05/04/2002

12 rows selected.

I'll show you at least three different ways to get this. The first is the best in my opinion (easy to read, performs well)

ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> select item_no, sum(qty)
2 from (
3 select distinct item_no, bin,
4 first_value(qty) over(partition by item_no, bin
5 order by effective_date desc) qty
6 from t
7 )
8 group by item_no
9 /

ITEM_ SUM(QTY)
----- ----------
AC006 200
AC007 194

it uses the analytic functions available with 816 EE and up...

The next uses a "max" trick i use alot to avoid correlated subqueries:


ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> select substr( data, 14, 5 ) item_no, sum( to_number( substr( data, 19 ) ) ) qty
2 from (
3 select max( to_char( effective_date, 'YYYYMMDD' ) || rpad( bin, 5 ) || rpad( item_no, 5 ) || to_char(qty) ) data
4 from t
5 group by item_no, bin
6 )
7 group by substr( data, 14, 5 )
8 /

ITEM_ QTY
----- ----------
AC006 200
AC007 194


and the last uses a correlated subquery:

ops$tkyte@ORA817DEV.US.ORACLE.COM>
ops$tkyte@ORA817DEV.US.ORACLE.COM> select item_no, sum(qty)
2 from t
3 where effective_date = ( select max(effective_date)
4 from t t2
5 where t2.item_no = t.item_no
6 and t2.bin = t.bin )
7 group by item_no
8 /

ITEM_ SUM(QTY)
----- ----------
AC006 200
AC007 194

ops$tkyte@ORA817DEV.US.ORACLE.COM>

to achieve the same...

3) No, not at all. Why would it be 150 and not 180? How would a computer know that -- you are using some hidden piece of knowledge in this case. I don't even know what that hidden bit of knowledge is myself. Basically you are saying "hey, if there is some long period of time between sets of measurements, ignore the old stuff". Only if you could tell me exactly (procedurally) how to filter this data (eg: only use data whose effective_date is within 5 days of the max effective_date). Otherwise -- it would seem to me that the answer is 180, not 150.



and you rated our response

  (933 ratings)

Is this answer out of date? If it is, please let us know via a Review

Reviews

SQL query

March 17, 2002 - 3:49 pm UTC

Reviewer: munz from reston, usa

Excellent as usual

Why r u Using Distinct and then First_value here

March 19, 2002 - 7:38 am UTC

Reviewer: Pascal from germany,HH

Refer to ur Query just compied from above:

select item_no, sum(qty)
2 from (
3 select distinct item_no, bin,
4 first_value(qty) over(partition by item_no, bin
5 order by effective_date desc) qty
6 from t
7 )
8 group by item_no
9 /

I have been reading ur Book and been trying these Analytic Functions myself..but sometimes i had to use Distinct to get correct results ---otherwise , it doesn't work..

Can u please Clarify a bit more why r u using Distinct and then first_value here..
Wouldn't first_value be sufficient ?

Thanks and Best Regards,

pascal


Tom Kyte

Followup  

March 19, 2002 - 9:04 am UTC

Well, I'm actually using the ANALYTIC function and then the distinct.

We got -- for every row in T (where there are more then one row for each ITEM_NO, BIN combination) the first_value of qty when sorted descending by date. That would give us 12 rows (using my example) with many duplicates. The distinct will remove the duplicate ITEM_NO/BIN combinations and then the sum collapses out the BIN dimension.

query

June 24, 2003 - 4:09 pm UTC

Reviewer: mo

Tom:

I have this query:

ISD> select a.request_id,a.shipment_id,b.item_number,b.stock_number,
2 max(a.shipment_date) from shipment a, shipped_item b
3 where a.shipment_id = b.shipment_id and b.disposition='B'
4 group by a.request_id,a.shipment_id,stock_number,item_number;

REQUEST_ID SHIPMENT_ID ITEM_NUMBER STOCK_NUMB MAX(A.SHIPMENT_DATE)
---------- ----------- ----------- ---------- --------------------
593 2074 2 AC010 24-jun-2003 00:00:00
593 2074 4 BB005 24-jun-2003 00:00:00
593 2075 2 AC010 25-jun-2003 00:00:00
593 2075 4 BB005 25-jun-2003 00:00:00
594 2076 1 AC010 24-jun-2003 00:00:00
594 2076 2 BB005 24-jun-2003 00:00:00
594 2076 3 MS193 24-jun-2003 00:00:00

7 rows selected.

What i am tring to get is the records of the shipment of the max date. so here it would exclude the first two. how would you do this.

Tom Kyte

Followup  

June 25, 2003 - 11:31 am UTC

select * (
select a.request_id,a.shipment_id,b.item_number,b.stock_number,
a.shipment_date,
max(a.shipment_date) over (partition by shipment_id) max_ship_date
from shipment a, shipped_item b
where a.shipment_id = b.shipment_id
and b.disposition='B'
)
where shipment_date = max_ship_date
/









actual query

June 24, 2003 - 5:03 pm UTC

Reviewer: mo

Tom:

Please disregard previous query. here is the actual one. I have two tables: shipment (PK is shipment_id) and shipped_item (PK is shipment_id,stock_number and item_number). Every shipment record that has a backorder flag, I want to read the quantity. However if it is the same item and request id I am only intersted in the last shipped one. SO here the result should be so that I skip
the first and third records.

1 select a.request_id,b.stock_number,b.backorder_quantity,
2 a.shipment_date from shipment a, shipped_item b
3 where a.shipment_id = b.shipment_id and b.disposition='B'
5* order by 1,2
ISD> /

REQUEST_ID STOCK_NUMB BACKORDER_QUANTITY SHIPMENT_DATE
---------- ---------- ------------------ --------------------
593 AC010 190 24-jun-2003 00:00:00
593 AC010 145 25-jun-2003 00:00:00
593 BB005 380 24-jun-2003 00:00:00
593 BB005 300 25-jun-2003 00:00:00
594 AC010 90 24-jun-2003 00:00:00
594 BB005 50 24-jun-2003 00:00:00
594 MS193 50 24-jun-2003 00:00:00

7 rows selected.


Tom Kyte

Followup  

June 25, 2003 - 11:34 am UTC

I think that is the same answer as the other one.

June 25, 2003 - 11:58 am UTC

Reviewer: mo

Tom:

Thanks a lot. Is it any way possible using analytical functions too to get the min(date) in the result set. Your answer gave me what I need. Now is it possible to add the min(shipment_date) from the first record displayed in the initial result set to the final result set which displays the record with maximum(shipment_date)?



Tom Kyte

Followup  

June 25, 2003 - 7:25 pm UTC

(did you even think to try "min"?????)

just try adding a select of min(...) over (....)

query

June 25, 2003 - 9:34 pm UTC

Reviewer: mo

Tom:

I think you misunderstood me or maybe I misunderstood your last comment.

The max( ) over gave me the result set however I am trying to grab the lowest ship date from the first record. For example, for this data set, I need to grab the record (quantity) from record highest shipment_date but then I want to grab lowest shipment date (initial date).

REQUEST_ID STOCK_NUMB BACKORDER_QUANTITY SHIPMENT_DATE
---------- ---------- ------------------ --------------------
593 AC010 190 24-jun-2003 00:00:00
593 AC010 145 25-jun-2003 00:00:00
593 BB005 380 24-jun-2003 00:00:00
593 BB005 300 25-jun-2003 00:00:00
594 AC010 90 24-jun-2003 00:00:00
594 BB005 50 24-jun-2003 00:00:00
594 MS193 50 24-jun-2003 00:00:00

i WOULD GET FOR AC010:


593 AC010 145 24-jun-2003
or


593 AC010 145 25-jun-2003 24-jun-2003
(here the min(date) is added as another column.



Tom Kyte

Followup  

June 26, 2003 - 8:51 am UTC

failing to see the problem here, did you even TRY adding


select * (
select a.request_id,a.shipment_id,b.item_number,b.stock_number,
a.shipment_date,
max(a.shipment_date) over (partition by shipment_id) max_ship_date
min(a.shipment_date) over (partition by shipment_id) min_ship_date

from shipment a, shipped_item b
where a.shipment_id = b.shipment_id
and b.disposition='B'
)
where shipment_date = max_ship_date
/

that'll get you the MIN shipment date by shipment_id for dispositions = 'B' You'll have max ship date, min ship date, etc etc et.

Great. This solves lot of my Issues.

June 27, 2003 - 10:16 am UTC

Reviewer: A reader

Thank you Tom.

sql query

September 11, 2003 - 6:27 pm UTC

Reviewer: mo

Tom:

I have this query that gives me all storage codes for each stock item for "WASHDC" warehouse. Problem is that if a stock item is not stored anywhere in "WASHDC" it will be excluded from the result set. I want a master report of all stock items that shows blank entries if a stock item does not have an entry. ALl stock items are listed in stock_item table.

What can i do to get this "resultset" to union with all other stock items that are not in the result set just to be displayed on the report.

select stock_number,description,
max(decode(seq,1,storage_code,null)) Loc#1,
max(decode(seq,1,qty_Available,null)) qty#1,
max(decode(seq,2,storage_code,null)) Loc#2,
max(decode(seq,2,qty_Available,null)) qty#2,
max(decode(seq,3,storage_code,null)) loc#3,
max(decode(seq,3,qty_Available,null)) qty#1,
max(decode(seq,4,storage_code,null)) loc#4,
max(decode(seq,4,qty_Available,null)) qty#4
from (
select stock_number, storage_code,description,qty_available,
row_number() over(partition by stock_number order by stock_number nulls last) seq
from (select a.stock_number, b.storage_code,a.description,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, physical_inventory b
where a.stock_number = b.stock_number(+)
and b.warehouse_id in (''WASHDC'')
and a.stock_number <> ''99999''
union all
select a.stock_number, b.storage_code,a.description,
compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, storage_receipt b
where a.stock_number = b.stock_number(+)
and b.warehouse_id in (''WASHDC'')
)
group by stock_number,storage_Code,description,qty_available )
where seq <=4

THanks,

Tom Kyte

Followup  

September 11, 2003 - 8:21 pm UTC

you don't need a union, you just need to outer join to a distinct set of all stock items at the end.

take that query -- and outer join it to the distinct set of stock items.

query

September 11, 2003 - 9:43 pm UTC

Reviewer: mo

TOm:

1. DO you mean doing like this :

select * from (query) a, stock_item b where a.stock_number=b.stock_number(+);

2. or do the join in the innermost (warehouse column) query like :

select a.stock_number, b.storage_code,a.description,

compute_qty_stored(b.warehouse_id,a.stock_number,b.storage_Code) qty_available
from stock_item a, physical_inventory b
where a.stock_number = b.stock_number(+)
and b.warehouse_id(+) in (''WASHDC'')
and a.stock_number <> ''99999''

thanks

Tom Kyte

Followup  

September 12, 2003 - 9:47 am UTC

select *
from ( your_query ) a,
( query to get DISTINCT stock numbers ) b
where a.stock#(+) = b.stock#

Very Nice

September 12, 2003 - 10:07 am UTC

Reviewer: R.Chacravarthi from Chennai,India

Hello Tom,
I have a question for you regarding a query.It deals with
selecting min and max values in a query.For example:
select ename,sal from emp where sal = (select min(sal) from
emp ) or sal = (select max(sal) from emp);
It returns me the employees getting min and max sal values
in the table emp.My question is
"Can this query be put using the In operator like
select ename,sal from emp where sal in('query1','query2');" query1 deals with min(sal) and query2
deals with max(sal).Is this possible?I tried but it throws errors.Could you please help?
Thanks in advance.Please do reply.
P.S:) Please specify the other formats of the same query.



Tom Kyte

Followup  

September 12, 2003 - 10:50 am UTC

ops$tkyte@ORA920>
ops$tkyte@ORA920> select ename
  2   from emp
  3   where sal in ( (select min(sal) from emp), (select max(sal) from emp) );
 
ENAME
----------
SMITH
KING
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> select ename
  2   from emp
  3   where sal in (select min(sal) from emp union select max(sal) from emp);
 
ENAME
----------
SMITH
KING
 


both work 

what do u think of this query...still doing a table scan??

September 12, 2003 - 1:59 pm UTC

Reviewer: A reader

SQL> sELECT
  2           employees.USID,
  3           review_status,
  4           jobs.ID,
  5           jobs.STATUS,
  6           JOB_JAVA_PKG.GET_CHEMIST(jobs.ID) ASSIGNED_TO,
  7           jobs.TEST ,
  8           JOB_JAVA_PKG.get_review_status(jobs.ID) REVIEW_STATUS,
  9           jobs.CREATED_BY ,
 10           jobs.REASON_FOR_CHANGE,
 11           DECODE(STATUS,'CANCELLED',jobs.MODIFIED_BY,NULL) MODIFIED_BY
 12      FROM JOBS, job_chemists, employees, enotebook_reviews
 13          -- where jobs.id is not null AND jobs.RECORD_STATUS='CURRENT'
 14           where jobs.RECORD_STATUS='CURRENT'
 15           and jobs.id = job_fk_id
 16           and job_chemists.RECORD_STATUS='CURRENT'
 17           and enotebook_reviews.RECORD_STATUS='CURRENT'
 18           and job_chemists.employee_fk_id = employee_id
 19           and e_notebook_entity_id = jobs.id
 20           and job_fk_id = e_notebook_entity_id
 21  /

611 rows selected.

Elapsed: 00:00:06.04

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=30 Card=1 Bytes=172)
   1    0   NESTED LOOPS (Cost=30 Card=1 Bytes=172)
   2    1     HASH JOIN (Cost=29 Card=1 Bytes=155)
   3    2       TABLE ACCESS (FULL) OF 'JOBS' (Cost=11 Card=615 Bytes=
          47970)

   4    2       HASH JOIN (Cost=17 Card=709 Bytes=54593)
   5    4         TABLE ACCESS (FULL) OF 'JOB_CHEMISTS' (Cost=11 Card=
          611 Bytes=25051)

   6    4         INDEX (FAST FULL SCAN) OF 'LOU1' (NON-UNIQUE) (Cost=
          5 Card=2156 Bytes=77616)

   7    1     TABLE ACCESS (BY INDEX ROWID) OF 'EMPLOYEES' (Cost=1 Car
          d=485 Bytes=8245)

   8    7       INDEX (UNIQUE SCAN) OF 'EMPLOYEES_PK' (UNIQUE)




Statistics
----------------------------------------------------------
       1833  recursive calls
          0  db block gets
      42323  consistent gets
          0  physical reads
          0  redo size
      43153  bytes sent via SQL*Net to client
        498  bytes received via SQL*Net from client
          4  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
        611  rows processed 

Tom Kyte

Followup  

September 12, 2003 - 2:34 pm UTC


why do you think a full scan is a bad thing??

looks awesome I guess -- unless you can show me something better or explain why you think it is "bad"

I would guess most of the run time is in the stuff that has the word "java" in it.

Thanks!!!

September 12, 2003 - 3:16 pm UTC

Reviewer: A reader

Thanks Tom,

do you think is a good idea to call a fuction like this
in side the select statement. The reason why I have it
througth my code is because I don't want to do a lot joins.
Please tell me if is a good idea to call it. Anyway,
here is the function I called get chemist from the previous
select. Any idea will be great to make it better!!!

FUNCTION get_chemist (p_job IN VARCHAR2)
RETURN VARCHAR2
IS
v_emp_id VARCHAR2 (35);
v_emp VARCHAR2 (50);
BEGIN
SELECT employee_fk_id
INTO v_emp_id
FROM job_chemists
WHERE job_fk_id = TRIM (p_job) AND record_status = 'CURRENT';

SELECT usid
INTO v_emp
FROM employees
WHERE TRIM (employee_id) = TRIM (v_emp_id);

RETURN v_emp;
END

Tom Kyte

Followup  

September 12, 2003 - 7:51 pm UTC

umm, so you think this would be better then a join??????

it is a join -- just a really really really slow join, the slowest way to do it.

don't second guess the database engine, it is pretty good at doing what it does -- joins!


I would not even consider calling such a function -- never in a billion years, not a chance.

do it in 100% SQL

SQL Statement to grab the next lowest value within a single row

September 12, 2003 - 5:16 pm UTC

Reviewer: David

Hi Tom,

I have been trying hard to think of a way to do this with just one easy SQL statement, as opposed to many PL/SQL code blocks.

The main issue is that we loaded data from a networked database to an Oracle 9i database without a hitch. During development, we discovered that in designing the new tables prior to the load, we missed the need to add a key column in one of the tables to establish a relationship with another. This was a big mistake. Unfortunately, we do not have time now to unload and reload the data into re-designed tables. The population of the owner key can only be done during the unload process, and there is simply no time left. The only option we have is to come up with a workable solution. I prefer, if possible, a single SQL statement that can retrieve the correct results.

So for example, in Table A:

SEQNO EFFECTIVE_DATE SERVICE_STATUS
2 20020426 ND
2 20020130 AB
2 20020129 AB
2 20011009 AB
2 20011002 AB
2 20010912 AB
2 20001028 AB
2 20001026 NP
1 20030328 AB
1 20020722 AB
1 20020720 AB
1 20020719 AB
1 20020717 NP

And in Table B:

SERIAL_NUMBER SEQNO EFFECTIVE_DATE
21814290378 2 20020426
21814290378 2 20020130
21814290378 2 20020129
21814290378 2 20011009
21814290378 2 20011002
21814317918 2 20010912
21814317918 2 20001028
9300134799 1 20030328
9300134799 1 20020722
9300134799 1 20020720
9300134799 1 20020719

There should be a SERIAL_NUMBER field in Table A so that we can pin-point the EFFECTIVE_DATE. This is the column that is missing. Table A should look like:

SEQNO EFFECTIVE_DATE SERVICE_STATUS SERIAL_NUMBER
2 20020426 ND 21814290378
2 20020130 AB 21814290378
2 20020129 AB 21814290378
2 20011009 AB 21814290378
2 20011002 AB 21814290378
2 20010912 AB 21814317918
2 20001028 AB 21814317918
2 20001026 NP
1 20030328 AB 9300134799
1 20020722 AB 9300134799
1 20020720 AB 9300134799
1 20020719 AB 9300134799
1 20020717 NP


So the way this works is that for a SEQNO, you can have multiple serial numbers. We need to produce a report that looks like:

SERIAL_NUMBER SRV_BEGIN
------------------------------------
9300134799 20020717
21814290378 20011002
21814317918 20001026

The logic is this: For each sequence number, list the effective dates of each serial number. The effective date should be the earliest date for that serial number. If the SERVICE_STATUS column in Table A is 'NP', then use the effective date for that serial number. If it isn't, then use the date that is in Table B. This seems simple, but is quite complicated. I am hoping that you can come up with a single SQL statement to do this.

Thanks.

David

Tom Kyte

Followup  

September 12, 2003 - 8:03 pm UTC

isn't the logic more easily stated as:

for every row in table A where service_status <> NP, set serial_number = first serial number for that sequence you find in table b?



Whaa?

September 12, 2003 - 9:17 pm UTC

Reviewer: David

Do you mean "where service_status = NP"? How would you do it with one SQL statement?

Tom Kyte

Followup  

September 13, 2003 - 9:01 am UTC

no, i meant

for every row -- where the status is NOT "NP" -- update that column to the first value for that sequence you find in the other table.

that matches your output. is that is what you want -- just


update tablea
set that_column = ( select that_column from tableb where tableb.seq = tablea.seq and rownum = 1 )
where status <> 'NP';

Nice

September 13, 2003 - 12:50 am UTC

Reviewer: R.Chacravarthi from Chennai,India

Thanks for your response.Sorry to disturb you again.I need a
query which returns deptno wise highest and lowest salary
getting employees.For ex. I expect the resultset to be as
follows:
deptno Min(sal) Minsal_ename Max(sal) Maxsal_ename
10 800 Smith 5000 King
20 1500 ... ...
30 ... .... .... ...
I need a query like this?Could you please Provide a query?
Please specify different formats of the same query.

Tom Kyte

Followup  

September 13, 2003 - 9:15 am UTC


please specify different formats?  do we get bonus points on homework for that :)


tell me, what happens when two people (or thirty people, whatever) make the most or least -- are we to pick on at random?  

well, here are three ways -- note that the last query returns a different -- yet equally valid -- answer due to this duplicity

ops$tkyte@ORA920> create table emp as select * from scott.emp order by ename;
 
Table created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920>
ops$tkyte@ORA920> select deptno,
  2         to_number(substr(xmax,1,14)) max_sal,
  3         substr(xmax,15) max_name,
  4         to_number(substr(xmin,1,14)) min_sal,
  5         substr(xmin,15) min_name
  6    from (
  7  select deptno,
  8         max( to_char(sal,'0000000000.00') || ename ) xmax,
  9         min( to_char(sal,'0000000000.00') || ename ) xmin
 10    from emp
 11   group by deptno
 12         )
 13  /
 
    DEPTNO    MAX_SAL MAX_NAME      MIN_SAL MIN_NAME
---------- ---------- ---------- ---------- ----------
        10       5000 KING             1300 MILLER
        20       3000 SCOTT             800 SMITH
        30       2850 BLAKE             950 JAMES
 
ops$tkyte@ORA920>
ops$tkyte@ORA920>
ops$tkyte@ORA920> select deptno,
  2         max(case when rn<>1 then sal else null end) max_sal,
  3         max(case when rn<>1 then ename else null end) max_ename,
  4         max(decode(rn,1,sal)) min_sal,
  5         max(decode(rn,1,ename)) min_ename
  6    from (
  7  select *
  8    from (
  9  select deptno,
 10         row_number() over ( partition by deptno order by sal ) rn,
 11         max(sal) over (partition by deptno) max_sal,
 12         ename,
 13         sal
 14    from emp
 15         )
 16   where rn = 1 or sal = max_sal
 17         )
 18   group by deptno
 19  /
 
    DEPTNO    MAX_SAL MAX_ENAME     MIN_SAL MIN_ENAME
---------- ---------- ---------- ---------- ----------
        10       5000 KING             1300 MILLER
        20       3000 SCOTT             800 SMITH
        30       2850 BLAKE             950 JAMES
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> select deptno,
  2         max_sal,
  3         (select ename from emp where sal = max_sal and rownum = 1 ) max_ename,
  4         min_sal,
  5         (select ename from emp where sal = min_sal and rownum = 1 ) min_ename
  6    from (
  7  select deptno, min(sal) min_sal, max(sal) max_sal
  8    from emp
  9   group by deptno
 10         )
 11  /
 
    DEPTNO    MAX_SAL MAX_ENAME     MIN_SAL MIN_ENAME
---------- ---------- ---------- ---------- ----------
        10       5000 KING             1300 MILLER
        20       3000 FORD              800 SMITH
        30       2850 BLAKE             950 JAMES
 

Excellent

September 13, 2003 - 10:46 pm UTC

Reviewer: A reader from Cincinatti,USA

How to reverse the rows of a table?i.e.starting from the last row and proceeding upwards.Can this be done in sql?I
tried in pl/sql using index by tables with attributes last
and prior.It works fine.Please show me a way how to do it
sql.
Thanks in advance.
Bye!

Tom Kyte

Followup  

September 14, 2003 - 9:50 am UTC

there is no such thing as the "last row"...

order by DESC

and

order by ASC

are the only ways to have "first" and "last" rows. so, if you want the "last row" first and were using order by asc, use desc

Ok

September 15, 2003 - 12:46 am UTC

Reviewer: Peter from Boulder,USA

Dear Tom,
Read your response.One of my Oracle University Tutors said
the following information."A row in the table can be the last row if it has the maximum rowid and a row can be the
first if it has the minimum rowid".Is this correct information or misleading one?I have a question also for you
and kindly bear with us.It is
select * from emp where &N = (select ....);
Keep the data as it is (i.e keeping data in the order of row insertion ) and suppose if I enter "1" for N it should return the first row and if I enter "5" it should return the fifth row.Is this possible in
sql?Please do reply.
Thanks in advance.

Tom Kyte

Followup  

September 15, 2003 - 9:34 am UTC

it is incorrect.  

first, what does it mean to be "first" or "last"??????? nothing, nothing at all - not in SQL, not in relational databases.  But, anyway, let me demonstrate:

borrowing the example from:
http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:4423420997870

I'll reuse it here:

ops$tkyte@ORA920> create table t ( x int primary key, a char(2000), b char(2000), c char(2000), d char(2000), e char(2000) );
 
Table created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into t(x) values ( 1 );
1 row created.
 
ops$tkyte@ORA920> insert into t(x) values ( 2 );
1 row created.
 
ops$tkyte@ORA920> insert into t(x) values ( 3 );
1 row created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> commit;
Commit complete.
 
ops$tkyte@ORA920> column a noprint
ops$tkyte@ORA920> column b noprint
ops$tkyte@ORA920> column c noprint
ops$tkyte@ORA920> column d noprint
ops$tkyte@ORA920> column e noprint
ops$tkyte@ORA920>
ops$tkyte@ORA920> select * from t;
 
         X
----------
         1
         2
         3

<b>so, data comes out in the order it is inserted -- or not???  the "last row" is 3, first row is "1" right?  or is it??</b>
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> update t set a = 'x', b = 'x', c = 'x' where x = 3;
 
1 row updated.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> commit;
 
Commit complete.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> update t set a = 'x', b = 'x', c = 'x' where x = 2;
 
1 row updated.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> commit;
 
Commit complete.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> update t set a = 'x', b = 'x', c = 'x' where x = 1;
 
1 row updated.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> commit;
 
Commit complete.

<b>just some updates right -- but carefully planned ones:</b>

 
ops$tkyte@ORA920>
ops$tkyte@ORA920> select * from t;
 
         X
----------
         3
         2
         1

<b>now 3 is the "first" row and 1 is the "last row" but look at the rowids</b>
 
ops$tkyte@ORA920>
ops$tkyte@ORA920>
ops$tkyte@ORA920> select x, rowid, min(rowid) over (), max(rowid) over (),
  2         decode( rowid, min(rowid) over (), 'min rowid' ),
  3         decode( rowid, max(rowid) over (), 'max rowid' )
  4    from t;
 
  X ROWID              MIN(ROWID)OVER()   MAX(ROWID)OVER()   DECODE(RO DECODE(RO
--- ------------------ ------------------ ------------------ --------- ---------
  3 AAAJ49AALAAAQaiAAC AAAJ49AALAAAQaiAAA AAAJ49AALAAAQaiAAC           max rowid
  2 AAAJ49AALAAAQaiAAB AAAJ49AALAAAQaiAAA AAAJ49AALAAAQaiAAC
  1 AAAJ49AALAAAQaiAAA AAAJ49AALAAAQaiAAA AAAJ49AALAAAQaiAAC min rowid
 

<b>3 has max rowid, 1 has min rowid but -- 3 is first and 1 is last!!!</b>

so, that shows the "maximum rowid theory" is false.....





As for the last question -- hopefully you see now that there is NO SUCH THING as the n'th row in a relation database (unless you yourself number them!)


You can get the n'th row from a result set -- but the n'th row can and will change over time.  Only by numbering the rows yourself and using order by can you get the same n'th row time after time after time 


select *
  from ( select a.*, rownum r
           from ( query-to-define-your-result-set ) a
          where rownum <= &n )
 where r = &n;


gets the n'th row from a result set (NOT a table, a result set) 

Problem with SQL Query

September 15, 2003 - 8:20 am UTC

Reviewer: Raghu

Hi TOm,

I don't understand the reason behind this behaviour. 

SQL> desc dept
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 DEPTNO                                             NUMBER(2)
 DNAME                                              VARCHAR2(14)
 LOC                                                VARCHAR2(13)

SQL> desc emp
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 EMPNO                                     NOT NULL NUMBER(4)
 ENAME                                              VARCHAR2(10)
 JOB                                                VARCHAR2(9)
 MGR                                                NUMBER(4)
 HIREDATE                                           DATE
 SAL                                                NUMBER(7,2)
 COMM                                               NUMBER(7,2)
 DEPTNO                                             NUMBER(2)

SQL> select * from dept
  2  where dname in
  3  (select dname from emp);

    DEPTNO DNAME          LOC
---------- -------------- -------------
        10 ACCOUNTING     NEW YORK
        20 RESEARCH       DALLAS
        30 SALES          CHICAGO
        40 OPERATIONS     BOSTON

DNAME column is missing in the emp table but still it does not give any error. 

Tom Kyte

Followup  

September 15, 2003 - 9:43 am UTC

that query is the same as:

select * from dept
where DEPT.dname in ( select DEPT.dname from emp );


you just did a correlated subquery. as long as EMP has at least one row -- that query is the same as:

select * from dept
where DEPT.dname is not null;


it is the defined, expected behaviour.

Thanks!!!

September 15, 2003 - 9:01 am UTC

Reviewer: A reader

Thanks Tom,

do you think is a good idea to call a fuction like this
in side the select statement. The reason why I have it
througth my code is because I don't want to do a lot joins.
Please tell me if is a good idea to call it. Anyway,
here is the function I called get chemist from the previous
select. Any idea will be great to make it better!!!

FUNCTION get_chemist (p_job IN VARCHAR2)
RETURN VARCHAR2
IS
v_emp_id VARCHAR2 (35);
v_emp VARCHAR2 (50);
BEGIN
SELECT employee_fk_id
INTO v_emp_id
FROM job_chemists
WHERE job_fk_id = TRIM (p_job) AND record_status = 'CURRENT';

SELECT usid
INTO v_emp
FROM employees
WHERE TRIM (employee_id) = TRIM (v_emp_id);

RETURN v_emp;
END

Tom Kyte

Followup  

September 15, 2003 - 9:49 am UTC

it is a horrible idea.

joins are not evil.

calling plsql (or any function) from sql when you don't need to is.

joins are not evil.

databases were BORN to join

joins are not evil.

you are doing a join yourself -- that can only be slower then letting the datbase do what it was programmed to do!

joins are NOT evil.


don't do this (and that abuse of trim() -- on a database column!! precluding indexes in most cases! you want to rethink that -- why would you need to trim() ?? that would indicate bad data -- something you want to fix on the ingest process, not on the way out!

simple sql question

September 16, 2003 - 12:37 pm UTC

Reviewer: A reader

Hi Tom
Here is the test case:
9:25:11 test@ORA901> @test1
09:25:14 test@ORA901> drop table t1;

Table dropped.

09:25:14 test@ORA901> drop table t2;

Table dropped.

09:25:14 test@ORA901> create table t1 ( x int , y varchar2(30) );

Table created.

09:25:14 test@ORA901> create table t2 ( x int , y varchar2(30) );

Table created.

09:25:14 test@ORA901> insert into t1 values ( 1, 'xx' );

1 row created.

09:25:14 test@ORA901> insert into t1 values ( 2, 'xx' );

1 row created.

09:25:14 test@ORA901> select t1.x , t1.y from t1, t2
09:25:14 2 where not exists ( select null from t2 where t2.x = t1.x );

no rows selected

09:25:14 test@ORA901>
09:25:14 test@ORA901> insert into t2 values ( 1, 'xx' );

1 row created.

09:25:14 test@ORA901> select t1.x, t1.y from t1, t2
09:25:14 2 where not exists ( select null from t2 where t2.x = t1.x );

2 xx


My question is:
Why in the first case we get "no rows selected" - I would
have expected all the rows of t1. When I have at least one row in t2 (matching or not), then I get the desired result.
Basically, I want to select t1's values that don't exist
in t2 - . If t2 is empty I want to get all rows of t1.


Thank you!!!!

Tom Kyte

Followup  

September 16, 2003 - 1:02 pm UTC


why are you cartesian product'ing the tables together?

the query should be:


ops$tkyte@ORA920> select t1.x , t1.y from t1
  2  where not exists ( select null from t2 where t2.x = t1.x );
 
         X Y
---------- ------------------------------
         1 xx
         2 xx


that is what the query should be -- when you join to an empty table -- you get no rows. 

thanx tom!!

September 16, 2003 - 1:32 pm UTC

Reviewer: A reader

It was a stupid mistake - thanx for correcting me!

Good

September 18, 2003 - 8:25 am UTC

Reviewer: Ferdinand Maer from CT,USA

Dear Sir,
Suppose if I have a string like "Metalink " ,How can I insert a blank space between each character so that string
appears as "M e t a l i n k"?Is a query possible here?
Please do reply.
Thanks
Maer


Tom Kyte

Followup  

September 18, 2003 - 10:41 am UTC

procedurally -- sure, its easy. this would be one where I would write a small plsql function to do it.

OK

September 18, 2003 - 11:11 am UTC

Reviewer: Ferdinand Maer from CT,USA

Thanks for your reply.Please provide some hints to do the
coding.That's where we need your help.
Bye!
with regards,
Maer

Tom Kyte

Followup  

September 18, 2003 - 11:18 am UTC

really?  seems pretty straight forward...

ops$tkyte@ORA920> create or replace function spacer( p_string in varchar2 ) return varchar2
  2  as
  3          l_string varchar2(4000);
  4  begin
  5          for i in 1 .. length(p_string)
  6          loop
  7                  l_string := l_string || substr(p_string,i,1) || ' ';
  8          end loop;
  9          return l_string;
 10  end;
 11  /
 
Function created.
 
ops$tkyte@ORA920>
ops$tkyte@ORA920> column ename format a20
ops$tkyte@ORA920>
ops$tkyte@ORA920> select ename, spacer(ename) ename from emp;
 
ENAME                ENAME
-------------------- --------------------
ADAMS                A D A M S
ALLEN                A L L E N
BLAKE                B L A K E
CLARK                C L A R K
FORD                 F O R D
JAMES                J A M E S
JONES                J O N E S
KING                 K I N G
MARTIN               M A R T I N
MILLER               M I L L E R
SCOTT                S C O T T
SMITH                S M I T H
TURNER               T U R N E R
WARD                 W A R D
 
14 rows selected.
 
 

query

January 10, 2004 - 2:26 pm UTC

Reviewer: mo

Tom:

I would like to ask you about the best way to accomplish this query. It is used to generate a report.

I have 5 tables: Library table stores all libraries. Request table stores all requests submitted by libraries. Requested_Items stores all individual items requested. Shipment table stores all shipments sent to libraries. Shipped_Item stores all shipped items sent to libraries.

Library (LibCode,Name)
Request(Request_ID,LibCode)
Requested_Items(Request_ID,Item_no,Material_ID)
Shipment(Shipment_ID,Request_ID,LibCode)
Shipped_Item(Shipment_ID,Item_no,material_id)

Physical relationships are as follows:
Request table is child table to parent table Library.
Requested_Items table is a child table to parent table Request.
Shipment table is child table to parent table Request.
Shipped_Item is child table to parent table Shipment.

I want to generate a columnar report as follows:

Library Total Total Total Total
Request Request Items Shipments Shipped Items

Here is how I want to do it. Simple way but may be inefficient due to the several table scans.

For x in (select libcode from library)
Loop
Select count(*) into tot_request from request where libcode = x.libcode;
Select count(*) into tot_request_item from requested_items where request_id in (select request_id from request where libcode = x.libcode);
Select count(*) into tot_shipment from shipment where libcode = x.libcode;
Select count(*) into tot_shipped_item from shipped_items where shipment_id in (select shipment_id from shipment where libcode = x.libcode);
Htp.p(tot_request);
Htp.p(tot_request_item);
Htp.p(tot_shipment);
Htp.p(tot_shipped_item);
END LOOP;

Is this an efficient way of doing it or not. If not how would you do it?


Tom Kyte

Followup  

January 10, 2004 - 4:14 pm UTC

select l.libcode, r.cnt1, r.cnt2, s.cnt1, s.cnt2
from library L,
(select request.libcode,
count(distinct request.request_id) cnt1,
count(*) cnt2
from request, requested_items
where request.request_id = requested_items.request_id(+)
group by request.libcode ) R,
(select shipment.libcode,
count(distinct shipment.shipment_id) cnt1,
count(*) cnt2
from shipment, shipped_items
where shipment.shipment_id = shipped_items.shipment_id(+)
group by shipment.libcode ) S
where l.libcode = r.libcode(+)
and l.libcode = s.libcode(+)


ONLY use the (+) if necessary. If the relations are not "optional" (eg: every libcode is in request and shipment that is in library and every row in request has at least a row in requested_items and every row in shipment has a row in shipped_items -- remove them -- remove as many as you can)

that gets them all in one statement.

SQL Query

January 10, 2004 - 10:23 pm UTC

Reviewer: Natasha from UAE

Tom,

I have a query pls. have a look at that

Query :
Select * From <Tab> Where Session_ID = <Session_Number>
point_of_sale, origin,destination,decode(category,'Y',1,'F',2,'J',3),
fare_id,rid,mfid,mrid.

Result Set:

MRBD BKGFRM BKGTO DEPFRM DEPTO FID RID MFID MRID
M 3/5/03 6/15/03 4/1/03 6/15/03 149 154 146 5427
M 3/5/03 6/19/03 6/16/03 6/19/03 149 154 147 5430
H 3/5/03 6/19/03 4/1/03 6/19/03 149 154 12364 16149

M 3/5/03 7/15/03 6/20/03 7/15/03 150 155 147 5430
M 3/5/03 7/31/03 7/16/03 7/31/03 150 155 3492 5432
H 3/5/03 7/31/03 6/20/03 7/31/03 150 155 12364 16149

M 3/5/03 8/31/03 8/16/03 8/31/03 151 8351 3491 5429
M 3/5/03 8/15/03 8/1/03 8/15/03 151 8351 3492 5432
H 3/5/03 8/31/03 8/1/03 8/31/03 151 8351 12364 16149

M 3/5/03 12/9/03 12/1/03 12/9/03 152 8353 149 160
M 3/5/03 12/25/0312/10/0312/25/03152 8353 149 160
M 3/5/03 3/31/04 1/1/04 3/31/04 152 8353 150 161
M 3/5/03 12/31/0312/26/0312/31/03152 8353 150 161
M 3/5/03 11/19/039/1/03 11/19/03152 8353 3491 5429
M 3/5/03 11/30/0311/20/0311/30/03152 8353 3491 5429
H 3/5/03 12/9/03 12/1/03 12/9/03 152 8353 12364 16149
H 3/5/03 11/19/039/1/03 11/19/03152 8353 12364 16149
H 3/5/03 11/30/0311/20/0311/30/03152 8353 12364 16149
H 3/5/03 3/31/04 1/1/04 3/31/04 152 8353 12364 16149
H 3/5/03 12/31/0312/10/0312/31/03152 8353 12364 16149
M 3/5/03 8/31/03 8/16/03 8/31/03 4888 8394 3491 5429
M 3/5/03 8/15/03 8/1/03 8/15/03 4888 8394 3492 5432
H 3/5/03 8/31/03 8/1/03 8/31/03 4888 8394 12364 16149
M 3/5/03 12/9/03 12/1/03 12/9/03 4889 8395 149 160
M 3/5/03 12/25/0312/10/0312/25/034889 8395 149 160
M 3/5/03 3/31/04 1/1/04 3/31/04 4889 8395 150 161
M 3/5/03 12/31/0312/26/0312/31/03 4889 8395 150 161
M 3/5/03 11/19/039/1/03 11/19/03 4889 8395 3491 5429
M 3/5/03 11/30/0311/20/0311/30/03 4889 8395 3491 5429
H 3/5/03 12/9/03 12/1/03 12/9/03 4889 8395 12364 16149
H 3/5/03 11/19/039/1/03 11/19/03 4889 8395 12364 16149
H 3/5/03 11/30/0311/20/0311/30/03 4889 8395 12364 16149
H 3/5/03 3/31/04 1/1/04 3/31/04 4889 8395 12364 16149
H 3/5/03 12/31/0312/10/0312/31/03 4889 8395 12364 16149
M 3/5/03 6/15/03 4/1/03 6/15/03 15682 23867 146 5427
M 3/5/03 7/15/03 6/16/03 7/15/03 15682 23867 147 5430
M 3/5/03 12/25/0312/1/03 12/25/03 15682 23867 149 160
M 3/5/03 3/31/04 12/26/03 3/31/04 15682 23867 150 161
M 3/5/03 11/30/038/16/03 11/30/03 15682 23867 3491 5429
M 3/5/03 8/15/03 7/16/03 8/15/03 15682 23867 3492 5432
H 3/1/03 3/31/04 3/1/03 3/31/04 15682 23867 12364 16149
H 4/1/07 3/31/08 4/1/07 3/31/08 15756 23990 12454 16232




What I am looking for :

Tom, If you check FID, and their Departure From & Departure To dates...there should be continuity. I mean the sequence of date breaks.

For Ex :-

FID DEPFRM DEPTO MRBD
149 01/04/2003 15/06/2003 M
149 16/06/2003 19/06/2003 M
149 01/04/2003 19/06/2003 H

This is the perfect output according to the date break sequence. But When you check FID '151', the date breaks are improper.

For Ex:-

FID DEPFRM DEPTO MRBD
151 16/08/2003 31/08/2003 M
151 01/08/2003 15/08/2003 M
151 01/08/2003 31/08/2003 M

So the output should come as

FID DEPFRM DEPTO MRBD
151 01/08/2003 15/08/2003 M
151 16/08/2003 31/08/2003 M
151 01/08/2003 31/08/2003 M


Pls. ensure that the date sequence should come for all the FID's.

I would appreciate, if you can answer my query.

thxs in advance.

Tom Kyte

Followup  

January 11, 2004 - 6:09 am UTC

er? sorry, don't understand what you might be looking for here. don't know if you are looking for a constraint to avoid overlaps, a query to filter them out, whatever.

(example could be lots smaller too I think)

Query to filter

January 11, 2004 - 7:56 am UTC

Reviewer: Natasha from UAE

Tom,

I need a query to filter the records according to the above examples I had enclosed.

thxs in advance.


Tom Kyte

Followup  

January 11, 2004 - 9:07 am UTC

don't get it. filter what like what?

looks like "where" with "order by" to me.

RE: Query to filter (Natasha)

January 11, 2004 - 10:31 am UTC

Reviewer: Marcio from br

<quote>
For Ex :-

FID DEPFRM DEPTO MRBD
149 01/04/2003 15/06/2003 M
149 16/06/2003 19/06/2003 M
149 01/04/2003 19/06/2003 H

This is the perfect output according to the date break sequence. But When you
check FID '151', the date breaks are improper.

For Ex:-

FID DEPFRM DEPTO MRBD
151 16/08/2003 31/08/2003 M
151 01/08/2003 15/08/2003 M
151 01/08/2003 31/08/2003 M

So the output should come as

FID DEPFRM DEPTO MRBD
151 01/08/2003 15/08/2003 M
151 16/08/2003 31/08/2003 M
151 01/08/2003 31/08/2003 M
</quote>
PMJI, but you don't show the query, like Tom said -- I used just order by depto and figured it out.
BTW: you have a 'H' on MRBD for 151, 01/08/2003, 31/08/2003.

ops$marcio@MARCI9I1> select fid, depfrm, depto, mrbd
2 from t
3 where fid=151
4* order by depto
ops$marcio@MARCI9I1> /

FID DEPFRM DEPTO M
---------- ---------- ---------- -
151 01/08/2003 15/08/2003 M
151 16/08/2003 31/08/2003 M
151 01/08/2003 31/08/2003 H

regards,


query

February 26, 2004 - 6:52 pm UTC

Reviewer: mo

Tom:

1. If I have two tables one for Requests (Orders) and one for shipments linked by request_id and each table has a child table for items. Is it possible to run a sql statement to get count of items in each order (requested and shipped).

Requests
(request_id number(10),
request_date date);

Requested_items
(request_id number(10),
item_number number(5),
stock_number varcahr2(10),
quantity number(8))

Shipment
(shipment_id number(10),
request_id number(10),
shipment_date date)

Shipped_items
(shipment_id number(10),
item_number number(10),
stock_number varchar2(10),
quantity number )

What i want is count the items requested versus items shipped and the quantities for each request. One request can have multiple shipments.

Request ID Tot req Items Tot req Qty
Tot ship Items Tot Qty shipped

100 5 3 1000 800

Thank you



Thank you,



Tom Kyte

Followup  

February 26, 2004 - 7:17 pm UTC

aggregate everything up to the same level, just like we did above a while back.

use inline views, get things aggregated to the request_id level and join them.

February 27, 2004 - 4:53 pm UTC

Reviewer: reader from USA

You give 3 way to get result. For performance, which one is better if we have a big table?

Tom Kyte

Followup  

February 27, 2004 - 5:06 pm UTC

they are in relative order in the answer.

QUESTION

February 28, 2004 - 11:31 am UTC

Reviewer: PRS from USA

Hi Tom,
We have oracle 9.2.0.4 installed on solaris 9.
I have 2000 oracle connections to the database at a
given point of time. Means user may be doing something
or they are idle.

My question is how do I find out the number of
concurrent users at the database level at a given second
always doing something. We just want to find out the
number of concurrent users on the database.
Any help is appreciated.
Thanks,
PRS

Tom Kyte

Followup  

February 28, 2004 - 12:50 pm UTC

concurrently "active" or concurrent users.

select status, count(*) from v$session group by status

will in fact answer both - you'll see "inactive", "active" and perhas other status depending on your configuration. add them up and that is the number of concurrent users. if you are just interested in concurrent AND active users -- just use that number.

query

March 31, 2004 - 7:07 pm UTC

Reviewer: mo

Tom:

How would you do this query:

Requests
(request_id number(10),
request_date date);

Requested_items
(request_id number(10),
item_number number(5),
stock_number varcahr2(10),
quantity number(8))

Shipment
(shipment_id number(10),
request_id number(10),
shipment_date date)

Shipped_items
(shipment_id number(10),
stock_number varchar2(10),
quantity number,
code varchar2(1) )

I want to get a count of the backorder items that have been fullfilled in later shipments.

Initially when items shipped they get a code of "A" if shipped in full or "B" if it is on backorder. Later, if the backorder item was shipped it will get a code of "A".

Let us say I have this in shipments(shipment_id,request_id,date)

100,1,04/01/04
105,2,04/05/04

and in shipped_items(shipment_id,stock_no,qty,code)

100,AC002,10,A
100,AC006,5,B
101,AC006,5,A (here backorder for request 1(item2) gets filled)
105,BB005,6,A
105,BB006,10,B (here backorder for request 2(item2) stays open).

When I run the query i should get a count of 1 since only 1 item has been marked with A and then (same item) with B.



Tom Kyte

Followup  

March 31, 2004 - 7:14 pm UTC

no idea how your tables relate to one another or how you are tracking data -- seems very strange to have shipped items table set up that way. shipment id 101 doesn't see to go anywhere.

if that 101 was really supposed to be 100 then a simple


select shipment_id, stock_number
from shipped_items
group by shipment_id, stock_number
having count(distinct code) = 2

gets all of the rows that you then probably want to count

select count(*)
from (
select shipment_id, stock_number
from shipped_items
group by shipment_id, stock_number
having count(distinct code) = 2
)

query

March 31, 2004 - 9:43 pm UTC

Reviewer: mo

No I mean 101 however I forgot to include it in the shipment table. One Request can have many shipments.

Request and shipments are linked ussing Request_ID. Shipment and Shipped_items are linked using shipment_id.

You gave me the idea though?

select count(*)
from (
select a.request_id,b.stock_number,b.code
from shipment a, shipped_items b
where a.shipment_id = b.shipment_id
group by request_id, stock_number
having count(distinct code) = 2
)


Thank you,


query

April 08, 2004 - 10:36 pm UTC

Reviewer: mo

Tom:

In the query above I should have told you that are about 8 shipment codes and not only "A" or "B". However I am only interested in couting the item that has a "B" ijnitially and then they shipped it and got a code of "A". In this case what would you add to this?

having count(distinct code) = 2 and code in ('A','B')

Is this right?


Tom Kyte

Followup  

April 09, 2004 - 7:36 am UTC

code in ('a',b') goes in the where clause, not the having clause.

query

April 09, 2004 - 6:59 pm UTC

Reviewer: mo

Tom:

Can you check why this query is not giving the right answer. In the first set of data the count should be 0 because not one item has had two codes "A" and "B". In the second set of data I shipped one backorder item, and the count should change to 1 but it gave me 2 instead.

I am trying to get a total count of all items that have been shipped by request that get two codes "A" and "B".


SELECT e.request_id,disposition,f.stock_number
from shipment e, shipped_item f
where e.shipment_id = f.shipment_id(+) and
e.ship_to_org = 'DC1A' and
f.disposition in ('A','B')
group by request_id, disposition,stock_number;

REQUEST_ID D STOCK_NUMB
---------- - ----------
795 A AC008
795 A BB010
795 A CA294
795 B MA187
796 A AC008
796 A BB010
796 B CA294


select count(*) from
(
SELECT e.request_id,disposition,f.stock_number
from shipment e, shipped_item f
where e.shipment_id = f.shipment_id(+) and
e.ship_to_org = 'DC1A' and
f.disposition in ('A','B')
group by request_id, disposition,stock_number
)
group by request_id,stock_number
having count(distinct disposition)=2


no rows selected


Now when I ship one of the backorder items the count changes to 2 instead of 1.

REQUEST_ID D STOCK_NUMB
---------- - ----------
795 A AC008
795 A BB010
795 A CA294
795 A MA187
795 B MA187
796 A AC008
796 A BB010
796 B CA294

Thank you,

Tom Kyte

Followup  

April 10, 2004 - 11:38 am UTC

should be obvious -- if the count( distinct something ) = 2, count(*) for that group will be AT LEAST 2.... at least 2 (and maybe more).....


seems like you need two levels of aggregation here -- you want to count the groups after the fact. use another inline view to count the rows that pass the having clause test.

help with the query

April 14, 2004 - 5:49 pm UTC

Reviewer: P from CA

hi tom,
how should i change this query so it will return only one row, where hct.batch_num=max(hct.batch_num)...that is the first row
here is my query and the resultset

SELECT hct.batch_num,hct.batch_seq_num,hct.ap_order_num,hct.svc_num,sm.svc_num
FROM hist_cust_trans hct,service_mstr sm
WHERE hct.svc_num=sm.svc_num
AND hct.svc_type_cd=sm.svc_type_cd
AND hct.trans_status_cd not in ('NP', 'AN')
AND decode(hct.gcc_dest_num,NULL,'0','1')=sm.rstrctd_ind
AND substr(hct.ap_order_num,1,1)='T'
AND hct.svc_num=4042091777

45474 49472 TOFHNBQ2 4042091777 4042091777
45474 49473 TOFHNBQ2 4042091777 4042091777
45474 49474 TOFHNBQ2 4042091777 4042091777
43775 39582 TO803XY6 4042091777 4042091777
43775 39583 TO803XY6 4042091777 4042091777
43574 52701 TO8D5JX0 4042091777 4042091777
43574 52700 TO8D5JX0 4042091777 4042091777


Thank You

Tom Kyte

Followup  

April 15, 2004 - 7:53 am UTC

there are many ways to accomplish this.  assume this is your current query and you want the row(s) with the max(sal) reported:

ops$tkyte@ORA9IR2> select sal, empno, ename
  2    from emp
  3   where deptno = 20;
 
       SAL      EMPNO ENAME
---------- ---------- ----------
       800       7369 SMITH
      2975       7566 JONES
      3000       7788 SCOTT
      1100       7876 ADAMS
      3000       7902 FORD
 
<b>analytics get that easily:</b>

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select sal, max(sal) over () max_sal, empno, ename
  2    from emp
  3   where deptno = 20;
 
       SAL    MAX_SAL      EMPNO ENAME
---------- ---------- ---------- ----------
       800       3000       7369 SMITH
      2975       3000       7566 JONES
      3000       3000       7788 SCOTT
      1100       3000       7876 ADAMS
      3000       3000       7902 FORD
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select *
  2    from (
  3  select sal, max(sal) over () max_sal, empno, ename
  4    from emp
  5   where deptno = 20
  6         )
  7   where sal = max_sal;
 
       SAL    MAX_SAL      EMPNO ENAME
---------- ---------- ---------- ----------
      3000       3000       7788 SCOTT
      3000       3000       7902 FORD

<b>but that shows top-n queries can be tricky -- there are two highest salaries -- we can "solve" that by just getting "one" if that is an issue</b>
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select *
  2    from (
  3  select sal, row_number() over (order by sal DESC) rn, empno, ename
  4    from emp
  5   where deptno = 20
  6         )
  7   where rn = 1;
 
       SAL         RN      EMPNO ENAME
---------- ---------- ---------- ----------
      3000          1       7788 SCOTT

<b>alternatively, we can use order by in a subquery:</b>
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select *
  2    from (
  3  select sal, empno, ename
  4    from emp
  5   where deptno = 20
  6   order by sal desc
  7         )
  8   where rownum = 1;
 
       SAL      EMPNO ENAME
---------- ---------- ----------
      3000       7788 SCOTT
 
<b>as well -- there are other ways (if interested, i have a list of them in my book Effective Oracle by Design) but those are the two "easiest"</b>
 

some more explanation

April 15, 2004 - 11:02 am UTC

Reviewer: P from CA

Hi tom
That’s not what I am looking for, may be you did not understand my question (I guess I did not give all the information)
First 2 columns make the primary key for the table and I want to return only 1 row where batch_num is greatest. I need to pass this to an update statement meaning I am going to use it as a sub query in an update statement (I am updating service_mstr table) so I need only one row to be returned. In the update statement I would join svc_num to update table. So instead of hct.svc_num=4042091777 I would use join column from update table which is service_mstr. And I cannot use rownum as I am using it in an update statement.
so from the resultset i want to return only "TOFHNBQ2" which is from the last last group.


SELECT hct.batch_num,hct.batch_seq_num,hct.ap_order_num,hct.svc_num,sm.svc_num
FROM hist_cust_trans hct,service_mstr sm
WHERE hct.svc_num=sm.svc_num
AND hct.svc_type_cd=sm.svc_type_cd
AND hct.trans_status_cd not in ('NP', 'AN')
AND decode(hct.gcc_dest_num,NULL,'0','1')=sm.rstrctd_ind
AND substr(hct.ap_order_num,1,1)='T'
AND hct.svc_num=4042091777

43574 52701 TO8D5JX0 4042091777 4042091777
43574 52700 TO8D5JX0 4042091777 4042091777

43775 39582 TO803XY6 4042091777 4042091777
43775 39583 TO803XY6 4042091777 4042091777

45474 49472 TOFHNBQ2 4042091777 4042091777
45474 49473 TOFHNBQ2 4042091777 4042091777
45474 49474 TOFHNBQ2 4042091777 4042091777


Tom Kyte

Followup  

April 15, 2004 - 11:17 am UTC

(i can only answer that which is actually ASKED)...

what happens if

45474 49472 TOFHNBQ2x 4042091777 4042091777
45474 49473 TOFHNBQ2y 4042091777 4042091777
45474 49474 TOFHNBQ2z 4042091777 4042091777

is the data? you'll get a random one back


but in any case


set c = substr( select max( to_char(batch_num,'fm0000000000' ) || ap_order_num )
from ....
where .....
and hct.svc_num = updated_table.svc_num ), 11 )


assuming

o batch num is a max 10 digit positive number (if larger, add more zeroes, increase 11 approapriately)



If I had lots of rows to update, i might two step this with a global temporary table and

o get all of the svc_numbers/ap_order_nums into a GTT with a primary key of svc_num

o update the join of that gtt to the details




Question

April 21, 2004 - 12:07 pm UTC

Reviewer: PRS from USA

Tom,
   I have a following view defined on oracle 9.2.0.4 box.
CREATE OR REPLACE VIEW test_view (
   opportunity_id,
   bo_id_cust,
   wsi_account_id,
   wsi_account_no,
   first_name,
   last_name,
   opportunity_status,
   long1,
   td_opp_flw_up_act,
   long2,
   person_id,
   name,
   ra_campaign_id,
   ra_cmpgn_name,
   row_added_dttm,
   row_lastmant_dttm,
   next_activity_dt,
   act_close_dt,
   act_revenue,
   est_revenue,
   phone,
   dummy
  ,note )
AS
SELECT B.opportunity_id 
,B.BO_ID_CUST 
,A.WSI_ACCOUNT_ID 
,E.WSI_ACCOUNT_NO 
,B.FIRST_NAME 
,B.LAST_NAME 
,B.OPPORTUNITY_STATUS 
,f.xlatlongname long1
,A.TD_OPP_FLW_UP_ACT 
,g.xlatlongname long2 
,B.PERSON_ID 
,D.NAME 
,A.RA_CAMPAIGN_ID 
,C.RA_CMPGN_NAME 
,B.ROW_ADDED_DTTM 
,B.ROW_LASTMANT_DTTM 
,B.NEXT_ACTIVITY_DT
,B.ACT_CLOSE_DT 
,B.ACT_REVENUE 
,B.EST_REVENUE 
,B.PHONE 
,'' dummy
,crm_get_values_ref_cursor_pkg.get_opp_note(B.opportunity_id) note
FROM PS_WSI_RSF_OPP_FLD A 
, PS_RSF_OPPORTUNITY B 
, PS_RA_CAMPAIGN C 
, PS_RD_PERSON_NAME D 
, PS_WSI_ACCOUNT E 
,PSXLATITEM F
,PSXLATITEM G
WHERE A.OPPORTUNITY_ID = B.OPPORTUNITY_ID 
AND A.RA_CAMPAIGN_ID = C.RA_CAMPAIGN_ID(+) 
AND B.PERSON_ID = D.PERSON_ID(+) 
AND A.WSI_ACCOUNT_ID = E.WSI_ACCOUNT_ID(+)
AND f.fieldvalue(+) = b.opportunity_status
AND f.fieldname(+) = 'OPPORTUNITY_STATUS'
AND g.fieldvalue(+) = A.TD_OPP_FLW_UP_ACT 
AND g.fieldname(+) = 'TD_OPP_FLW_UP_ACT'
/

   My query is as shown below.
select /*+ FIRST_ROWS */ * from test_view where person_id = '50004100' and ra_campaign_id  = '4'
   This query comes back in .7 second. Following is the explain plan.

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=HINT: FIRST_ROWS (Cost=6444 Card= 3300 Bytes=745800)
   1    0   MERGE JOIN (OUTER) (Cost=6444 Card=3300 Bytes=745800)
   2    1     MERGE JOIN (OUTER) (Cost=5619 Card=3300 Bytes=666600)
   3    2       NESTED LOOPS (OUTER) (Cost=4794 Card=3300 Bytes=587400  )
   4    3         NESTED LOOPS (OUTER) (Cost=3144 Card=3300 Bytes=537900)
   5    4           NESTED LOOPS (OUTER) (Cost=2319 Card=3300 Bytes=435600)
   6    5             NESTED LOOPS (Cost=1494 Card=3300 Bytes=333300)
   7    6               TABLE ACCESS (BY INDEX ROWID) OF 'PS_RSF_OPPORTUNITY' (Cost=669 Card=3300 Bytes=264000)
   8    7                 INDEX (RANGE SCAN) OF 'PSJRSF_OPPORTUNITY' (NON-UNIQUE) (Cost=12 Card=3300)
   9    6               TABLE ACCESS (BY INDEX ROWID) OF 'PS_WSI_RSF_OPP_FLD' (Cost=2 Card=1 Bytes=21)
  10    9                 INDEX (UNIQUE SCAN) OF 'PS_WSI_RSF_OPP_FLD' (UNIQUE)
  11    5             TABLE ACCESS (BY INDEX ROWID) OF 'PSXLATITEM' (Cost=2 Card=1 Bytes=31)
  12   11               INDEX (RANGE SCAN) OF 'PSAPSXLATITEM' (NON-UNIQUE)
  13    4           TABLE ACCESS (BY INDEX ROWID) OF 'PSXLATITEM' (Cost=2 Card=1 Bytes=31)
  14   13             INDEX (RANGE SCAN) OF 'PSAPSXLATITEM' (NON-UNIQUE)
  15    3         TABLE ACCESS (BY INDEX ROWID) OF 'PS_WSI_ACCOUNT' (Cost=2 Card=1 Bytes=15)
  16   15           INDEX (RANGE SCAN) OF 'PSAWSI_ACCOUNT' (NON-UNIQUE ) (Cost=1 Card=1)
  17    2       BUFFER (SORT) (Cost=5617 Card=1 Bytes=24)
  18   17         TABLE ACCESS (BY INDEX ROWID) OF 'PS_RD_PERSON_NAME' (Cost=2 Card=1 Bytes=24)
  19   18           INDEX (RANGE SCAN) OF 'PSDRD_PERSON_NAME' (NON-UNIQUE)
  20    1     BUFFER (SORT) (Cost=6442 Card=1 Bytes=24)
  21   20       INDEX (FULL SCAN) OF 'PS0RA_CAMPAIGN' (NON-UNIQUE) (Cost=1 Card=1 Bytes=24)
Statistics
----------------------------------------------------------
        287  recursive calls
          0  db block gets
      22191  consistent gets
          0  physical reads
       3420  redo size
      58875  bytes sent via SQL*Net to client
        842  bytes received via SQL*Net from client
         19  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
        264  rows processed

As soon as I add order by clause query take 30 seconds to run. Please see below.

SQL> 
  1  select /*+ FIRST_ROWS */ * from test_view where person_id = '50004100' and ra_campaign_id  = '4'
  2* Order by person_id,row_added_dttm

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=HINT: FIRST_ROWS (Cost=12866 Card =3300 Bytes=745800)
   1    0   MERGE JOIN (OUTER) (Cost=12866 Card=3300 Bytes=745800)
   2    1     MERGE JOIN (OUTER) (Cost=12041 Card=3300 Bytes=666600)
   3    2       NESTED LOOPS (OUTER) (Cost=11216 Card=3300 Bytes=587400)
   4    3         NESTED LOOPS (OUTER) (Cost=10391 Card=3300 Bytes=485100)
   5    4           NESTED LOOPS (Cost=8741 Card=3300 Bytes=435600)
   6    5             NESTED LOOPS (OUTER) (Cost=7916 Card=3300 Bytes=366300)
   7    6               TABLE ACCESS (BY INDEX ROWID) OF 'PS_RSF_OPPORTUNITY' (Cost=7091 Card=3300 Bytes=264000)
   8    7                 INDEX (FULL SCAN) OF 'PSGRSF_OPPORTUNITY' (NON-UNIQUE) (Cost=26928 Card=3300)
   9    6               TABLE ACCESS (BY INDEX ROWID) OF 'PSXLATITEM'(Cost=2 Card=1 Bytes=31)
  10    9                 INDEX (RANGE SCAN) OF 'PSAPSXLATITEM' (NON-UNIQUE)
  11    5             TABLE ACCESS (BY INDEX ROWID) OF 'PS_WSI_RSF_OPP_FLD' (Cost=2 Card=1 Bytes=21)
  12   11               INDEX (UNIQUE SCAN) OF 'PS_WSI_RSF_OPP_FLD' (UNIQUE)
  13    4           TABLE ACCESS (BY INDEX ROWID) OF 'PS_WSI_ACCOUNT' (Cost=2 Card=1 Bytes=15)
  14   13             INDEX (RANGE SCAN) OF 'PSAWSI_ACCOUNT' (NON-UNIQUE) (Cost=1 Card=1)
  15    3         TABLE ACCESS (BY INDEX ROWID) OF 'PSXLATITEM' (Cost= 2 Card=1 Bytes=31)
  16   15           INDEX (RANGE SCAN) OF 'PSAPSXLATITEM' (NON-UNIQUE)
  17    2       BUFFER (SORT) (Cost=12039 Card=1 Bytes=24)
  18   17         TABLE ACCESS (BY INDEX ROWID) OF 'PS_RD_PERSON_NAME'(Cost=2 Card=1 Bytes=24)
  19   18           INDEX (RANGE SCAN) OF 'PSDRD_PERSON_NAME' (NON-UNIQUE)
  20    1     BUFFER (SORT) (Cost=12864 Card=1 Bytes=24)
  21   20       INDEX (FULL SCAN) OF 'PS0RA_CAMPAIGN' (NON-UNIQUE) (Cost=1 Card=1 Bytes=24)





Statistics
----------------------------------------------------------
        294  recursive calls
          0  db block gets
      57940  consistent gets
          0  physical reads
       1140  redo size
      60741  bytes sent via SQL*Net to client
        842  bytes received via SQL*Net from client
         19  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
        264  rows processed

SQL>

    It uses a different index. This query comes from peoplesoft application, so that puts the hint. We do not put hint. Our tables are 35% analyzed and indexes are 100% analyzed daily in the night.

    Indexes are as under on PS_RSF_OPPORTUNITY table.
psarsf_opportunity
    next_activity_dt                ASC,
    person_id                       ASC
psbrsf_opportunity
    bo_id_cust                      ASC,
    bo_id_contact                   ASC
psdrsf_opportunity
    row_lastmant_dttm               ASC,
    person_id                       ASC
psersf_opportunity
    last_name                       ASC,
    first_name                      ASC
psgrsf_opportunity
    row_added_dttm                  ASC,
    person_id                       ASC
pshrsf_opportunity
    phone                           ASC
psjrsf_opportunity
    person_id                       ASC,
    opportunity_status              ASC
pskrsf_opportunity
    first_name                      ASC
psmrsf_opportunity
    act_close_dt                    ASC,
    person_id                       ASC
ps_rsf_opportunity
    opportunity_id                  ASC

    Indexes on PS_WSI_RSF_OPP_FLD tables are as under.
psawsi_rsf_opp_fld
    wsi_account_id                  ASC
psbwsi_rsf_opp_fld
    ra_campaign_id                  ASC
pscwsi_rsf_opp_fld
    td_opp_flw_up_act               ASC,
    opportunity_id                  ASC
ps_wsi_rsf_opp_fld
    opportunity_id                  ASC

    Why order by is causing problem? Any insight is appreciated?

Thanks,
PRS 

Query

April 29, 2004 - 5:06 pm UTC

Reviewer: mo

Tom:

Do you know why I am not getting the answer of 5 here.

SQL> select course_no from course;

 COURSE_NO
----------
         1
         2
         3
         4
         5

5 rows selected.

SQL> select distinct course_no from certificate;

 COURSE_NO
----------
         1
         2
         3
         4


5 rows selected.

SQL> select course_no from course where course_no not in (select distinct course_no
  2  from certificate);

no rows selected
 

Tom Kyte

Followup  

April 29, 2004 - 5:17 pm UTC

give me

a) create table
b) insert into's

in order to reproduce.

query

April 30, 2004 - 7:45 pm UTC

Reviewer: mo

Tom:

This is really strange. When i replicate the tables/data in another instance I get correct resutls. When I run the query in TEST instance it gives me corect results. Only when I run the query in DEV instance I get the "no rows found".

Here are the DMLs:

create table course
(course_no number(2) );


create table certificate
(certificate_no number(2),
course_no number(2) );

insert into course values (1);
insert into course values (2);
insert into course values (3);
insert into course values (4);
insert into course values (5);

insert into certificate(10,1);
insert into certificate(10,2);
insert into certificate(10,3);
insert into certificate(10,4);

Tom Kyte

Followup  

May 01, 2004 - 9:11 am UTC

post the query plans for both a working and non-working (use sql_trace=true and post the tkprof reports for the queries making sure to point out which is which)

Query

May 01, 2004 - 1:54 pm UTC

Reviewer: Brian Camire from Toronto, ON CA

It looks like you have NULL values in certificate.course_no as...

SQL> select distinct course_no from certificate;

 COURSE_NO
----------
         1
         2
         3
         4


5 rows selected.

...suggests (since there were 5 rows selected instead of 4).  This would cause the NOT IN operator to return FALSE and explain the behavior you are observing. 

Tom Kyte

Followup  

May 01, 2004 - 5:50 pm UTC

that is what I thought -- but he said the output was:


SQL> select course_no from course;

 COURSE_NO
----------
         1
         2
         3
         4
         5

5 rows selected.

no nulls apparent there. 

Please help

May 01, 2004 - 2:22 pm UTC

Reviewer: Roselyn from Hanover,Germany

Hello Sir,
Whenever we issue a Select(query) statement,whether Oracle fetches a
copy of data to be operated upon or the entire original data?
I would like to know this.
Please do reply.



Tom Kyte

Followup  

May 01, 2004 - 7:47 pm UTC

we do not "copy the data"

we use multi-versioning, if you issue a query such as:

select * from a_1_kabillion_row_table;

there will be NO IO, until you actually fetch a row, then and only then will we read data and starting processing.



If you haven't read the Concepts Guide -- you should, especially the chapter on concurrency and multi-versioning. It is what sets Oracle apart from all of the rest.

Query

May 01, 2004 - 7:21 pm UTC

Reviewer: Brian Camire from Toronto, ON CA

Yes, but it's the certificate table that's being selected from in the subquery.

Tom Kyte

Followup  

May 01, 2004 - 7:56 pm UTC

AHHH, of course

that is it 100%

the null in there is doing it, definitely.

query

May 02, 2004 - 12:19 pm UTC

Reviewer: mo

Tom:

yes it was the null value. however i thought it should run like this:

select course_no from course where course_no not in (select distinct
course_no
from certificate);

select (1,2,3,4,5) where this not in (1,2,3,4,null)

5 is still is not in the set?

Tom Kyte

Followup  

May 02, 2004 - 4:25 pm UTC

it is "unknown" whether 5 is not in that set, that is the essence of NULL.

query

June 15, 2004 - 7:14 pm UTC

Reviewer: mo

Tom:

For the tables listed above, I am trying to get a report that lists several computations per material item in the MATERIAL table as Total requests that include each item, total shipments that include that item etc.

I got two queries working separately and I could not combine them correctly. Can and how do you do it:

select material_id,
count(case when request_id is not null and (request_status = 'Open' or request_status = 'Partial') and request_date < to_date('01-APR-2004') then 1 end) pending_req_cnt,
count(case when request_id is not null and request_date between to_date('01-APR-2004') and to_date ('01-JUL-2004') then 1 end) new_req_cnt,
count(case when request_id is not null and (request_status = 'Open' or request_status = 'Partial') and request_date < to_date ('01-JUL-2004') then 1 end) remain_req_cnt
from
(
select a.request_id,a.request_date,a.request_status,priority,b.item_number,
substr(c.description,1,15) description,c.material_id
from request a,requested_item b,material c
where a.request_id(+)=b.request_id and
b.material_id(+) = c.material_id
order by a.request_id
)
group by material_id


select material_id,
count(case when shipment_id is not null then 1 end) tot_shipments
from
(
select a.shipment_id,c.material_id
from shipment a, shipped_item b, material c
where a.shipment_id(+) = b.shipment_id and
b.material_id(+) = c.material_id
order by a.shipment_id
)
group by material_id

Tom Kyte

Followup  

June 16, 2004 - 12:08 pm UTC

i don't know how you want them "combined".....

if you want a single row per material_id, just

select material_id, sum(cnt1), sum(cnt2), sum(cnt3), sum(cnt4)
from
(
select material_id, case( ... ) cnt1, case( .... ) cnt2,
to_number(null)cnt3, to_number(null) cnt4
from .....
group by ....
UNION ALL
select material_id, to_number(null), to_number(null),
case( ..... ) cnt3, case(....) cnt4
from ...
group by ...
)
group by material_id;

(i am assuming you would need a full outer join to put your two queries together, this trick avoids the need for a full outer join, otherwise, if a material_id is either in BOTH results or NIETHER result - -just join)

query

June 16, 2004 - 4:25 pm UTC

Reviewer: mo

Tom:
Your way was truly brilliant. However it worked with this format:

select X.*,Y.* from
(
QUERY1
) X,
(
QUERY2
) Y

where x.material_id = y.material_id

Is your format better/faster or they both the same since they involve two table scans.

Tom Kyte

Followup  

June 16, 2004 - 4:30 pm UTC

they should be more or less equivalent, as long as a join is all you need.

if there are material ids in X not in Y or vice versa, you'd need the full outer join or my technique.

Max,Min and Last value combined

June 26, 2004 - 11:37 am UTC

Reviewer: Segun Jeks from Nigeria

Tom,

Kindly assist me. I do pray i'll get your response.
I have table :
create table mkt_daily
(ddate date,
price number(5,2),
coy varchar2(9),
constraints pk_md primary key (ddate,coy));
with these data:
insert into mkt_daily values(to_date('24-05-2004','dd-mm-yyyy'),'6.2','ASKTOM');
insert into mkt_daily values(to_date('25-05-2004','dd-mm-yyyy'),'6.1','ASKTOM');
insert into mkt_daily values(to_date('27-05-2004','dd-mm-yyyy'),'5.2','ASKTOM');
insert into mkt_daily values(to_date('26-05-2004','dd-mm-yyyy'),'5.2','ASKTOM');
insert into mkt_daily values(to_date('27-05-2004','dd-mm-yyyy'),'5.5','ASKTOM');
insert into mkt_daily values(to_date('28-05-2004','dd-mm-yyyy'),'6.0','ASKTOM');
insert into mkt_daily values(to_date('01-06-2004','dd-mm-yyyy'),'6.8','ASKTOM');
insert into mkt_daily values(to_date('02-06-2004','dd-mm-yyyy'),'5.5','ASKTOM');
insert into mkt_daily values(to_date('03-06-2004','dd-mm-yyyy'),'5.5','ASKTOM');
insert into mkt_daily values(to_date('07-06-2004','dd-mm-yyyy'),'5.6','ASKTOM');
insert into mkt_daily values(to_date('08-06-2004','dd-mm-yyyy'),'5.8','ASKTOM');
insert into mkt_daily values(to_date('09-06-2004','dd-mm-yyyy'),'5.9','ASKTOM');
insert into mkt_daily values(to_date('10-06-2004','dd-mm-yyyy'),'6.0','ASKTOM');
insert into mkt_daily values(to_date('11-06-2004','dd-mm-yyyy'),'6.1','ASKTOM');

My challenge is this: i want to fetch the max(price)High, min(price)Low and last(price)"Closing_Price" for every week.
i.e
week high low Closing_Price
22 6.2 5.2 6.0
23 6.8 5.5 5.5
24 6.1 5.6 6.1

I have tried:
a) select max(price)high,to_char(ddate,'IW') from mkt_daily GROUP BY to_char(ddate,'IW');
b) select min(price),to_char(ddate,'IW') from mkt_daily GROUP BY to_char(ddate,'IW');

Thanks for your anticipated positive response.


Tom Kyte

Followup  

June 26, 2004 - 7:03 pm UTC

ops$tkyte@ORA10G> select to_char(ddate,'iw'), max(price), min(price),
  2         to_number( substr( max(to_char(ddate,'yyyymmdd')||price), 9)) mp
  3    from mkt_daily
  4   group by to_char(ddate,'iw')
  5  /
 
TO MAX(PRICE) MIN(PRICE)         MP
-- ---------- ---------- ----------
22        6.2        5.2          6
23        6.8        5.5        5.5
24        6.1        5.6        6.1
 

Max,min and last combined

June 28, 2004 - 7:09 am UTC

Reviewer: Segun Jeks from Nigeria

Tom,

Many thanks. I am impressed.Your response was timely and fantastic.

Do you have any book that I can read to understand some of the sql tricks, especially combining the sql functions to get desired results like you just did.

Tom Kyte

Followup  

June 28, 2004 - 8:58 am UTC

well, mostly they are not 'tricks', they are the results of doing SQL for 17 years ;)

What I do (did) is list out the requirements in english to understand the question.

"by week, report the min price, the max price and the last price (price with the highest date for that week)"


That said it all -- it was easy after that. min/max -- trivial. The only 'hard' one was the "last price". I wrote about that a while ago:

</code> http://otn.oracle.com/oramag/oracle/02-sep/o52asktom.html
PLAYING WITH AGGREGATION

and demonstrated a couple of techniques.  Since we were already aggregating (the by week told me that), i used the technique of encoding the thing we needed to max (the date) in a string and putting the related fields on the end of the string - so we'd get the data for the max(date) plus the other stuff - to substring back out.


if you are interested:

http://asktom.oracle.com/~tkyte/asktom_articles.html <code>

has links to 4 years of columns -- each one pretty much has a different technique or two in it. (i also wrote about many of them in my books as well).


Anyone out there have a favorite "sql tricks" book?


quesiton on query rewriting

June 29, 2004 - 11:24 am UTC

Reviewer: A reader

somewhere on your site I saw a way of changing
the text of a query using a pl/sql package ( I think.) This is
useful for queries that you can not directly change
(3rd party application) and so want to intercept
it and silently modify it before executing...
Can you please point me to the thread or give the pl/sql
package name that does it?

thanx!

Tom Kyte

Followup  

June 29, 2004 - 4:13 pm UTC

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:16873041382355#16939690111297 <code>

10g and above new feature.

thanx!

June 29, 2004 - 4:14 pm UTC

Reviewer: A reader


query

July 09, 2004 - 12:28 pm UTC

Reviewer: mo

Tom:

Is there a way to do sql query on a number value(use between) for a varchar2 field that has values as either numbers or text. I want to search only the number values for field between 5000 and 6000.

is it possible?

Tom Kyte

Followup  

July 09, 2004 - 1:53 pm UTC

you'd need to first validate that what you have is in fact a number. if you expected only "digits", you can use replace/translate to determine that the string you have contains only the characters 0..9 and then to_number it.

You should have *some* metadata in your generic (as life goes on i am beginning to hate generic) implementation that you can look at to see if it is a number or not. If not, you just have random bits and bytes.

SQL Query

July 10, 2004 - 3:48 am UTC

Reviewer: A reader

How can I return multiple rows as a single row using sql queries?

From SQL*Plus, how can I return a single row when the result set contains multiple rows.

For example:

select tablespace_name from dba_segments

returns

SYSTEM
USER
TEMP

but I want this to return as 'SYSTEM','USER','TEMP'.

How can I achieve this from SQL*plus using sql queries?

Tom Kyte

Followup  

July 10, 2004 - 9:19 am UTC

search this site for stragg

single row result for multiple rows

July 19, 2004 - 5:47 pm UTC

Reviewer: Mir from Houston, TX

i am trying to write a sql query which will publish single row info from multiple rows.


create table t(
id number,
cusid number,
cat varchar2(3))
/

INSERT INTO t VALUES (1,1,'crd')
/
INSERT INTO t VALUES (2,2,'ins')
/
INSERT INTO t VALUES (3,2,'crd')
/
INSERT INTO t VALUES (4,2,'lns')
/
INSERT INTO t VALUES (5,3,'ins')
/
INSERT INTO t VALUES (6,3,'crd')
/
INSERT INTO t VALUES (7,4,'lns')
/
INSERT INTO t VALUES (8,4,'ins')
/
INSERT INTO t VALUES (9,4,'crd')
/
INSERT INTO t VALUES (10,5,'ins')
/
INSERT INTO t VALUES (11,6,'ins')
/
INSERT INTO t VALUES (12,6,'ins')
/
INSERT INTO t VALUES (13,7,'lns')
/
INSERT INTO t VALUES (14,7,'lns')
/

from the above data i want ID, CUSID = CUSID where cat = 'crd' OR CUSID should be the first value from the group

the output should be
id cusid cat
1 1 crd
3 2 crd
6 3 crd
9 4 crd
10 5 ins
11 6 ins
13 7 lns

Thanks


Tom Kyte

Followup  

July 19, 2004 - 7:09 pm UTC

CUSID = CUSID where cat = 'crd' OR CUSID should 
be the first value from the group

doesn't make sense to me.  "cusid = cusid"??  "first value from the group"??  what group?

near as I can tell, you might mean:

ops$tkyte@ORA9IR2> select distinct
  2         first_value(id) over (partition by cusid order by decode(cat,'crd',1,2), cat ) fid,
  3         cusid,
  4         first_value(cat) over (partition by cusid order by decode(cat,'crd',1,2), cat ) fcat
  5    from t
  6  /
 
       FID      CUSID FCA
---------- ---------- ---
         1          1 crd
         3          2 crd
         6          3 crd
         9          4 crd
        10          5 ins
        11          6 ins
        13          7 lns
 
7 rows selected.
 
 

Need help with combining multiple queries

July 20, 2004 - 5:07 pm UTC

Reviewer: denni50 from NA

Hi Tom

could you please help with the following queries.
I would like to combine them into one massive(relatively
speaking) query. I have them all working correctly
independently. I now have analytics so that would be
even better.

Finds first gift given by donor:
select i.giftamount,i.giftdate
from gift i,acga_dr a where i.giftdate in(select min(g.giftdate)
from gift g
where g.idnumber=i.idnumber
and g.giftamount>0)
and i.idnumber=a.idnumber

Finds last gift given by donor:
select i.giftamount,i.giftdate
from gift i,acga_dr a where i.giftdate in(select max(g.giftdate)
from gift g
where g.idnumber=i.idnumber
and g.giftamount>0)
and i.idnumber=a.idnumber

Performs aggregates on individual donor history and
inserts into new table:
begin
for i in(select g.idnumber,sum(g.giftamount)LTGifts,count(g.giftamount)LTCount,max(g.giftamount)LargestGift, min(g.giftdate)FirstGiftDate,max(g.giftdate)LastGiftDate
from gift g,acga_drL a
where g.idnumber=a.idnumber
group by g.idnumber
)loop
insert into acga_drL(ltgifts,ltcount,largestgift,firstgiftdate,lastgiftdate)
values(i.ltgifts,i.ltcount,i.largestgift,i.firstgiftdate,i.lastgiftdate);
end loop;
end;

thanks!..(sorry about the formatting here)




Tom Kyte

Followup  

July 20, 2004 - 8:47 pm UTC

why did you run the first two queries? where did you use that output?

first 2 queries(should have explained better)

July 20, 2004 - 9:16 pm UTC

Reviewer: denni50 from NA

I haven't done anything with them yet. I just ran those to
test and see if the correct results would get produced(which
they did).

Now I want to include them as part of the "insert" query
so that the results(will create columns) of the first 2 queries can be combined with the columns of the insert query...and that's where I'm kind of stuck.

hope this makes more sense... :~)

ps: analytics is really cool and man does it speed things up

Tom Kyte

Followup  

July 20, 2004 - 10:01 pm UTC

are all of the table names right? the L on the end of some but not others?

two tables

July 21, 2004 - 8:56 am UTC

Reviewer: denni50 from NA

The acga_drL table is the actual table the acga_dr table
is a copy for testing purposes.

Upon testing the 2 queries for correctness using the
test table(acga_dr) I would then combine the two queries
with the insert query to insert the results to the
acga_drL table.

thanks


Tom Kyte

Followup  

July 21, 2004 - 9:06 am UTC

please clarify -- how many tables will the *real* thing be against?

is "acga_dr" there for the long haul -- the example confuses me with two tables, one of which might not be there for "long"

where I am heading is:

select g.idnumber,
sum(g.giftamount) LTGifts,
count(g.giftamount) LTCount,
max(g.giftamount) LargestGift,
min(g.giftdate) FirstGiftDate,
max(g.giftdate)LastGiftDate,
to_number(substr(max( case when g.giftamount>0 then to_char(g.giftdate,'yyyymmddhh24miss')||g.giftamount end), 15 )),
to_number(substr(min( case when g.giftamount>0 then to_char(g.giftdate,'yyyymmddhh24miss')||g.giftamount end), 15 )),
from gift g,acga_dr a
where g.idnumber=a.idnumber
group by g.idnumber


which uses the technique from:

</code> http://otn.oracle.com/oramag/oracle/02-sep/o52asktom.html <code>

"Playing with aggregation" to get the giftamount for the min/max date.

thanks Tom..

July 21, 2004 - 9:53 am UTC

Reviewer: A reader

sorry for the obvious confusion(I'm still developing the
plan as I go along).

I was just given this assignment yesterday with a friday
deadline.

This is a donor research project and what I'm looking at is this:

a) first find all the lapsed donors with 2+ years on file
with a lastgiftamount > 0 between 18-36 months.
I already have that data and inserted that into acga_dr

b) of those donors give us:
Lifetime giftamounts
Lifetime count of gifts
Largest gift amount
First gift date
Last giftdate
First giftamount
Last giftamount
(I am at this stage)

c)then give us an annual cumulative giving history based
on the date of the lastgiftamount>0,-12 months.
This sum will fall into buckets(example):
$10-74 bucket
$75-149 "
$150-499 "
...and so on

d) then give a report on how many of the donors fall
into the above buckets...along with the column results
from step b.

my plan is to use one table to get the results from step
a, use that table to gather the data for steps b & c and
put those results into a separate table. Then create a
view to process the results from both tables for output to a .txt or .csv file.

If you have a better solution I'm all eyes and "ears"

hth






that last post is mine..forgot to insert my username

July 21, 2004 - 9:54 am UTC

Reviewer: denni50 from NA


THANKS TOM!

July 21, 2004 - 10:25 am UTC

Reviewer: denni50 from NA

your query did the trick as as far as getting the
First Giftamount and Last Giftamount.

one last question(so I understand your case statement and
can learn from it).

why did you use to_number,substr and to_char to achieve
the results and what does '15' represent?

one last THANKS!

Tom Kyte

Followup  

July 21, 2004 - 11:00 am UTC

the 15 removes the leading 14 characters of yyyymmddhh24miss information (the date :)

we glued the date on front in a fixed width field that "sorts string wise" and minned/maxxed that. that'll give us the giftamount we glued onto the end -- which we just substr off.

SQL tricks

August 20, 2004 - 7:24 am UTC

Reviewer: Syed from London

Hi Tom

your ability to do things with SQL is so impressive Like a previous reply, i'm sure many of us would love a small book / list of top 20 SQL tricks etc.

Anyway, I am sure the following cursor / loop could be combined inot a single SQL statements (following your mantra of do it in a single statement if possible), but am not sure how to go about it ?


cursor c1 is

select
y.rowid get_rowid
from
tab1 y,
(select col1, max(col2) collection from tab1 group by col1) x
where
x.col1 = y.col1
and
x.collection = y.collection;

for REC in c1 loop

insert into tab2 (a, b)
select
tab1.clid,
tab2.blid
from
tab1, tab2
where
tab1.rowid = REC.get_rowid
and
tab1.clid = tab2.blid(+)
end loop;


Thanks

Syed

Tom Kyte

Followup  

August 20, 2004 - 11:19 am UTC

insert into tab2 (a, b)
select
tab1.clid,
tab2.blid
from
tab1, tab2, (YOUR CURSOR QUERY) tab3
where
tab1.rowid = tab3.get_rowid
and
tab1.clid = tab2.blid(+)
/

just "join" -- you are doing the classic "do it yourself nested loop join" there.

using analytics you could further simplify this. looks like you want the row from tab1 such that col2 is the max grouped by col1:

from
(select ...
from (select ..., max(col2) over (partition by col1) max_col2
from tab1 )
where col2 = max_col2) tab1, tab2
where tab1.xxx = tab2.xxxx (+)

would do that.

Brilliant

August 23, 2004 - 5:40 am UTC

Reviewer: Syed from London


simplify further

August 23, 2004 - 10:36 am UTC

Reviewer: Tom Burrows from Sweden

Hi tom

Can you show the final query from above with the analytical function in it ?

Thanks

Tom

Tom Kyte

Followup  

August 23, 2004 - 10:41 am UTC

i did?!?

max(col2) over (partition by col1) max_col2

is the analytic

Why doesn't it work!!!!!!!!!!

August 23, 2004 - 3:48 pm UTC

Reviewer: A reader

Hi Tom,
I am executing the following query:
select
c.cmpname Company,
to_char(t.trnsaledate,'Day, DD-fmMonth-YYYY') Fecha,
TO_CHAR(sum(r.recvalue),'9,999,999,999.00') Total
from
stkrecord r,
stktransaction t,
stkcompany c
where
t.trnsaledate > to_date('30-Jul-2004','DD-Mon-YYYY')
and t.trnsaledate < to_date('23-Aug-2004','DD-Mon-YYYY')
and to_char(t.trnsaledate,'Day') = 'Friday'
and c.cmpid = t.trncmpid
and r.rectrnID = t.trnID
group by c.cmpname, to_char(t.trnsaledate,'Day, DD-fmMonth-YYYY')

It returns me 0 rows.
Why does not the sentence and to_char(t.trnsaledate,'Day') = 'Friday' work.
Am I doing anything wrong? I need only the data for Friday.
Is the approach wrong?
Thanks as always......

Tom Kyte

Followup  

August 23, 2004 - 3:54 pm UTC

ops$tkyte@ORA9IR2> select '"' || to_char(d,'Day') || '"'
  2  from ( select sysdate+rownum d from all_users where rownum <= 7);
 
'"'||TO_CHA
-----------
"Tuesday  "
"Wednesday"
"Thursday "
"Friday   "
"Saturday "
"Sunday   "
"Monday   "
 
7 rows selected.
 
ops$tkyte@ORA9IR2> 1
  1* select '"' || to_char(d,'Day') || '"'
ops$tkyte@ORA9IR2> c/Day/fmDay/
  1* select '"' || to_char(d,'fmDay') || '"'
ops$tkyte@ORA9IR2> /
 
'"'||TO_CHA
-----------
"Tuesday"
"Wednesday"
"Thursday"
"Friday"
"Saturday"
"Sunday"
"Monday"
 
7 rows selected.



trailing blanks -- fm, the format modifier, trims them.

probably better to use:

where to_char(t.trnsaledate,'d') = 
         to_char(to_date('31-dec-1965','dd-mon-yyyy'),'d')


that 31-dec-1965 is a friday, it'll tell us the day of the week a friday is using your NLS setting....

It is safe (no whitespace)
It is international (works in places that spell friday differently!)

 

August 23, 2004 - 7:41 pm UTC

Reviewer: A reader


function in order by clause

August 24, 2004 - 8:18 am UTC

Reviewer: friend

hai tom,

i have one function fun

this returns 1

if i use this function in the following query

> select * from table_name order by fun;

fun in order by clause

it's not giving any syntactic error but it simply ignoring the order by clause

??? is it correct to use functions in order by clause

??? can we use functions after " from clause" insted of table name, by returing that table name from function





Tom Kyte

Followup  

August 24, 2004 - 8:55 am UTC

if the function fun returns the constant one, how can you possibly say "it is ignoring it"

??????


select * from table_name order by 'X';

think about that -- what does that do - it orders by the constant 'X'


perhaps you are thinking that:

select * from table_name order by f()

where f() returns the number 1 is the same as:

select * from table_name order by 1;


-- but it cannot be (think about this:

ops$tkyte@ORA9IR2> create table t as select 1 xxx from all_users;
 
Table created.
 
ops$tkyte@ORA9IR2> select * from t order by xxx;
 
       XXX
----------
         1
         1
         1
....


here xxx is not ANY DIFFERENT than your function f())


You are simply ordering by a constant, you are NOT specifying to "order by column 1"
 

excellent Sql

August 25, 2004 - 4:32 am UTC

Reviewer: A reader from CHINA

Hi,Tom ,Your sql is very userful to me,thankyou

How to get distinct values from a table?

September 02, 2004 - 11:37 am UTC

Reviewer: RB from NJ

Tom:
I have a table
TABLE A
(src varchar2(30)
Dest varchar2(30),
Start_date DATE,
End_date DATE,
Sent_bytes NUMBER(30)
Received_Bytes NUMBER(30)
);

This is what I am doing now:

We obtain the first connection to the database
We send the initial SQL statement “select * from A” using the first connection. The first connection returns a ResultSet, which contains metadata about the columns of table A and a pointer to the first record We obtain a second connection to the database

For each column defined by the metadata (repeat):
We send a new SQL statement “select distinct(src) from (select * from A) order by src desc” using the second connection.
The second connection returns a ResultSet, which contains all the distinct values of src in descending order
We pre-initialize dimension(src) using the records in this second ResultSet
Close the second connection to the database
Allocate the number of records defined by the first connection’s ResultSet
Now extract all the records returned by the first connection’s ResultSet populating our data structure with “data”
Once data is made available, the application can now define a visualization for this data

We extract out and define each dimension and their unique values in order to optimize user interactions and queries.


The problem is performance is really bad because we are doing column by column and doing distinct on top and sorting on top.

Is there a best way so that I can get the result that I want. If I can get the whole thing in one fetch that will be great - again this is just a sample table - our original table has 20+ columns and 300 million records - this table grows as well.

Any help is greatly appreciated

R





Tom Kyte

Followup  

September 02, 2004 - 12:59 pm UTC

how many bad things did I see in the first paragraph!!

why you have more than one connection is far far far beyond my comprehension.

but beyond that -- why do you need the distinct values -- what are you doing? do you really retrieve 300million records to a client application????

How to get distinct values from a table?

September 02, 2004 - 3:05 pm UTC

Reviewer: R from NJ

Tom:
Having multiple connection - When I saw the code I felt the same way. I have already reommended them to use a single connection.
Dinstinct Values -
We are developing a visualization package. To chart the data properly the application requires to get all the distinct values from each column.

RIght now for each column one query is being executed. I would like to eliminate that and get all the columns in one query if possible.

R

Tom Kyte

Followup  

September 02, 2004 - 4:18 pm UTC


ops$tkyte@ORA9IR2> create or replace procedure all_distinct_values( p_tname in varchar2, p_cursor in out sys_refcursor )
  2  as
  3      l_stmt  long := 'select distinct ';
  4      l_decode_1 long := 'decode( r';
  5      l_decode_2 long := 'decode( r';
  6      l_decode_3 long := 'decode( r';
  7  begin
  8
  9      for x in (select column_id, data_type, column_name,
 10                       decode( data_type, 'DATE', 'to_char(' || column_name || ', ''yyyymmddhh24miss'' )',
 11                                          'NUMBER', 'to_char(' || column_name || ' )',
 12                                          column_name) fcname
 13                       from user_tab_columns where table_name = p_tname)
 14      loop
 15          l_decode_1 := l_decode_1 || ', ' || x.column_id || ', ''' || x.column_name || '''';
 16          l_decode_2 := l_decode_2 || ', ' || x.column_id || ', ''' || x.data_type || '''';
 17          l_decode_3 := l_decode_3 || ', ' || x.column_id || ', ' || x.fcname ;
 18      end loop;
 19      l_decode_1 := l_decode_1 || ') cname, ';
 20      l_decode_2 := l_decode_2 || ') dtype, ';
 21      l_decode_3 := l_decode_3 || ') value';
 22
 23      l_stmt := l_stmt || l_decode_1 || l_decode_2 || l_decode_3 || ' from ' || p_tname ||
 24      ', (select rownum r from user_tab_columns where table_name = :x )';
 25      open p_cursor for l_stmt using p_tname;
 26  end;
 27  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> show errors
No errors.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> drop table emp;
 
Table dropped.
 
ops$tkyte@ORA9IR2> create table emp as select * from scott.emp;
 
Table created.
 
ops$tkyte@ORA9IR2> variable x refcursor
ops$tkyte@ORA9IR2> exec all_distinct_values( 'EMP', :x );
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> print x
 
CNAME    DTYPE    VALUE
-------- -------- ----------------------------------------
COMM     NUMBER   0
COMM     NUMBER   1400
COMM     NUMBER   300
COMM     NUMBER   500
COMM     NUMBER
DEPTNO   NUMBER   10
DEPTNO   NUMBER   20
......
 

Would you please explain this stored procedure?

September 02, 2004 - 5:44 pm UTC

Reviewer: Vipul from NY

This is so cool - Would you please explain this stored procedure line by line so that those who are not that familiar with some of these techniques will be benefited?

I read close to 50+ queries and responses today - I never so this kind of technical resources anywhere else. Thanks Tom.

Vipul

Tom Kyte

Followup  

September 03, 2004 - 9:35 am UTC

ops$tkyte@ORA9IR2> create or replace procedure prt ( p_str in varchar2 )
  2  is
  3     l_str   long := p_str;
  4  begin
  5     loop
  6        exit when l_str is null;
  7        dbms_output.put_line( substr( l_str, 1, 250 ) );
  8        l_str := substr( l_str, 251 );
  9     end loop;
 10  end;
 11  /
 
Procedure created.


if we add a prt call to the procedure, you see what it does:

ops$tkyte@ORA9IR2> exec all_distinct_values( 'EMP', :x );
select distinct decode( r, 1, 'EMPNO', 2, 'ENAME', 3, 'JOB', 4, 'MGR', 5,
'HIREDATE', 6, 'SAL', 7, 'COMM', 8, 'DEPTNO') cname, decode( r, 1, 'NUMBER', 2,
'VARCHAR2', 3, 'VARCHAR2', 4, 'NUMBER', 5, 'DATE', 6, 'NUMBER', 7, 'NUMBER', 8,
'NUMBER') dtype,
decode( r, 1, to_char(EMPNO ), 2, ENAME, 3, JOB, 4, to_char(MGR ), 5,
to_char(HIREDATE, 'yyyymmddhh24miss' ), 6, to_char(SAL ), 7, to_char(COMM ), 8,
to_char(DEPTNO )) value from EMP, (select rownum r from user_tab_columns where
table_name = :x )


it (the procedure) doesn't do much, the query does all of the work.

All we do is build a 3 column query.  We'll start at the end though -- the cartesian product.

Basically, we want to take each row in EMP and output it once for each column in that row.  (eg: emp has 8 columns -- the first row in emp should be output 8 times -- once for each column).  We use rownum R from user_tab_columns for that -- we KNOW user_tab_columns will have *at least* enough rows since it has a row/column.

Then, we output three columns:

column 1 -- is going to be the column name.  The first time we output row 1, we'll pump out "EMPNO", the second time we output row 1 -- ENAME and so on.

column 2 -- the datatype, I'm assuming the application would want this

column 3 -- the value -- taking care to convert everything to a "string" and taking extra care with dates. 

Is there a limit of records that the variable x can hold?

September 02, 2004 - 5:50 pm UTC

Reviewer: R from NJ

Tom:
Thanks a lot for the solution. This is exactly what I was looking for.

If the table has several million records, do u think the variable can hold that many records or is there a limit?

R


Tom Kyte

Followup  

September 03, 2004 - 9:36 am UTC

you will exceed your end users patience well before you exceed an Oracle result set (eg: it is just a query, a cursor, a result set -- it is not a "variable holding data in memory" really)

How do we get this data in a sorted order - desc or asc

September 02, 2004 - 7:03 pm UTC

Reviewer: Alex from CA

Tom - How can get the result set in a sorted order - asc or desc order?



Tom Kyte

Followup  

September 03, 2004 - 9:37 am UTC

add an order by ?

order by clause

September 07, 2004 - 1:40 pm UTC

Reviewer: vipul from NY

Tom - would you please point me in the stored procedure where I can put that order by <column_name> clause? so that the data will be in a sorted order. somehow I couldnt figure this out and I am getting compilation error.

Tom Kyte

Followup  

September 07, 2004 - 2:25 pm UTC

umm, it is just a "sql query"? order by's go on the end of it.

suggest you print it out (like I did), cut and paste it, add the order by (to get the syntax correct) and modify the code.

you probably just want to add:

order by 1, 3

to the end of the query to order by column name and within a column name by the values.

please take a look at it

September 07, 2004 - 2:54 pm UTC

Reviewer: vipul from NY

Tom:
Here is what I have done and still its giving me error when I execute the query. I have made the changes where we create the statement. Please help to resolve this issue.

What I am looking for is that the value field sorted and grouped by column name


create or replace procedure all_distinct_values( p_tname in
varchar2, p_cursor in out sys_refcursor )
as
l_stmt long := 'select distinct ';
l_decode_1 long := 'decode( r';
l_decode_2 long := 'decode( r';
l_decode_3 long := 'decode( r';
begin
for x in (select column_id, data_type, column_name,
decode( data_type, 'DATE', 'to_char(' || column_name
|| ', ''yyyymmddhh24miss'' )',
'NUMBER', 'to_char(' || column_name
|| ' )',
column_name) fcname
from user_tab_columns where table_name = p_tname)
loop
l_decode_1 := l_decode_1 || ', ' || x.column_id || ', ''' ||
x.column_name || '''';
l_decode_2 := l_decode_2 || ', ' || x.column_id || ', ''' ||
x.data_type || '''';
l_decode_3 := l_decode_3 || ', ' || x.column_id || ', ' || x.fcname
;
end loop;
l_decode_1 := l_decode_1 || ') cname, ';
l_decode_2 := l_decode_2 || ') dtype, ';
l_decode_3 := l_decode_3 || ') value';

l_stmt := l_stmt || l_decode_1 || l_decode_2 || l_decode_3 || ' from '
|| p_tname || ' order by 1, 3 ' ||
', (select rownum r from user_tab_columns where table_name = :x)';
open p_cursor for l_stmt using p_tname;
end;



Tom Kyte

Followup  

September 07, 2004 - 3:00 pm UTC

order by's go AT THE END OF A QUERY.


you have


... from TABLE order by 1, 3 , ( select rownum r from user....)


please -- take a second to take a look at these things. If you were to have printed this out on your screen, it might have been forehead smacking "obvious"?




prt procedure and its use

September 07, 2004 - 3:00 pm UTC

Reviewer: keshav from Chennai, India

How do you make a prt call to the procedure? Or how did you get the detailed view of the proecedure that you wrote when you explained the procedure?


Tom Kyte

Followup  

September 07, 2004 - 3:01 pm UTC

the code to prt is given along with the "detailed view" above?

There is a strange behaviour with SAL column?

September 07, 2004 - 3:52 pm UTC

Reviewer: vipul from NY

Tom - Attached is the updated procedure. I have tried with the SCOTT.EMP table and I got the result correctly except the last column "SAL". There two values out of order and the rest looks good. This is the results that I got with the SAL COLUMN - The first two rows in this result set is not sorted in the right way.

SAL NUMBER 950
SAL NUMBER 800
SAL NUMBER 5000
SAL NUMBER 3000
SAL NUMBER 2975

CNAME DTYPE VALUE
-------- -------- ---------
SAL NUMBER 2850
SAL NUMBER 2450
SAL NUMBER 1600
SAL NUMBER 1500
SAL NUMBER 1300
SAL NUMBER 1250
SAL NUMBER 1100

Modified procedure - sorry for my mistakes in the prev query
create or replace procedure all_distinct_values( p_tname in
varchar2, p_cursor in out sys_refcursor )
as
l_stmt long := 'select distinct ';
l_decode_1 long := 'decode( r';
l_decode_2 long := 'decode( r';
l_decode_3 long := 'decode( r';
begin
for x in (select column_id, data_type, column_name,
decode( data_type, 'DATE', 'to_char(' || column_name
|| ', ''yyyymmddhh24miss'' )',
'NUMBER', 'to_char(' || column_name
|| ' )',
column_name) fcname
from user_tab_columns where table_name = p_tname)
loop
l_decode_1 := l_decode_1 || ', ' || x.column_id || ', ''' ||
x.column_name || '''';
l_decode_2 := l_decode_2 || ', ' || x.column_id || ', ''' ||
x.data_type || '''';
l_decode_3 := l_decode_3 || ', ' || x.column_id || ', ' || x.fcname
;
end loop;
l_decode_1 := l_decode_1 || ') cname, ';
l_decode_2 := l_decode_2 || ') dtype, ';
l_decode_3 := l_decode_3 || ') value';

l_stmt := l_stmt || l_decode_1 || l_decode_2 || l_decode_3 || ' from '
|| p_tname ||
', (select rownum r from user_tab_columns where table_name = :x ) order by 1,3 desc ';
open p_cursor for l_stmt using p_tname;
end;





Tom Kyte

Followup  

September 07, 2004 - 3:59 pm UTC

because everything is sorted "as a string"

so, use:

24 ', (select rownum r from user_tab_columns where table_name = :x )
25 order by 1,
26 decode( dtype, ''NUMBER'', null, value ),
27 decode(dtype, ''NUMBER'', to_number(value) )';
28 open p_cursor for l_stmt using p_tname;
29 end;
30 /


to order by cname and if a string/date (dates are sortable as encoded) then by that, else by to_number of the number...



where clause

September 08, 2004 - 2:11 am UTC

Reviewer: karthick from india

i have two tables sl_master and br_master
both have a field sub_code.

sl_master --> sub_code -- type is char(6)

br_master --> sub_code -- type is char(10)

i gave the join condition,

"where sl_master.sub_code = br_master.sub_code"

but it is not equating properly.

but when i gave the conditin as

"where trim(sl_master.sub_code) = trim(br_master.sub_code)"

it works fine.

the data in both the tables sub_code field are "CLNT01".

Why is it so.


Tom Kyte

Followup  

September 08, 2004 - 9:32 am UTC

oh, it is equating "properly"

but the facts of life are

'KING ' <> 'KING '
^^ ^^^^^^

i despise the char(n) type -- a char(n) is nothing more than a varchar2(n) with trailing blanks.

you should never use char.


In your case, you are doing to want to trim OR rpad one or the other - but not both.


say you have

from S, B
where s.something = :x
and s.sub_code = b.sub_code


here, you probably use an index on something to find S rows and you want to then use the index on b(sub_code) to find the related B rows. so, you should apply the function to S.sub_code:


from S, B
where s.something = :x
and rpad( s.sub_code, 10 ) = b.sub_code


so the indexes on s(something) and b(sub_code) can be used.

conversely:


from S, B
where b.something = :x
and s.sub_code = b.sub_code


would lead me towards:



from S, B
where b.something = :x
and s.sub_code = trim(b.sub_code)

instead


if you have:


from S, B
where s.something = :x
and b.something_else = :y
and s.sub_code = b.sub_code

well, then YOU pick one or the other.


But, I would encourage you to change your char's to varchar2's if you are still in design mode.




To karthick

September 08, 2004 - 9:21 am UTC

Reviewer: Marco van der Linden from The Netherlands

Because of the datatypes..........

> sl_master --> sub_code -- type is char(6)
> br_master --> sub_code -- type is char(10)

.....the join condition

"where sl_master.sub_code = br_master.sub_code"

equates to 'CLNT01' = 'CLNT01 '
which is obviously not equal.
If the datatypes would have been VARchar(n)

"where sl_master.sub_code = br_master.sub_code"

would return a result, UNLESS the value inserted into br_master.sub_code had been 'CLNT01 '

why so...

September 08, 2004 - 11:06 am UTC

Reviewer: P.Karthick from India

is there any specific reason for having that difference between char and varchar2.....

Tom Kyte

Followup  

September 08, 2004 - 1:00 pm UTC

because it is what makes a CHAR a CHAR -- it is a fixed length character string padded out with blanks (the standard bodies said so)...



Strange Result Showing up while executing a Query

September 13, 2004 - 10:35 am UTC

Reviewer: Sujit from India

Dear Tom,
     I am executing the query "select * from scott.emp where (1 = 0 or empno = 7369) and 1 = 0;" in Oracle "Oracle9i Enterprise Edition Release 9.2.0.1.0". But it's faching one row where as it should fetch none as "1 = 0" shouls always be evaluated to FALSE.

SQL> select * from scott.emp where (1 = 0 or empno = 7369) and 1 = 0;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20

SQL> 


Kindly Advice.....

Regards...
Sujit 

Tom Kyte

Followup  

September 13, 2004 - 1:09 pm UTC

Oracle9i Enterprise Edition Release 9.2.0.5.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.5.0 - Production

scott@ORA9IR2> select * from scott.emp where (1 = 0 or empno = 7369) and 1 = 0;

no rows selected

scott@ORA9IR2> alter session set optimizer_goal=first_rows;

Session altered.

scott@ORA9IR2> select * from scott.emp where (1 = 0 or empno = 7369) and 1 = 0;

no rows selected


I cannot reproduce.... please contact support for this one.

faster way to select distinct records?

September 13, 2004 - 6:39 pm UTC

Reviewer: celia Wang from USA

Table t1(c1 NUMBER)
C1
1
2

Table t2 (c1, number, c2 char(1), c3 varchar2(5))

C1 C2 C3
1 Y M1
1 Y M2
1 N M3
2 Y A1
2 N A2

The relationship t1 and t2 is one to many through t1.c1 = t2.c1

The purpose is to query all rows in table t1 when t2.c2 = ‘Y’

Select DISTINCT t1.c1
From t1, t2
Where t1.c1 = t2.c1
And t2.c3 = ‘Y’

If I have million of row in table t1, this query runs very slow. So, “distinct” is very expensive performance.

Select t1.c1
From t1,
(select distinct c1, c2 from t2
where c2= ‘Y’) a
where t1.c1 = a.c1

By using embedded SQL, the elapsed time has been decreased by 50%.

Do you have any better way to accomplish the same result?

Thanks a lot.


Tom Kyte

Followup  

September 13, 2004 - 9:08 pm UTC

it would have been natural to use "in"

select c1 from t1 where c1 in ( select c1 from t2 where c2 = 'Y' );



To Sujit

September 13, 2004 - 9:22 pm UTC

Reviewer: A reader

You used 92010, Tom used 92015. Perhaps this is a bug
fixed in a patchset?

Strange Cases in Oracle 9i (9.2.0.1.0)

September 14, 2004 - 5:00 am UTC

Reviewer: Sujit from India

Yes i Also think it's some kind of Bug with 9.2.0.1.0 vertion.



SQL*Plus: Release 9.0.1.0.1 - Production on Tue Sep 14 14:09:24 2004

(c) Copyright 2001 Oracle Corporation.  All rights reserved.


Connected to:
Oracle9i Enterprise Edition Release 9.2.0.1.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.1.0 - Production

SQL> set lin 2000
SQL> select * from scott.emp where (1 = 0 or empno = 7369) and 1 = 0;

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20

SQL> 


    Anyways thanks TOM for your reply.

Regards...
Sujit
 

Doubts / Error in Group By

September 20, 2004 - 9:42 am UTC

Reviewer: Udanks from India

Hi Tom,


I have a table supplier which has supplier ID and Supplier Name. I have another table Order_formats which has Order_ID - which is unique for every order placed and Order_XML which holds all the information regarding the order placed. When I run the following query 

SELECT T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal(),
--s.supplier_name,
--formats.order_id,
COUNT(DISTINCT(formats.order_id)) OrderCount,
COUNT(formats.order_id) ItemCount,
--T.extract('/ItemOut/Components/ExtendedPriceFloat/text()').getNumberVal() ItemPrice,
SUM(T.extract('/ItemOut/Components/ExtendedPriceFloat/text()').getNumberVal()) ItemTotal
FROM ORDER_FORMATS1 formats,
TABLE(XMLSEQUENCE(EXTRACT(order_xml,'//ItemOut'))) T,
SUPPLIERS s
WHERE T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()
= s.supplier_id (+)
GROUP BY T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()
ORDER BY
T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()

which is correct answer.

SUP_ID
-----------------------------------------
ORDERCOUNT  ITEMCOUNT  ITEMTOTAL
---------- ---------- ----------
000072
         2          2        1.1

054054
         1          1        200

30000072
         4          4      73.15

30054054
         1          1      -77.5

30068737
         1          1       89.9

30361119
         1          1      65.25

But when I try to add supplier_name, order_id,

  1  SELECT T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal() Sup_ID,
  2  s.supplier_name,
  3  formats.order_id,
  4  COUNT(DISTINCT(formats.order_id)) OrderCount,
  5  COUNT(formats.order_id) ItemCount,
  6  T.extract('/ItemOut/Components/ExtendedPriceFloat/text()').getNumberVal() ItemPrice,
  7  SUM(T.extract('/ItemOut/Components/ExtendedPriceFloat/text()').getNumberVal()) ItemTotal
  8  FROM ORDER_FORMATS1 formats,
  9  TABLE(XMLSEQUENCE(EXTRACT(order_xml,'//ItemOut'))) T,
 10  SUPPLIERS s
 11  WHERE T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()
 12  = s.supplier_id (+)
 13  GROUP BY T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()
 14  ORDER BY
 15* T.extract('/ItemOut/ItemID/SupplierPartID/text()').getStringVal()
SQL> /
s.supplier_name,
*
ERROR at line 2:
ORA-00979: not a GROUP BY expression


Where I am going wrong ... plz do let me know. 

Tom Kyte

Followup  

September 20, 2004 - 10:41 am UTC

seems self explainatory?

It is still such a bummer you've taken the worlds most structured problem ever -- Orders and Line Items -- and made it "really cool" via XML.

look at your query, you have the equivalent of:


select a, b, c
from t
group by a

what about B? what about C? any column that is not aggregated would have to be grouped by.

sql joins

September 22, 2004 - 12:30 am UTC

Reviewer: Ishaque Hussain from Fords, NJ USA

I have heard that doing a what I call "loop join" is not a good practice in sql. What I am referring to here is having three tables x,y,z. x is joined to y, y is joined to z and x is joined to z. I know that the design should change but in this case, I can't change the design. However, in terms of data I need to join one of the columns in table x with one of the columns in z. Is it a bad idea to have this type of "loop join".
I have done tests on my personal oracle and the result sets that I am getting using this so called "loop join" are correct. I just wanted to get your opinion on this one.



SELECT DISTINCT
HDR.HDR_NUM,
ITEM.INVC_NO,
ITEM.INVC_DT,
ITEM.PROD_CD,
HDR.DM_NO,
TRCG.DM_NO,
DISTRNO
FROM HDR, --this is x
ITEM, --this is y
TRCG --this is z
WHERE HDR.HDR_NUM = ITEM.HDR_NUM
AND ITEM.INVC_NO = TRCG.INVC_NO
AND ITEM.INVC_DT = TRCG.INVC_DT
AND ITEM.PROD_CD = TRCG.PROD_CD
AND HDR.DM_NO = TRCG.DM_NO


Thanks,

Ishaque

Tom Kyte

Followup  

September 22, 2004 - 7:45 am UTC

umm, you heard wrong. where have you heard that normalization (which is what you've basically done here) is "wrong"?

You should use the CBO for sure, it'll be brutally efficient and full scan the three tables, hash joining them.

question for you -- are you sure that distinct is necessary -- not possible to tell from where I sit, but are you sure you need it?

sql query

September 22, 2004 - 2:35 pm UTC

Reviewer: Ishaque Hussain from Fords, NJ USA

I have actually ran the query and it is efficient(I actually have parameters which I didn't include here) and you are correct in that I don't need the distinct. I like normalization and I like to use it as well. My concern was having what I call the "loop" (I made this terminology up so I can have a name for what I was trying to describe). "Normally" in a situation like this x would be joined to y, and y would be joined to z. However, in this situation, I am joing z back to x because of that dm_no column which would "close the circuit". I didn't see anything wrong with this. I have done a report and I didn't do the hdr to trcg (x to z join) because somebody mentioned it wasn't a good idea. Lesson learned, don't always listen to others instead try it for yourself first.


Thanks,

Ishaque





How to write this query

September 24, 2004 - 10:52 am UTC

Reviewer: A reader

CREATE TABLE DTAB( DKEY NUMBER(10))
/

CREATE TABLE IDTAB(DKEY NUMBER(10),
AAFLAG VARCHAR2(1))
/



INSERT INTO DTAB VALUES(1)
/
INSERT INTO DTAB VALUES(2)
/
INSERT INTO DTAB VALUES(3)
/
INSERT INTO DTAB VALUES(4)
/
INSERT INTO DTAB VALUES(5)
/


INSERT INTO IDTAB VALUES(1,'Y')
/
INSERT INTO IDTAB VALUES(2, 'Y')
/
INSERT INTO IDTAB VALUES(2,'N')
/
INSERT INTO IDTAB VALUES(3, 'Y')
/
INSERT INTO IDTAB VALUES(3,'N')
/
INSERT INTO IDTAB VALUES(4,'N')
/


My requirement is to

1.select those dkey's in idtab table where for a given dkey the aaflag is 'Y' or both 'Y' and 'N'
2.do not select those dkeys where aaflag is just 'N' for a given dkey
3.select all those dkeys which are in dtab table and are not in idtab table.

Please help

Tom Kyte

Followup  

September 24, 2004 - 12:05 pm UTC

select distinct dkey from idtab where aaflag = 'Y'

gets 1 & 2 ok.


3) seems to be another query?? for we are back to the full idtab again? that would be

select * from dtab where dkey not in ( select dkey from idtab );

September 24, 2004 - 12:20 pm UTC

Reviewer: A reader

Well, Tom how can you combine the above two ?

Tom Kyte

Followup  

September 24, 2004 - 12:34 pm UTC

i have no idea, they are asking two different questions.

Merging 2 Queries!

October 12, 2004 - 11:50 pm UTC

Reviewer: A reader

Hi Tom,

Welcome back!

I have the following queries:

SELECT Z.location_nme,A.Candidate_Name, A.IVR
FROM IVR as A , gctlocation as Z
WHERE A.gctlocation_srl = Z.srl;

location_nme | candidate_name | ivr
--------------+----------------+-----
NT | Bob Benger | 1
NS | Bob Benger | 1
BC | Bob Benger | 1
NS | Bob Eisen | 1
ON | Bob Langer | 1
NT | Bob McNamara | 1
(6 rows)


SELECT Z.location_nme,B.Candidate_Name, B.WEB
FROM web as B , gctlocation as Z
WHERE B.gctlocation_srl = Z.srl;
location_nme | candidate_name | web
--------------+----------------+-----
NB | Bob Redmond | 2
NS | Bob Benger | 2
ON | Bob Langer | 4
YK | Bob Burke | 1
NT | Bob Cobban | 1
(5 rows)

I want to merge them and have a result set as follow:

location_nme | candidate_name | ivr |web
--------------+----------------+-----+-----
NT | Bob Benger | 1 |
NS | Bob Benger | 1 |2
BC | Bob Benger | 1 |
NS | Bob Eisen | 1 |
ON | Bob Langer | 1 |4
NT | Bob McNamara | 1 |
NB | Bob Redmond | |2
YK | Bob Burke | 1
NT | Bob Cobban | 1
..............
.............
The order, doesn't mattar. Just showing in one line for the same 'location_nme' and 'candidate_nme' is important. (e.g NS , Bob Benger )

How can I do this? Could you please help me on this?

Thank you so much for your help.
- Arash

P.S. I tried to use in-line views or outer join, but everytime I missed some records!


Tom Kyte

Followup  

October 13, 2004 - 8:08 am UTC



select location_nme, candidate_name, max(ivr), max(web)
from ( SELECT Z.location_nme,A.Candidate_Name, A.IVR, to_number(null) web
FROM IVR as A , gctlocation as Z
WHERE A.gctlocation_srl = Z.srl
union all
SELECT Z.location_nme,B.Candidate_Name, to_number(null), B.WEB
FROM web as B , gctlocation as Z
WHERE B.gctlocation_srl = Z.srl )
group by location_name, candidate_name;


Thank you so much! You are great!

October 13, 2004 - 10:10 am UTC

Reviewer: A reader


How can I have max(ivr)+max(web) as Total?

October 13, 2004 - 12:18 pm UTC

Reviewer: A reader

Hi Tom,

I don't know why this doesn't work:

select location_nme, candidate_name, max(ivr), max(web), max(web)+max(ivr) as total
from ( SELECT Z.location_nme,A.Candidate_Name, A.IVR, to_number(null) web
FROM IVR as A , gctlocation as Z
WHERE A.gctlocation_srl = Z.srl
union all
SELECT Z.location_nme,B.Candidate_Name, to_number(null), B.WEB
FROM web as B , gctlocation as Z
WHERE B.gctlocation_srl = Z.srl )
group by location_name, candidate_name;


It may be because of 'NULL' values in each subqueries.

Please let me know how I can do this?

Thank you again,
- Arash


October 13, 2004 - 1:32 pm UTC

Reviewer: A reader

Tom,

I used NVL and it fixed the problem.

Thanks


Where would we be without Tom?

October 20, 2004 - 10:55 pm UTC

Reviewer: Ben Ballard from Boston (on-site at a client in Pennsylvania this week)

Tom,

Here I am alone in the office at 10:30pm, missing the ALCS Game 7, trying to correct some truly horrible code and save a project. I'm working day and night so that maybe I won't have to be away from my wife again next week. Once again, I've found the answer to my problem here at asktom. It is in these moments, in the clutch, that your site is most indispensible and that you are most appreciated. Thank you.

character mode reports on windows xp

October 28, 2004 - 8:24 am UTC

Reviewer: siddartha m.s from indian

hello sir
i need to know how to print character mode reports on windows xp please send the solution as soon as posible
thanking you
siddartha




Passing value to a procedure.

December 04, 2004 - 2:31 am UTC

Reviewer: karthick from india

hai tom,

I have a front end form that downloads data form a excel file. the data in the file has a number of client code.
and i have used a oracle stored procedure that does some process with those client code. each client code is of 15 characters. at every download i get a minimum of 500 client code.

is there any way that i can send all the client code to that procedure as an arguement at one shot. i dont want to call the procedure in a loop as we are using a three tire consept.

i tryed to pad the client code into a string and send it as an arguement. but most of the time it exceeds the size of varchar2 and i get error.

can you please help me with this.

Thank you

karthick.

Tom Kyte

Followup  

December 04, 2004 - 10:59 am UTC

well, you can send 2047 of them in a single string (a varchar2 is 32k in plsql)

but you want to read the docs for whatever language you are using. it would sort of depend on that don't you think. I mean, the solution I would use for java would be slightly different than VB.

(and unless it is an open language, one that runs on more than a single OS, you'll have to ask around, i only use things that work on linux/unix in addition to that os that shall not be named)

passing arguement to procedure

December 05, 2004 - 11:42 pm UTC

Reviewer: karthick from india

ok let me put it in this way,

the fornt end language can store x characters in a vairable. i need y such variables to store.this y is unknown and determined only at run time. so is it possible to pass that y variables to my stored procedure as arguement.y can be 1,2,3....

Tom Kyte

Followup  

December 06, 2004 - 11:23 am UTC


Ok, let me put it this way:

YES

there are collections, there are plsql table types. how you use them depends on the client language you are programming in (as stated)

Order by clause

December 22, 2004 - 4:21 pm UTC

Reviewer: Laxman Kondal from Springfield, VA

Hi Tom

How can I use order by in procedure to return ref cursor.
This one has no effect. I used string also as cloumn name.

scott@ORA9I> CREATE OR REPLACE PROCEDURE P(p_list NUMBER, p_rc OUT sys_refcursor)
2 AS
3 BEGIN
4 OPEN p_rc FOR SELECT EMPNO, ENAME, JOB MGR FROM Emp ORDER BY p_list;
5 END;
6 /

Procedure created.

scott@ORA9I> var cur refcursor
scott@ORA9I> set autoprint on
scott@ORA9I> exec p(2, :cur)

PL/SQL procedure successfully completed.


EMPNO ENAME JOB MGR
---------- ---------- --------- ----------
7369 SMITH CLERK 7902
7499 ALLEN SALESMAN 7698
7521 WARD SALESMAN 7698
7566 JONES MANAGER 7839
7654 MARTIN SALESMAN 7698
7698 BLAKE MANAGER 7839
7782 CLARK MANAGER 7839
7788 SCOTT ANALYST 7566
7839 KING PRESIDENT
7844 TURNER SALESMAN 7698
7876 ADAMS CLERK 7788
7900 JAMES CLERK 7698
7902 FORD ANALYST 7566
7934 MILLER CLERK 7782

14 rows selected.


scott@ORA9I>

Is there any way this proc can accept order by as IN parameter and do the order by.

Thanks and regards.

Tom Kyte

Followup  

December 22, 2004 - 6:54 pm UTC

it absolutely has an effect, it is just like:

select empno, ename, job mgr from emp order by '2';


you could do this:

select empno, ename, job, mgr from emp
order by decode(p_list,1,empno),
decode(p_list,2,ename),
decode(p_list,3,job),
decode(p_list,4,mgr);




Order by clause

December 22, 2004 - 4:43 pm UTC

Reviewer: Laxman Kondal from Springfield, VA

Hi Tom

If I use:

OPEN p_rc FOR SELECT empno, ename, job FROM Emp ORDER BY DECODE(p_list, 2, ename, 3, job);

then it works:

scott@ORA9I> exec p(2, :rc)

PL/SQL procedure successfully completed.


EMPNO ENAME JOB
---------- ---------- ---------
7876 ADAMS CLERK
7499 ALLEN SALESMAN
7698 BLAKE MANAGER
7782 CLARK MANAGER
7902 FORD ANALYST
7900 JAMES CLERK
7566 JONES MANAGER
7839 KING PRESIDENT
7654 MARTIN SALESMAN
7934 MILLER CLERK
7788 SCOTT ANALYST
7369 SMITH CLERK
7844 TURNER SALESMAN
7521 WARD SALESMAN

14 rows selected.

scott@ORA9I> exec p(3, :rc)

PL/SQL procedure successfully completed.


EMPNO ENAME JOB
---------- ---------- ---------
7788 SCOTT ANALYST
7902 FORD ANALYST
7369 SMITH CLERK
7876 ADAMS CLERK
7934 MILLER CLERK
7900 JAMES CLERK
7566 JONES MANAGER
7782 CLARK MANAGER
7698 BLAKE MANAGER
7839 KING PRESIDENT
7499 ALLEN SALESMAN
7654 MARTIN SALESMAN
7844 TURNER SALESMAN
7521 WARD SALESMAN

14 rows selected.

scott@ORA9I>

IS there any better way and can take more then one order by in one parameter?

Thanks for help.
Regards


Tom Kyte

Followup  

December 22, 2004 - 6:56 pm UTC

see above.

Order by Value || Asc / Desc dynamically

December 23, 2004 - 8:27 am UTC

Reviewer: Vaishnavi from India

Hi Tom,

How to get data Asc or Desc dynamically? (Order by column is fixed)

I tried this query:

select * from t order by qty || (select decode(:x, 'A', 'Asc', 'Desc' from dual);

But its not giving the data as desired or not throwing any error.

Can I do this?

Sincerely
Vaishnavi

Tom Kyte

Followup  

December 23, 2004 - 11:28 am UTC

why would it throw an error, not any different than:


select * from t order by qty || 'asc';


that is perfectly valid.


select * from t order by
case when :x = 'A' then qty end ASC,
case when :x <> 'A' then qty end DESC;

just like above for multiple columns........ variation on a theme

I want to make oracle take same amount of time, while running same sql again

December 31, 2004 - 3:36 am UTC

Reviewer: Ashutosh from New Delhi, INDIA

I am facing some problem, while testing my code on development database. After some code enahncement, I want to match the time with earlier run, but it is unmatchable because of SGA. Running the same SQL 2nd or 3rd time takes, small time. So I am unable to perform real testing. How can I do that.

Tom Kyte

Followup  

December 31, 2004 - 11:05 am UTC

guess what -- you are in fact performing real testing!!!!!

in the "real world (tm)" would your cache ever be empty?
in the "real world (tm)" would you start from scratch each time?

what you need to do is vary the inputs into your query and model the real world.


(in the real world (tm), would you have a single user as you probably do now!!)

(and please -- no one tell how to flush the buffer cache, not in any release -- what a waste of time if you are using a buffered file system.......... an utter and complete waste of time)

non moving items report

February 02, 2005 - 5:34 am UTC

Reviewer: Dajani from UAE

Hi Tom
I am currently developing a report in Crystal connected to Maximo Database.
This report is suppose to generate all those items that where neither been issued nor received in another word no "transactions"

The problem is that I do have "last issue date" in my inventory master table. So I can say if isnull (inventory. last issuedate) but I can not follow that with and isnull (inventory. last receiveddate) then "non moving"
Because the last received date is not available in the inventory master table

How can I write an sql statement or formula to get the "last received date" from the inventory transactions table

no des bal cos tot lstissudte lstrecdte moving status

1 Baring 100 100 1,0000 ------- ----- non moving

Like I said the last issue date will show blank but last received date is not available in the master table .. if I can get the last received date to show NULL then the item is "a non moving item"



Thanks




Tom Kyte

Followup  

February 02, 2005 - 5:37 am UTC

"if isnull"? what is that, it isn't sql.

Efficient way to get counts

February 02, 2005 - 3:15 pm UTC

Reviewer: Thiru

Hi Tom,

What is an efficient way to get the counts from a table (around 10 million rows) based on varied conditions?

The actual table has around 50 columns.
drop table temp_del;
create table temp_del (c1 varchar2(3),c2 varchar2(3),c3 varchar2(3),c4 varchar2(3),flag number);
insert into temp_del values('abc','bcd','cde','def',0);
insert into temp_del values('abc','bcd','cde','def',1);
insert into temp_del values('abc','bcd','cde','def',2);

insert into temp_del values('bcd','cde','def','efg',0);
insert into temp_del values('bcd','cde','def','efg',1);
insert into temp_del values('bcd','cde','def','efg',2);

insert into temp_del values('cde','def','efg','fgh',0);
insert into temp_del values('cde','def','efg','fgh',1);
insert into temp_del values('cde','def','efg','fgh',2);
commit;

select count(*) from temp_del where c1='abc' and c2='bcd' and flag=0;
select count(*) from temp_del where c1='abc' and c2='bcd' and flag=1;
select count(*) from temp_del where c1='abc' and c2='bcd' and c3='efg' and flag=0;
select count(*) from temp_del where c1='abc' and c2='bcd' and c3='efg' and flag=1;
select count(*) from temp_del where c1='bcd' and c2='cde' and c3='def' and flag=2;
and so many other combinations similar to this..

Is there a way the table can be accessed once and get the varied counts like above?

Thanks a million.

Tom Kyte

Followup  

February 03, 2005 - 1:35 am UTC

need more info, is this table modified during the day or is this a warehouse.

is this example cut way down and there are 500 columns
or is this it.

is c1, c2, flag always involved,
or was that just a side effect of your example..

before anyone can suggest the "best way", details about how the data is used need to be known.

How to write this query - is this possible at all

February 03, 2005 - 8:12 pm UTC

Reviewer: Chenna



create table test5(
begdate date,
enddate date,
location varchar2(10),
status varchar2(10),
price varchar2(50) )
/

insert into test5 values('05-jan-05' , '31-jan-05' ,   'Expedite', 40000,   'A price of $6.89 flat rate')
/
insert into test5 values('01-feb-05' , '28-feb-05',     'Expedite', 1000 ,   'A price of $7.87 flat rate' )
/
insert into test5 values('05-mar-05' , '30-mar-05' ,   'Expedite', 40000,   'A price of $6.89 flat rate')
/

insert into test5 values ('01-dec-04', '31-dec-04', 'expedite',40000,'A price of $6.89 flat 

rate')

SQL> SELECT * FROM TEST5;

BEGDATE   ENDDATE   LOCATION   STATUS     PRICE
--------- --------- ---------- ---------- --------------------------------------------------
05-JAN-05 31-JAN-05 EXPEDITE   40000      A price of $6.89 flat rate
01-FEB-05 28-FEB-05 EXPEDITE   1000       A price of $7.87 flat rate
05-MAR-05 30-MAR-05 EXPEDITE   40000      A price of $6.89 flat rate
01-DEC-04 31-DEC-04 EXPEDITE   40000      A price of $6.89 flat rate

SQL> select min(begdate), max(enddate) , location, status, price
  2  from test5
  3  group by LOCATION ,STATUS,PRICE
  4  /

MIN(BEGDA MAX(ENDDA LOCATION   STATUS     PRICE
--------- --------- ---------- ---------- --------------------------------------------------
01-FEB-05 28-FEB-05 EXPEDITE   1000       A price of $7.87 flat rate
01-DEC-04 30-MAR-05 EXPEDITE   40000      A price of $6.89 flat rate

01-DEC-04 30-MAR-05 EXPEDITE   40000      A price of $6.89 flat rate row of out put is 

conveying wrong message, it is as if febraury is also for the price of 'A price of $6.89 flat 

rate' which is not the case

The output I'm looking for is

01-DEC-04 31-jan-05 EXPEDITE   40000      A price of $6.89 flat rate
01-FEB-05 28-FEB-05 EXPEDITE   1000       A price of $7.87 flat rate
05-MAR-05 30-MAR-05 EXPEDITE   40000      A price of $6.89 flat rate


Please help me write this query. Is this possible at all.
 

Tom Kyte

Followup  

February 04, 2005 - 1:50 am UTC

same concept as outlined here:

http://www.oracle.com/technology/oramag/oracle/04-mar/o24asktom.html

you might have to tweak for nulls of location/status/price is NULLABLE.


ops$tkyte@ORA9IR2> select min(begdate), max(enddate), location, status, price
  2    from (
  3  select begdate, enddate,
  4         location, status, price,
  5         max(grp) over (order by begdate) grp2
  6    from (
  7  select t.*,
  8         case when lag(location) over (order by begdate) <> location
  9                or lag(status) over(order by begdate) <> status
 10                or lag(price) over (order by begdate) <> price
 11                or row_number() over (order by begdate) = 1
 12              then row_number() over (order by begdate)
 13          end grp
 14    from t
 15         )
 16         )
 17   group by location, status, price, grp2
 18   order by 1;
 
MIN(BEGDA MAX(ENDDA LOCATION   STATUS     PRICE
--------- --------- ---------- ---------- ---------------------------
01-DEC-04 31-JAN-05 Expedite   40000      A price of $6.89 flat rate
01-FEB-05 28-FEB-05 Expedite   1000       A price of $7.87 flat rate
05-MAR-05 30-MAR-05 Expedite   40000      A price of $6.89 flat rate
 

showing parent -child relationship in a row joining with second table!

February 04, 2005 - 2:56 pm UTC

Reviewer: A reader

Hi Tom,

Sorry for my cause of confusion. This time I tried to make my question more understandable and readable. And I hope that I posted my question to the right thread this time.



CREATE TABLE DW_TBL_DIM_PRODUCT
(
SRL NUMBER(10) NOT NULL,
BRAND_DESC VARCHAR2(50)
)
/

Insert into DW_TBL_DIM_PRODUCT values (1, 'prd1');
Insert into DW_TBL_DIM_PRODUCT values (2, 'prd2');

CREATE TABLE DW_TBL_DIM_MARKET
(
SRL NUMBER(10) NOT NULL,
MARKET_DESC VARCHAR2(50),
MARKET_PAR_SRL VARCHAR2(30),
MARKET_PAR_DESC VARCHAR2(50),
MARKET_CLASS NUMBER(1),
MARKET_LEVEL NUMBER(1)
);




Insert into DW_TBL_DIM_MARKET values (1, 'PPPAB', null, null, 1, 0);
Insert into DW_TBL_DIM_MARKET values (6, 'PPA', 1, 'PPPAB', 1, 1);
Insert into DW_TBL_DIM_MARKET values (7, 'PPB', 1, 'PPPAB', 1, 1);
Insert into DW_TBL_DIM_MARKET values (12, 'PA', 6, 'PPA', 1, 2);
Insert into DW_TBL_DIM_MARKET values (13, 'PB', 7, 'PPB', 1, 2);
Insert into DW_TBL_DIM_MARKET values (20, 'A', 12, 'PA', 1, 3);
Insert into DW_TBL_DIM_MARKET values (21, 'B', 13, 'PB', 1, 3);


Insert into DW_TBL_DIM_MARKET values (2, 'PPEF', null, null, 2, 0);
Insert into DW_TBL_DIM_MARKET values (8, 'PEF', 2, 'PPEF', 1, 1);
Insert into DW_TBL_DIM_MARKET values (14, 'E', 8, 'PEF', 1, 2);
Insert into DW_TBL_DIM_MARKET values (15, 'F', 8, 'PEF', 1, 2);


CREATE TABLE DW_TBL_PRODUCT_MARKET
(
FK_DIM_PRODUCT NUMBER(10) NOT NULL,
FK_DIM_MARKET NUMBER(10) NOT NULL
);

Insert into DW_TBL_PRODUCT_MARKET values (1,20);
Insert into DW_TBL_PRODUCT_MARKET values (2,21);

SELECT
LPAD(' ',10*(LEVEL-1)) || market_desc market_tree
FROM dw_tbl_dim_market
START WITH market_desc = 'PPPAB'
CONNECT BY PRIOR srl = market_par_srl;

MARKET_TREE
----------------------------------------------
PPPAB
PPA
PA
A
PPB
PB
B
7 rows selected.

*Now my question is how I can show the result in two rows than 7 rows including the products like this:


1 PPPAB PPA PA A prd1
1 PPPAB PPB PB B prd2


Many thanks for your time,
Elahe


February 07, 2005 - 10:50 am UTC

Reviewer: A reader

Hi Sir,

Just have a question regarding previous posted question on Feb. 4th.

Is it really doable by just using SQL? Or have to use reporting tools?

Thanks



Tom Kyte

Followup  

February 07, 2005 - 11:14 am UTC

ops$tkyte@ORA9IR2> SELECT
  2      sys_connect_by_path(market_desc,' ' )
  3  FROM dw_tbl_dim_market     y
  4  where not exists ( select * from dw_tbl_dim_market x where x.market_par_srl = y.srl)
  5  START WITH market_desc = 'PPPAB'
  6  CONNECT BY PRIOR srl = market_par_srl
  7  /
 
SYS_CONNECT_BY_PATH(MARKET_DESC,'')
-------------------------------------------------------------------------------
 PPPAB PPA PA A
 PPPAB PPB PB B


start with that, not really knowing how the other stuff comes "along"....


also, in 10g, the where becomes "where connect_by_isleaf = 1" instead of a where exists. 

equi join in a query

February 08, 2005 - 12:23 pm UTC

Reviewer: Vapan

Tom,

If could find some time for this sql query for the results required:

create table TBL1(ty VARCHAR2(2),ID VARCHAR2(2),MID VARCHAR2(3),REM NUMBER);


insert into TBL1 values('S','C','ABC',1);
insert into TBL1 values('B','C','ABC',1);
insert into TBL1 values('S','L','BCD',1);
insert into TBL1 values('B','C','BCD',1);
insert into TBL1 values('S','D','CDE',1);
insert into TBL1 values('B','C','CDE',1);
insert into TBL1 values('S','C','DEF',1);
insert into TBL1 values('B','C','DEF',1);
insert into TBL1 values('S','L','EFG',1);
insert into TBL1 values('B','C','EFG',1);


SQL> SELECT * FROM TBL1;

TY ID MID        REM
-- -- --- ----------
S  C  ABC          1
B  C  ABC          1
S  L  BCD          1
B  C  BCD          1
S  D  CDE          1
B  C  CDE          1
S  C  DEF          1
B  C  DEF          1
S  L  EFG          1
B  C  EFG          1

RESULT REQUIRED WITH THE FOLLOWING CONDITIONS:

a)The result should not include ID='C' if it's TY='B' and its' contra ID='D'.
b)And the result should also not include where ID='C' and its contra ID='L'.

The contra id determined by the column MID. And every TY with value 'S' will 
have a corresponding TY with value 'B'. MID values' are same for each contra item.


RESULT REQUIRD FOR THE DATA ABOVE IS:

TY   ID  MID  REM

S     C  ABC    1
B     C  ABC    1
S     L  BCD    1
S     D  CDE    1
S     C  DEF    1
B     C  DEF    1
S     L  EFG    1

My attempt:

I could get only a part of this, but when I add the 'C' value for ID column, the query blows :

SELECT A1.MID,A1.TY,A1.ID,A1.REM
FROM
(
SELECT MID,TY,ID,REM FROM TBL1 
WHERE 
ID IN('L') AND REM=1 )A1,
(SELECT MID FROM TBL1 WHERE ID IN'C' AND REM=1) A2
WHERE A1.MID=A2.MID

MID TY ID        REM
--- -- -- ----------
BCD S  L           1
EFG S  L           1
 

Tom Kyte

Followup  

February 09, 2005 - 1:31 am UTC

looks like a new question some day, I have more questions than answers (reading this three times quick and I still didn't get it)

Date

February 09, 2005 - 9:05 am UTC

Reviewer: Andrea Maia Gaziola from Brasil

I need to make (trunc(sydate)-90) with field DATA_ABERTURA, as I must proceed?
SELECT DISTINCT DECODE(A.DIA_ABERTURA_DOC, '-1', ' ',
LPAD(A.DIA_ABERTURA_DOC, 2, '00') || '/' || LPAD(A.MES_ABERTURA_DOC, 2, '00') || '/' || A.ANO_ABERTURA_DOC) DATA_ABERTURA,
FROM BILHETE_ATIVIDADE A
,SGE_BA_SERV_ASSOC B
,ACIONAMENTO C
,ACIO_TECNICO_MICRO D
WHERE B.NUM_DOCUMENTO = A.NUM_DOCUMENTO
AND C.NUM_DOCUMENTO(+) = B.NUM_DOCUMENTO
AND D.NUM_DOCUMENTO(+) = C.NUM_DOCUMENTO
AND D.NUM_ACIONAMENTO(+) = C.NUM_ACIONAMENTO

Grateful

February 09, 2005 - 10:55 am UTC

Reviewer: Vapan

Tom,

Sorry for not being clear with the test case I gave above. The requirement is :

The query needs to do this:

a. Give all the records where ID='C' and REM=1 and also give it's contra record also ID= 'C' and REM=1 where MID for this pair of records is the same.
b. Give all the records where ID='L' and REM=1  but do not  give  its' contra record that is ID='C' and key is MID column value.
c. Give all the records where ID='D' and REM=1 but do not give its' contra record that is ID='C' (key is MID col value)

SQL> SELECT * FROM TBL1;

TY ID MID        REM
-- -- --- ----------
S  C  ABC          1
B  C  ABC          1
S  L  BCD          1
B  C  BCD          1
S  D  CDE          1
B  C  CDE          1
S  C  DEF          1
B  C  DEF          1
S  L  EFG          1
B  C  EFG          1




Expected REsult: (for the data above)

TY   ID  MID  REM

S     C  ABC    1
B     C  ABC    1
S     L  BCD    1
S     D  CDE    1
S     C  DEF    1
B     C  DEF    1
S     L  EFG    1

Thanks again for the time. 

Tom Kyte

Followup  

February 09, 2005 - 2:49 pm UTC

same answer as before, looks like a new question some day.

reader

February 10, 2005 - 11:54 pm UTC

Reviewer: A reader

I like to query v$database for name of the database and
dba_users to get the username.

If the username exists, the query must return the name
of the database and the username. If the username does
not exist, the query will return no rows

This is to cycle through all the ORACLE_SID from
oratab and find if username exists in any of the
databases in the server

Is it possible to construct a query like this

Tom Kyte

Followup  

February 11, 2005 - 7:56 pm UTC

sure, v$database has one row.

so, just join

select * from dba_users, v$database where dba_users.username = :x





SYSDATE

February 11, 2005 - 12:16 pm UTC

Reviewer: ANDREA MAIA GAZIOLA from Brasil

Tom,

I need to make (trunc(sydate)-90) with field DATA_ABERTURA, as I must proceed when the date (day, month and year) is in separate fields?
SELECT DISTINCT DECODE (A.DAY_DOC, '-1', ' ',
LPAD (A.DAY_DOC, 2, '00') || '/' || LPAD(A.MONTH_DOC, 2, '00') || '/' || A.YEAR_DOC) DATE_ OPENING
FROM BILHETE_ATIVIDADE A
,SGE_BA_SERV_ASSOC B
,ACIONAMENTO C
,ACIO_TECNICO_MICRO D
WHERE B.NUM_DOCUMENTO = A.NUM_DOCUMENTO
AND C.NUM_DOCUMENTO(+) = B.NUM_DOCUMENTO
AND D.NUM_DOCUMENTO(+) = C.NUM_DOCUMENTO
AND D.NUM_ACIONAMENTO(+) = C.NUM_ACIONAMENTO

I need its aid with urgency
Grateful.


Tom Kyte

Followup  

February 12, 2005 - 8:01 am UTC

<quote>
as I must proceed
when the date (day, month and year) is in separate fields?
</quote>

if you are asking me what is the most logical set of steps you should undertake when the above is true, the "most truthful" answer I can give you is:

find the person that did this, sign them up for database training. Then, fix the grievous error by taqking these three (maybe 6) fields and put them into one, the way they belong.


The answer you probably want is, you need to "to_date()" these three fields together and turn them into a date.

to_date( decode( a.day_doc,-1, NULL, a.month||'/'||a.day_doc||'/'||a.year_doc),
'mm/dd/yyyy' )

(i'm praying that they actually used YYYY -- 4 digits, don't know why I hold out hope, because they probably didn't, which means you really have a 2 character string with meaningless data in it... but anyway)

reader

February 11, 2005 - 2:03 pm UTC

Reviewer: A reader

The following query works without syntax error in SQL
select username,
CASE length(username)
when '' then ''
else (select name from v$database)
END
from dba_users where username = 'TEST19'

When used within unix shell script I get the error

1 select username,
2 CASE username
3 when '' then ''
4 else (select name from v$database)
5 END
6* from dba_users where username = 'TEST'
when '' then ''
*
ERROR at line 3:
ORA-00923: FROM keyword not found where expected

when the username does not exist in the database.



Tom Kyte

Followup  

February 12, 2005 - 8:24 am UTC

() would be shell special characters.

wait till you try <, > or || or ..............

actually, I'd guess that v$database is becoming v (unless you have an environment variable $database that is...)

but you give us nothing to work with, so we cannot suggest a fix, short of "maybe try putting "\" in front of shell special characters...

reader

February 12, 2005 - 10:45 am UTC

Reviewer: A reader

Your suggested query,

select username, (select name from v$database)
from dba_users where username = :x

works

Thanks.

As for my subsequent posting, I DID use \$
for v$database in the shell script. Not sure why
I got the error from the shell script. I'll look
further into it

Thanks

Tom Kyte

Followup  

February 12, 2005 - 12:48 pm UTC

because you didn't \( and \)



February 12, 2005 - 12:27 pm UTC

Reviewer: A reader

Hi Tom,
I have a requirment where I've to break all rows in table in 10 batches.We have a column batch_number in the table.
For e.g If I have 10 rows in a table, 1st row would have batch_number 1,2nd row would have batch_number 2 etc...If I have 1000 rows in a table then first 100 rows would in batch 1,next 200 rows would be in batch 2 etc...
How can I do this? Can I update this in a single udpdate statement?

Thanks

Tom Kyte

Followup  

February 12, 2005 - 1:01 pm UTC

I'd rather break the table into 10 pieces:

set echo off
                                                                                              
set verify off
define TNAME=&1
define CHUNKS=&2
                                                                                              
                                                                                              
select grp,
       dbms_rowid.rowid_create( 1, data_object_id, lo_fno, lo_block, 0 ) min_rid,
       dbms_rowid.rowid_create( 1, data_object_id, hi_fno, hi_block, 10000 ) max_rid
  from (
select distinct grp,
       first_value(relative_fno) over (partition by grp order by relative_fno, block_id
                   rows between unbounded preceding and unbounded following) lo_fno,
       first_value(block_id    ) over (partition by grp order by relative_fno, block_id
                   rows between unbounded preceding and unbounded following) lo_block,
       last_value(relative_fno) over (partition by grp order by relative_fno, block_id
                   rows between unbounded preceding and unbounded following) hi_fno,
       last_value(block_id+blocks-1) over (partition by grp order by relative_fno, block_id
                   rows between unbounded preceding and unbounded following) hi_block,
       sum(blocks) over (partition by grp) sum_blocks
  from (
select relative_fno,
       block_id,
       blocks,
       trunc( (sum(blocks) over (order by relative_fno, block_id)-0.01) /
              (sum(blocks) over ()/&CHUNKS) ) grp
  from dba_extents
 where segment_name = upper('&TNAME')
   and owner = user order by block_id
       )
       ),
       (select data_object_id from user_objects where object_name = upper('&TNAME') )
/

that'll give you 10 non-overlapping rowid ranges that cover the table (feed those into your batch process)


short of that, you'd be using "ntile" and merge.

ops$tkyte@ORA10G> create table t as select * from all_users;
 
Table created.
 
ops$tkyte@ORA10G> alter table t add nt number;
 
Table altered.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> merge into t
  2  using ( select rowid rid, ntile(10) over (order by username) nt from t ) t2
  3  on ( t.rowid = t2.rid )
  4  when matched then update set nt = t2.nt;
 
35 rows merged.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> select * from t order by nt;
 
USERNAME                          USER_ID CREATED           NT
------------------------------ ---------- --------- ----------
BI                                     63 19-DEC-04          1
ANONYMOUS                              43 10-AUG-04          1
CTXSYS                                 40 10-AUG-04          1
DBSNMP                                 22 10-AUG-04          1
DEMO                                   75 02-JAN-05          2
DMSYS                                  37 10-AUG-04          2
DIP                                    19 10-AUG-04          2
EXFSYS                                 32 10-AUG-04          2
LEAST_PRIVS                            68 02-JAN-05          3
HR                                     58 19-DEC-04          3
IX                                     60 19-DEC-04          3
MDDATA                                 49 10-AUG-04          3
OE                                     59 19-DEC-04          4
MGMT_VIEW                              56 10-AUG-04          4
MDSYS                                  36 10-AUG-04          4
OLAPSYS                                46 10-AUG-04          4
OPS$TKYTE                              80 17-JAN-05          5
ORDPLUGINS                             34 10-AUG-04          5
OUTLN                                  11 10-AUG-04          5
ORDSYS                                 33 10-AUG-04          5
PERFSTAT                               82 28-JAN-05          6
PM                                     62 19-DEC-04          6
SCOTT                                  57 10-AUG-04          6
SH                                     61 19-DEC-04          7
SYS                                     0 10-AUG-04          7
SI_INFORMTN_SCHEMA                     35 10-AUG-04          7
TEST                                   65 23-DEC-04          8
SYSMAN                                 54 10-AUG-04          8
SYSTEM                                  5 10-AUG-04          8
WKPROXY                                51 10-AUG-04          9
WKSYS                                  50 10-AUG-04          9
WK_TEST                                53 10-AUG-04          9
WSMGMT                                 81 28-JAN-05         10
XDB                                    42 10-AUG-04         10
WMSYS                                  23 10-AUG-04         10
 
35 rows selected.


(in 9i, you'd need to have a "when not matched then insert (nt) values ( null)" but it would basically be a big "no-operation" since all of the rows would in fact match....)

 

February 12, 2005 - 8:09 pm UTC

Reviewer: A reader

Excellent..Thanks tom.

February 12, 2005 - 8:26 pm UTC

Reviewer: A reader

Hi Tom,
We are using oracle 9i
You told
"in 9i, you'd need to have a "when not matched then insert (nt) values ( null)"
but it would basically be a big "no-operation" since all of the rows would in
fact match....)"

I didn't got that part..Could you please explain?

Thanks

Tom Kyte

Followup  

February 13, 2005 - 9:10 am UTC

in 9i, merge MUST have:

when matched then update ....
when not matched then insert ......



in 10g, you do not. So, in 9i there would have to be a "when not matched", but since we are joining the entire table with itself by rowid -- the "when not matched" clause would in fact never "happen", so you can just put a "dummy" insert in there -- that'll never actually happen

February 13, 2005 - 11:49 am UTC

Reviewer: A reader

Hi Tom,
I got it and implemented Merge statement to break the table into 10 batches..
Thanks a lot for the help


SYSDATE

February 15, 2005 - 11:52 am UTC

Reviewer: Andrea Maia Gaziola from Brasil

What I would like to know is as I use ((SYSDATE)-90) when the composition of the date this in different columns (day, month and year)


Tom Kyte

Followup  

February 15, 2005 - 3:37 pm UTC

huh? did not understand.

OK

February 17, 2005 - 12:05 pm UTC

Reviewer: Raju from Hyderabad,India

Hi Tom,
Please have a look at this query.

SQL> create table t(x int,y int)
  2  /

Table created.

SQL> insert into t select rownum,rownum+1 from cat where rownum 

<= 5
  2  /

5 rows created.

SQL> commit;

Commit complete.

SQL> select * from t
  2  /

         X          Y                                             

              
---------- ----------                                             

              
         1          2                                             

              
         2          3                                             

              
         3          4                                             

              
         4          5                                             

              
         5          6                                             

              

SQL> select x,y,x+y from t
  2  union all
  3  select sum(x),sum(y),sum(x+y) from t
  4  /

         X          Y        X+Y                                  

              
---------- ---------- ----------                                  

              
         1          2          3                                  

              
         2          3          5                                  

              
         3          4          7                                  

              
         4          5          9                                  

              
         5          6         11                                  

              
        15         20         35                                  

              

6 rows selected.

Can this query be put in any other way??

I would like to eliminate union all from this query.
I even tried 
SQL > select decode(grouping(..

But it is not working properly.Can you provide
some other way??

 

Tom Kyte

Followup  

February 17, 2005 - 1:58 pm UTC

ops$tkyte@ORA9IR2> select decode( grouping(rowid), 0, null, 1, 'the end' ) label,
  2         sum(x), sum(y), sum(x+y)
  3   from t
  4  group by rollup(rowid);
 
LABEL       SUM(X)     SUM(Y)   SUM(X+Y)
------- ---------- ---------- ----------
                 1          2          3
                 2          3          5
                 3          4          7
                 4          5          9
                 5          6         11
the end         15         20         35
 
6 rows selected.
 

Efficient way to get counts

March 14, 2005 - 2:13 pm UTC

Reviewer: Thiru

Tom,

Excuse me for not replying immediately to your followup above with title "Efficient way to get counts"

Your followup was:

"need more info, is this table modified during the day or is this a warehouse.

is this example cut way down and there are 500 columns
or is this it.

is c1, c2, flag always involved,
or was that just a side effect of your example..

before anyone can suggest the "best way", details about how the data is used
need to be known"

The case example repeated :

drop table temp_del;
create table temp_del (c1 varchar2(3),c2 varchar2(3),c3 varchar2(3),c4
varchar2(3),flag number);
insert into temp_del values('abc','bcd','cde','def',0);
insert into temp_del values('abc','bcd','cde','def',1);
insert into temp_del values('abc','bcd','cde','def',2);

insert into temp_del values('bcd','cde','def','efg',0);
insert into temp_del values('bcd','cde','def','efg',1);
insert into temp_del values('bcd','cde','def','efg',2);

insert into temp_del values('cde','def','efg','fgh',0);
insert into temp_del values('cde','def','efg','fgh',1);
insert into temp_del values('cde','def','efg','fgh',2);
commit;

select count(*) from temp_del where c1='abc' and c2='bcd' and flag=0;
select count(*) from temp_del where c1='abc' and c2='bcd' and flag=1;
select count(*) from temp_del where c1='abc' and c2='bcd' and c3='efg' and
flag=0;
select count(*) from temp_del where c1='abc' and c2='bcd' and c3='efg' and
flag=1;
select count(*) from temp_del where c1='bcd' and c2='cde' and c3='def' and
flag=2;


Here is the data spread asked for:

No. of columns used by the query : 25
Is c1,c2,flag always involved : yes and a combination of the 25 columns.
Is this table modified during the day or is this a warehouse: This table is modified regularly during
the day. But the query that I have asked for is run only for reporting purposes.


I went with the sum(case.. ) method after creating bitmap indexes for all the columns used in the query where the
distinct values were actually less than 5 or 6. And normal indexes for other columns where the
distinct values were actually close to 60% of the no of rows.

select sum(case when c1='abc' and c2='bcd' and flag=0 then 1 else 0 end) r1,
sum(case when c1='abc' and c2='bcd' and c3='cde' and flag=1 then 1 else 0 end)r2
from temp_del

Kindly advise if this is a preferred solution for 10 million rows table or please suggest something better.


Tom Kyte

Followup  

March 14, 2005 - 2:48 pm UTC

you have bitmaps on a table that is modified regularly??????

March 14, 2005 - 3:47 pm UTC

Reviewer: Thiru

Having a very few values for the columns, that's what I thought of. Does this affect performance in the normal running of the application and in the queries for reporting purposes?

Thanks for the time.

Tom Kyte

Followup  

March 14, 2005 - 7:47 pm UTC

do you have bitmaps on columns that are regularly updated?

March 15, 2005 - 10:26 am UTC

Reviewer: Thiru

Yes. A few columns are updated quite frequently.

Tom Kyte

Followup  

March 15, 2005 - 10:26 am UTC

and you have not found this to be an issue with

a) deadlocks
b) massive bitmap index growth

??

March 29, 2005 - 4:36 pm UTC

Reviewer: Steve from nyc, NY

Tom,

I am not sure if the folowing logic can be done by a single sql.

I have two tables

receipts
store_id, order_id, prod_id, rec_date, rec_qty
-------------------------------------------------
1003 10001 2001, 3/5/2005, 3
1003 10002 2001, 3/8/2005, 1
1004 10003


sales
sales_date, store_id, prod_id, sales_qty, ...
----------------------------------------------
3/8/05, 1003, 2001, 1
3/10/05, 1003, 2001, 2
3/11/05, 1003, 2001, 1
3/12/05, 1003, 2001, 1
.....

I want to create a received_sales match report

store_id, order_id, prod_id, rec_date, rec_qty, sale_qty
1003 10001 2001, 3/5/2005, 2 2
1003 10002 2001, 3/8/2005, 1 1

Matching rule:
Given a receipt of product, if there is a sale for that type of the product within 14 day of receipt_date, then we conside a sale match.

Thanks in advanced!

Steve



Tom Kyte

Followup  

March 29, 2005 - 5:07 pm UTC

no create tables, no inserts....

join by store id, where one_date-other_date <= 14.

Joining three scripts and get values for three columns.

April 05, 2005 - 2:28 pm UTC

Reviewer: Dawar from LA-CA- USA


Tom,
I need to run below script which displays only three columns.

EMPLOYEE_NAME
V.DEPT_NO DEPT_NO
V.PAY_LOCATION PAY_LOCATION

I got those three script from Our current Oracle reports.
emp_no from the first script is PK and other two columns has this column (emp_no) FK.
here are three scripts, how will I join below scripts and get values for only EMPLOYEE_NAME, V.DEPT_NO DEPT_NO
& V.PAY_LOCATION PAY_LOCATION columns.


SELECT V.LAST_NAME || ', ' || V.FIRST_NAME || ' ' || V.MIDDLE_INITIAL
EMPLOYEE_NAME
,E.home_phone PHONE
,E.home_street STREET
,E.home_city CITY
,E.home_zip1 ZIP1
,E.home_zip2 ZIP2
,nvl(E.bilingual_code, 'Not Applicable') BC
,nvl(V.specialty, 'Not Applicable') SPECIALTY
,nvl(V.sub_specialty,'Not Applicable') SBSP
,E.BILINGUAL_REF_CD BRC
,V.EMP_NO EMP_NO
,V.DEPT_NO DEPT_NO
,C.DEPT_TITLE DEPT_TITLE
,V.PAY_LOCATION PAY_LOCATION
,V.LAYOFF_SENIORITY_DATE LAYOFF_SENIORITY_DATE
,V.TIME_IN_GRADE TIME_IN_GRADE
,V.PAYROLL_ITEM_NO PAYROLL_ITEM_NO
,V.ITEM_LETTER ITEM_LETTER
,V.CLASS_TITLE CLASS_TITLE
,DECODE(V.REPRESENTATION_STATUS,'Y','REPRESENTED','NON-REPRESENTED')
REPRESENTATION_STATUS
,DECODE(V.PROBATION_STATUS,'1','FIRST','2','SUBSEQUENT','NONE')
PROBATION_STATUS
,DECODE(V.IMPROVEMENT_NEEDED_END_DATE,NULL,'NONE',
TO_CHAR(V.IMPROVEMENT_NEEDED_END_DATE,'MM/DD/YY')) IMPROVEMENT_NEEDED_END_DATE
FROM EMPINFO_VIEW V,
DEPARTMENTS C,
EMPLOYEES E
WHERE V.PRIOR_ITEM_INDICATOR IS NULL
AND V.JOB_CODE = 'A'
AND (V.EMP_NO = :EMP_PARM OR :EMP_PARM IS NULL)
AND (V.DEPT_NO = :DEPT_PARM OR :DEPT_PARM IS NULL)
AND (V.BUDGETED_GROUP_ID = :GROUP_PARM OR :GROUP_PARM IS NULL)
AND (C.DEPT_NO = :DEPT_PARM OR :DEPT_PARM IS NULL)
and (v.payroll_item_no = :ITEM_PARM or :ITEM_PARM is null)
AND C.DEPT_NO = V.DEPT_NO
and V.emp_no = E.emp_no
ORDER BY V.DEPT_NO
,V.PAY_LOCATION
,V.LAST_NAME


***********************************************

SELECT EMPITM.PAYROLL_ITEM_NO PAYROLL_ITEM_NO2
,ITEM.CLASS_TITLE CLASS_TITLE2
,EMPITM.ITEM_LETTER ITEM_LETTER2
,EMPITM.EMP_NO EMP_NO2
FROM EMPLOYEE_ITEMS EMPITM
,ITEMS ITEM
WHERE ITEM.ITEM_NO = EMPITM.PAYROLL_ITEM_NO
AND EMPITM.PRIOR_ITEM_INDICATOR = 'Y'
ORDER BY ITEM.MAXIMUM_ANNUAL_SALARY DESC

****************************************************************

SELECT EMP_NO EMP_NO3,
PRIORITY_GEO_A PGA,
PRIORITY_GEO_B PGB,
PRIORITY_GEO_C PGC
FROM EMPLOYEES

Regards,
Dawar

Tom Kyte

Followup  

April 05, 2005 - 6:47 pm UTC

no idea what you mean

SQL Query

April 06, 2005 - 1:12 am UTC

Reviewer: Reader from India

Dear Tom,

The following query takes around 45 seconds...All tables have been analyzed using dbms_stats. Indexes are in place.  The view called in this query runs very fast and the response for the view is less than a second. Can you please give inputs to improve the performance?  Are joins bad here?
Should we rewrite the query?

Regards


=======================
SQL> SELECT  count(1) noofrecs FROM
OPAY.OC_CHEQUE_INTERFACE OCI,
OPAY.FILE_MST_PAY FIM,
OPAY.OC_CHEQUE_DETAIL OCD,
OPMAY.CLIENTALL VW_CLA
WHERE
OCD.COD_TXN_STATUS = 'ISSUED' and
OCI.AMT_CREDIT BETWEEN
0 AND 999999999999.99 and
OCD.ISSUE_DATE BETWEEN
TO_DATE('21-08-2004','DD-MM-YY') AND
TO_DATE ('29-08-2004','DD-MM-YY')
AND oci.cod_cust LIKE
DECODE ('VOLTEST', '', '%', 'VOLTEST')
AND vw_cla.dividend_number
LIKE DECODE ('VOLTESTDIV', '', '%','VOLTESTDIV')
AND
VW_CLA.COD_STOCK LIKE DECODE ('', '', '%', '') AND
TO_DATE (vw_cla.dat_payment, 'DD-MM-YY')
BETWEEN TO_DATE
('08-06-2006','DD-MM-YYYY') AND
TO_DATE ('15-06-2006','DD-MM-YYYY') AND
OCI.COD_FILEID = FIM.COD_FILEID AND
OCI.TXN_ID = OCD.TXN_ID AND
vw_cla.cycle_id = fim.cycle_id
  2    3    4    5    6    7    8    9   10   11   12   13   14   15   16   17
SQL> /

Elapsed: 00:00:43.65
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=759 Card=1 Bytes=133
          )

   1    0   SORT (AGGREGATE)
   2    1     NESTED LOOPS (Cost=759 Card=1 Bytes=133)
   3    2       HASH JOIN (Cost=757 Card=1 Bytes=109)
   4    3         NESTED LOOPS (Cost=11 Card=84 Bytes=5880)
   5    4           VIEW OF 'CLIENTALL' (Cost=8 Card=2 Bytes=112)
   6    5             SORT (UNIQUE) (Cost=8 Card=2 Bytes=122)
   7    6               UNION-ALL
   8    7                 NESTED LOOPS (Cost=2 Card=1 Bytes=57)
   9    8                   TABLE ACCESS (FULL) OF 'DVD_CYCLE_MST_PAY'
           (Cost=1 Card=1 Bytes=29)

  10    8                   TABLE ACCESS (BY INDEX ROWID) OF 'ORBICASH
          _CLIENTMST' (Cost=1 Card=119 Bytes=3332)

  11   10                     INDEX (UNIQUE SCAN) OF 'SYS_C0014447' (U
          NIQUE)
  12    7                 NESTED LOOPS (Cost=2 Card=1 Bytes=65)
  13   12                   TABLE ACCESS (FULL) OF 'DVD_CYCLE_MST_PAY'
           (Cost=1 Card=1 Bytes=29)

  14   12                   TABLE ACCESS (BY INDEX ROWID) OF 'COUNTER_
          MST_PAY' (Cost=1 Card=14 Bytes=504)

  15   14                     INDEX (UNIQUE SCAN) OF 'SYS_C0014648' (U
          NIQUE)

  16    4           INDEX (RANGE SCAN) OF 'PERF2' (NON-UNIQUE) (Cost=2
           Card=4767 Bytes=66738)

  17    3         TABLE ACCESS (BY INDEX ROWID) OF 'OC_CHEQUE_INTERFAC
          E' (Cost=745 Card=30 Bytes=1170)

  18   17           INDEX (RANGE SCAN) OF 'IDX_OC_CHEQUE_INT_CODCUST'
          (NON-UNIQUE) (Cost=36 Card=30)

  19    2       TABLE ACCESS (BY INDEX ROWID) OF 'OC_CHEQUE_DETAIL' (C
          ost=2 Card=49 Bytes=1176)

  20   19         INDEX (UNIQUE SCAN) OF 'SYS_C0015224' (UNIQUE) (Cost
    =1 Card=49)

 Statistics
----------------------------------------------------------
          7  recursive calls
          8  db block gets
    1693075  consistent gets
      47287  physical reads
          0  redo size
        367  bytes sent via SQL*Net to client
        425  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          9  sorts (memory)
          0  sorts (disk)
          1  rows processed


============================================

 

Tom Kyte

Followup  

April 06, 2005 - 6:40 am UTC

I cannot tune every query..

but "indexes are in place" - that could be the problem, using indexes. indexes are good, they are bad, they are sometimes neither good nor bad.

sorry, without tables and indexing schemes....


TO_DATE (vw_cla.dat_payment, 'DD-MM-YY')
BETWEEN TO_DATE
('08-06-2006','DD-MM-YYYY') AND
TO_DATE ('15-06-2006','DD-MM-YYYY')

I can say that is plain "wrong", as in gets the wrong data.

did you know that the date the 14 of January 1806 which is in your query the string

14-jan-1806

is between the string '08....' and the string '15....'

convert STRINGS TO DATES to compare to DATES.

Also, applying functions to database columns typically prevents the use of indexes on that column.

why would you to_char a date to have it converted back to a date...

where DATE_COLUMN between to_date( string ) and to_date( another_string )



SQL Query

April 07, 2005 - 12:50 am UTC

Reviewer: reader from India

Tom,

Thanks for the inputs. 

Please clarify on the following:

1. I am under the belief that when indexes are in place and the tables stand analyzed using dbms_stats, CBO will decide whether or not to use the index.This being the case how the index would be bad during select operations.

2. As suggested, the query was modified to compare the date column to  to_date of string. But the consistent gets continue to be the same as shown below. Is there any other part of the query to look at and modfiy?

Regards.

==============================================
SQL> SELECT  count(1) noofrecs FROM
OPAY.OC_CHEQUE_INTERFACE OCI,
OPAY.FILE_MST_PAY FIM,
OPAY.OC_CHEQUE_DETAIL OCD,
OPMAY.CLIENTALL VW_CLA
WHERE
OCD.COD_TXN_STATUS = 'ISSUED' and
OCI.AMT_CREDIT BETWEEN
0 AND 999999999999.99 and
OCD.ISSUE_DATE BETWEEN
TO_DATE('21-08-2004','DD-MM-YYYY') AND
TO_DATE ('29-08-2004','DD-MM-YYYY')
AND oci.cod_cust LIKE
DECODE ('VOLTEST', '', '%', 'VOLTEST')
AND vw_cla.dividend_number
LIKE DECODE ('VOLTESTDIV', '', '%','VOLTESTDIV')
AND
VW_CLA.COD_STOCK LIKE DECODE ('', '', '%', '') AND
vw_cla.dat_payment
BETWEEN TO_DATE
('08-06-2006','DD-MM-YYYY') AND
TO_DATE ('15-06-2006','DD-MM-YYYY') AND
OCI.COD_FILEID = FIM.COD_FILEID AND
OCI.TXN_ID = OCD.TXN_ID AND
vw_cla.cycle_id = fim.cycle_id
  2    3    4    5    6    7    8    9   10   11   12   13   14   15   16   17
SQL> /

Elapsed: 00:00:27.42

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=766 Card=1 Bytes=133
          )

   1    0   SORT (AGGREGATE)
   2    1     NESTED LOOPS (Cost=766 Card=1 Bytes=133)
   3    2       HASH JOIN (Cost=764 Card=1 Bytes=109)
   4    3         HASH JOIN (Cost=18 Card=84 Bytes=5880)
   5    4           VIEW OF 'CLIENTALL' (Cost=8 Card=2 Bytes=112)
   6    5             SORT (UNIQUE) (Cost=8 Card=2 Bytes=122)
   7    6               UNION-ALL
   8    7                 NESTED LOOPS (Cost=2 Card=1 Bytes=57)
   9    8                   TABLE ACCESS (FULL) OF 'DVD_CYCLE_MST_PAY'
           (Cost=1 Card=1 Bytes=29)
 10    8                   TABLE ACCESS (BY INDEX ROWID) OF 'ORBICASH
          _CLIENTMST' (Cost=1 Card=119 Bytes=3332)

  11   10                     INDEX (UNIQUE SCAN) OF 'SYS_C0014447' (U
          NIQUE)

  12    7                 NESTED LOOPS (Cost=2 Card=1 Bytes=65)
  13   12                   TABLE ACCESS (FULL) OF 'DVD_CYCLE_MST_PAY'
           (Cost=1 Card=1 Bytes=29)

  14   12                   TABLE ACCESS (BY INDEX ROWID) OF 'COUNTER_
          MST_PAY' (Cost=1 Card=14 Bytes=504)

  15   14                     INDEX (UNIQUE SCAN) OF 'SYS_C0014648' (U
          NIQUE)

  16    4           TABLE ACCESS (FULL) OF 'FILE_MST_PAY' (Cost=9 Card
          =4767 Bytes=66738)

  17    3         TABLE ACCESS (BY INDEX ROWID) OF 'OC_CHEQUE_INTERFAC
          E' (Cost=745 Card=30 Bytes=1170)
18   17           INDEX (RANGE SCAN) OF 'IDX_OC_CHEQUE_INT_CODCUST'
          (NON-UNIQUE) (Cost=36 Card=30)

  19    2       TABLE ACCESS (BY INDEX ROWID) OF 'OC_CHEQUE_DETAIL' (C
          ost=2 Card=49 Bytes=1176)

  20   19         INDEX (UNIQUE SCAN) OF 'SYS_C0015224' (UNIQUE) (Cost
          =1 Card=49)

Statistics
----------------------------------------------------------
          0  recursive calls
         12  db block gets
    1693160  consistent gets
      47557  physical reads
          0  redo size
        367  bytes sent via SQL*Net to client
        425  bytes received via SQL*Net from client
          2  SQL*Net roundtrips to/from client
          1  sorts (memory)
          0  sorts (disk)
          1  rows processed


============================================= 

Tom Kyte

Followup  

April 07, 2005 - 9:10 am UTC

1) </code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:6749454952894#6760861174154 <code>

2)

AND oci.cod_cust LIKE
DECODE ('VOLTEST', '', '%', 'VOLTEST')
AND vw_cla.dividend_number
LIKE DECODE ('VOLTESTDIV', '', '%','VOLTESTDIV')
AND
VW_CLA.COD_STOCK LIKE DECODE ('', '', '%', '')

why that, why no

cod_cust = 'constant'
and dividend_number = 'anotherconstant'
and cod_stock is not null


Are the cardnialities in the autotrace even close to those in the tkprof.

May 24, 2005 - 12:12 pm UTC

Reviewer: Alex

Hi Tom,

I have a quick question about my decode I'm trying to do but I don't know if what I'm doing is allowed or not. I'm doing:

select a.name,
DECODE (r.text,INSTR (r.text, 'XXX') != 0, r.id || SUBSTR (r.text, 4),r.text)

from address a, requirements r
where a.key = r.key

I get ORA-00907: missing right parenthesis, but as you see they match. I think it doesn't like something about that INSTR. Thank you.

Tom Kyte

Followup  

May 24, 2005 - 1:40 pm UTC

the decode isn't making sense.

what are you trying to do exactly? (decode doesn't do boolean expressions)

are you trying to return r.id || substr() when the instr() is not zero?


decode( instr(r.text,'XXX'), 0, r.text, r.id||substr(r.text) )

perhaps? that is:

case when instr(r.text,'XXX') = 0
then r.text
else r.id||substr(r.text)
end

you might just want to use case actually, more readable in many cases.

May 28, 2005 - 7:34 am UTC

Reviewer: mo

Tom:

I have two tables:

SQL> desc phone_log;
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 LOG_NO                                    NOT NULL NUMBER(10)
 CALLER_ID                                 NOT NULL NUMBER(10)
 CONTACT_PERSON                                     VARCHAR2(50)
 PHONE                                              VARCHAR2(25)
 DATE_RECEIVED                                      DATE
 DATE_RESOLVED                                      DATE
 PURPOSE                                            VARCHAR2(20)
 TOPIC                                              VARCHAR2(25)
 PRIORITY                                           VARCHAR2(6)
 INITIAL_OUTCOME                                    VARCHAR2(20)
 ISSUE                                              VARCHAR2(500)
 INITIAL_RESPONSE                                   VARCHAR2(500)
 SOURCE                                             VARCHAR2(10)

SQL> desc phone_followup
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 LOG_NO                                    NOT NULL NUMBER(10)
 FOLLOWUP_NO                               NOT NULL NUMBER(2)
 FOLLOWUP_DATE                                      DATE
 RESPONSE                                           VARCHAR2(500)
 OUTCOME                                            VARCHAR2(20)

The phone log table is a parent table to phone_followup.  However a parent record 
can exist without any children.  I am trying to query on pending records which are defined as:
Find all records in phone_log without any children where date_resolved is null
or if there are children records in phone followup then find the maximum followup number
where outcome is not resolved.

I wrote this but it does not work.  Is there a way to join both tables and find the 
maximum followup number record to join and also find records in parent that do not have children.

  1  select f.log_no,g.outcome from
  2  (
  3  select f.log_no,f.date_received,f.date_resolved from phone_log f,
  4  (
  5   select * from
  6  (
  7  select a.log_no,a.outcome,a.followup_no from phone_followup a,
  8  (select log_no,max(followup_no) followup_no from phone_followup group by log_no) b
  9  where a.log_no = b.log_no and a.followup_no=b.followup_no
 10  ) e
 11  ) g
 12  where f.log_no=g.log_no(+)
 13* )
SQL> /
select f.log_no,g.outcome from
                *
ERROR at line 1:
ORA-00904: "G"."OUTCOME": invalid identifier





  1   select a.log_no,a.date_received,a.date_resolved,b.outcome,b.followup_no from
  2  phone_log a,phone_followup b where
  3  a.log_no=b.log_no(+)
  4  --and (a.date_resolved is null or b.outcome <> 'Resolved') and
  5* --b.followup_no=(select max(followup_no) from phone_followup where log_no=a.log_no)
SQL> /

    LOG_NO DATE_RECE DATE_RESO OUTCOME              FOLLOWUP_NO
---------- --------- --------- -------------------- -----------
        39 22-SEP-04           Referred                       1
        39 22-SEP-04           Follow-up Needed               2
        39 22-SEP-04           Resolved                       3
        39 22-SEP-04                                          4
        39 22-SEP-04           Referred                       5
        41 20-NOV-04           Call Escalated                 1
        41 20-NOV-04           Referred                       2
        41 20-NOV-04           Resolved                       3
        41 20-NOV-04           Follow-up Needed               4
        38 11-NOV-04 11-DEC-04 Follow-up Needed               1
        38 11-NOV-04 11-DEC-04 Resolved                       2

    LOG_NO DATE_RECE DATE_RESO OUTCOME              FOLLOWUP_NO
---------- --------- --------- -------------------- -----------
        38 11-NOV-04 11-DEC-04 Referred                       3
        50           27-MAY-05

13 rows selected.


What I want are the records with max(followup_no) for each log_No and check if the outcome 
is not 'Resolved'.  For record 50 which does not have children I want to only check 
"date resolved" field.


Thank you,
 

Tom Kyte

Followup  

May 28, 2005 - 9:20 am UTC

no creates, no inserts, no comment.

June 06, 2005 - 10:00 am UTC

Reviewer: A reader

create table orders
(order_id number(10),
address varchar2(100))
insert into orders values(1,'addr1');
insert into orders values(2,'addr2');
insert into orders values(3,'addr3');
insert into orders values(4,'addr4');
insert into orders values(5,'addr5');
insert into orders values(6,'addr6');

insert into order_items values(1,1,100,5);
insert into order_items values(2,1,200,15);
insert into order_items values(3,2,100,5);
insert into order_items values(4,2,200,15);
insert into order_items values(5,3,100,5);
insert into order_items values(6,4,300,4);
insert into order_items values(7,5,400,4);
insert into order_items values(7,6,400,4);


I need to select identical orders with the same set on inventory_Id and ordered items,

First set is orders 1, 2, and second set - orders 5,6.
order_id address count(order_id) Set#
1 addr1 2 1
2 addr2 2 1

5 addr3 2 2
6 addr5 2 2

Thanks in advance.





Tom Kyte

Followup  

June 06, 2005 - 10:52 am UTC

sort of incomplete example no?

June 06, 2005 - 11:09 am UTC

Reviewer: A reader

We have a lot of customers making the same orders,
and want to select such customers's orders as a bulk,
then create file and ship those orders thru fedx as a one set.
The number of orders in such bulk should be more than 3.
Let's say, if more than 2 orders have 10 ordered item 1,
20 items 2, this is a bulk #1. And so on.



June 06, 2005 - 2:56 pm UTC

Reviewer: A reader

Sorry, I need it and will try again.

let's say we have:
order1 contains item1 10 pieces, item2 15 pieces
order2 contains item1 10 pieces, item2 15 pieces
order3 contains item3 30 pieces
order4 contains item4 15 pieces, item1 20 pieces
order5 contains item1 8 pieces, item2 15 pieces
order6 contains item1 3 pieces, item2 15 pieces
order7 contains item3 30 pieces
order8 contains item3 30 pieces
order9 contains item7 10 pieces
Another words:
create table T
(item_id number(10), order_id number(10),
item varchar2(10), itm_ordered number(10))
insert into T values (1,1,'item1',10);
insert into T values (2,1,'item2',15);
insert into T values (3,2,'item1',10);
insert into T values (4,2,'item2',15);
insert into T values (5,3,'item3',30);
insert into T values (6,4,'item4',15);
insert into T values (7,4,'item1',20);
insert into T values (8,5,'item1',8);
insert into T values (9,5,'item2',15);
insert into T values (10,6,'item1',3);
insert into T values (11,6,'item2',15);
insert into T values (12,7,'item3',30);
insert into T values (13,8,'item3',30);
insert into T values (14,9,'item7',10);
and I need:
orders count in bulk
order1 2
order2 2
order3 3
order7 3
order8 3
order4,5,6,9 arent interesting because there is not dups for them.

Thanks.


Tom Kyte

Followup  

June 06, 2005 - 3:18 pm UTC

if you know the maximum items per order (and this maxes out at a varchar2(4000)) this'll do it

ops$tkyte@ORA9IR2> select *
  2    from (
  3  select order_id, data, count(*) over (partition by data) cnt
  4    from (
  5  select order_id,
  6          max(decode(r,1,item||'/'||itm_ordered)) || '|' ||
  7          max(decode(r,2,item||'/'||itm_ordered)) || '|' ||
  8          max(decode(r,3,item||'/'||itm_ordered)) || '|' ||
  9          max(decode(r,4,item||'/'||itm_ordered)) || '|' ||
 10          max(decode(r,5,item||'/'||itm_ordered)) || '|' ||
 11          max(decode(r,6,item||'/'||itm_ordered)) || '|' ||
 12          max(decode(r,7,item||'/'||itm_ordered)) data
 13    from (select a.*, row_number() over (partition by order_id order by item, itm_ordered) r
 14            from t a
 15             )
 16   group by order_id
 17         )
 18         )
 19   where cnt > 1
 20  /
 
  ORDER_ID DATA                                                      CNT
---------- -------------------------------------------------- ----------
         1 item1/10|item2/15|||||                                      2
         2 item1/10|item2/15|||||                                      2
         3 item3/30||||||                                              3
         7 item3/30||||||                                              3
         8 item3/30||||||                                              3
 

If you don't know the number of items on an order....

June 06, 2005 - 4:28 pm UTC

Reviewer: Sean D Stuber from Columbus, OH

How about this? I've been trying to think of a more effficient or at least more "elegant" way but so far this is the best I could come up with. I hope it helps.

SELECT * FROM
(SELECT order_id,
COUNT(*) OVER(PARTITION BY items) cnt FROM
(SELECT x.*,
ROW_NUMBER() OVER(PARTITION BY order_id
ORDER BY lvl DESC) rn
FROM
(SELECT y.*, LEVEL lvl,
SYS_CONNECT_BY_PATH(item || '/'
|| itm_ordered,
'|') items
FROM
(SELECT t.*,
ROW_NUMBER()
OVER (PARTITION BY order_id
ORDER BY item_id) itm_idx
FROM t
) y
CONNECT BY order_id = PRIOR order_id
AND itm_idx - 1 = PRIOR itm_idx
) x
)
WHERE rn = 1
)
WHERE cnt > 1

Tom Kyte

Followup  

June 06, 2005 - 5:52 pm UTC

has the same 4000 byte limit -- so ultimately there is always a "max"

OK

June 10, 2005 - 8:48 am UTC

Reviewer: James from CT,USA

Hi Tom,
My requirement is
"I would like to get grouped rows from EMP table
where no individual makes more than 3000"

I tried this query but getting errors.

SQL> select deptno,avg(sal)
  2  from emp
  3  group by deptno
  4  having sal <= 3000
  5  /
having sal <= 3000
       *
ERROR at line 4:
ORA-00979: not a GROUP BY expression
 

Tom Kyte

Followup  

June 10, 2005 - 10:37 am UTC

where sal <= 3000

not having. having works on the grouped columns or the aggregates only. "sal" no longer exists when you get to the having.


but, is the question really:

I want the avg salary for all employees in any dept where the maximum salary in that dept is <= 3000


that would be having max(sal) <= 3000

OK

June 10, 2005 - 12:54 pm UTC

Reviewer: A reader

Hi Tom,
My requirement is:
I want to exclude grouped rows when atleast one individual
in each group gets a salary of more than 3000.


Tom Kyte

Followup  

June 10, 2005 - 3:47 pm UTC

that would be having max(sal) <= 3000 then.

Query

June 14, 2005 - 4:33 pm UTC

Reviewer: Laxman Kondal from Springfield, VA

Hi Tom

I wanted to find a way to fetch from emp table where I pass deptno. And if deptno is not in emp then fetch all.

And this is what I did. Since deptno=50 not exists and 'OR' clauese 1=1 bribgs all results.

And when I use deptno=10 or 1=1 then also it fetches all deptno.
scott@ORA9I> select ename, empno from emp where deptno=10;

scott@ORA9I> select ename, empno, deptno from emp where deptno=10;

I think my concept of 'OR' caluse is messedup.

ENAME EMPNO DEPTNO
---------- ---------- ----------
CLARK 7782 10
KING 7839 10
MILLER 7934 10

3 rows selected.

scott@ORA9I> select ename, empno, deptno from emp where deptno=50;

no rows selected

scott@ORA9I> select ename, empno, deptno from emp where deptno=50 or 1=1;

ENAME EMPNO DEPTNO
---------- ---------- ----------
SMITH 7369 20
ALLEN 7499 30
WARD 7521 30
JONES 7566 20
MARTIN 7654 30
BLAKE 7698 30
CLARK 7782 10
SCOTT 7788 20
KING 7839 10
TURNER 7844 30
ADAMS 7876 20
JAMES 7900 30
FORD 7902 20
MILLER 7934 10

14 rows selected.

scott@ORA9I> select ename, empno, deptno from emp where deptno=10 or 1=1;

ENAME EMPNO DEPTNO
---------- ---------- ----------
SMITH 7369 20
ALLEN 7499 30
WARD 7521 30
JONES 7566 20
MARTIN 7654 30
BLAKE 7698 30
CLARK 7782 10
SCOTT 7788 20
KING 7839 10
TURNER 7844 30
ADAMS 7876 20
JAMES 7900 30
FORD 7902 20
MILLER 7934 10

14 rows selected.

scott@ORA9I>

Thanks and regards.

Tom Kyte

Followup  

June 14, 2005 - 4:46 pm UTC

(some 'requirements' just boggle my mind, I'll never figure out the business case behind this one)

do you really mean this? or can it be more like:

if I pass in null, i want all rows, else I want only the matching rows?

Query

June 15, 2005 - 8:26 am UTC

Reviewer: Laxman Kondal from Springfield, VA

Hi Tom

You are right and some time I want to figure out some way to work around possibility in shorter and correct way. Although I can have two blocks in if statements and either one will work. That's double coding and if I add just 'were' clause then will it work?

What I am trying to get is that if I pass deptno which exists then get me that dept and if not exists then from all deptno.

Thanks for the hint and it works

scott@ORA9I> CREATE OR REPLACE PROCEDURE Demo(p_dep IN NUMBER )
2 AS
3 v1 NUMBER := p_dep;
4 BEGIN
5 FOR i IN (SELECT *
6 FROM Emp
7 WHERE (CASE WHEN p_dep = 0
8 THEN v1
9 ELSE deptno
10 END ) = p_dep )
11
12 LOOP
13 dbms_output.put_line(i.ename||' - '||i.deptno);
14 END LOOP;
15 END Demo;
16 /

Procedure created.

scott@ORA9I> exec demo(10)
CLARK - 10
KING - 10
MILLER - 10

PL/SQL procedure successfully completed.

scott@ORA9I> exec demo(20)
SMITH - 20
JONES - 20
SCOTT - 20
ADAMS - 20
FORD - 20

PL/SQL procedure successfully completed.

scott@ORA9I> exec demo(30)
ALLEN - 30
WARD - 30
MARTIN - 30
BLAKE - 30
TURNER - 30
JAMES - 30

PL/SQL procedure successfully completed.

scott@ORA9I> exec demo(0)
SMITH - 20
ALLEN - 30
WARD - 30
JONES - 20
MARTIN - 30
BLAKE - 30
CLARK - 10
SCOTT - 20
KING - 10
TURNER - 30
ADAMS - 20
JAMES - 30
FORD - 20
MILLER - 10

PL/SQL procedure successfully completed.

scott@ORA9I>

Thanks and regards.

Tom Kyte

Followup  

June 15, 2005 - 10:05 am UTC

guess I'll recommend

ops$tkyte@ORA9IR2> variable x number
ops$tkyte@ORA9IR2> exec :x := 50;
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> declare
  2      l_cursor sys_refcursor;
  3      l_rec    emp%rowtype;
  4  begin
  5      open l_cursor for select * from emp where deptno = :x;
  6      fetch l_cursor into l_rec;
  7      if ( l_cursor%notfound )
  8      then
  9          close l_cursor;
 10          open l_cursor for select * from emp;
 11          fetch l_cursor into l_rec;
 12      end if;
 13      loop
 14          exit when l_cursor%notfound;
 15          dbms_output.put_line( l_rec.deptno || ', ' || l_rec.ename );
 16          fetch l_cursor into l_rec;
 17      end loop;
 18      close l_cursor;
 19  end;
 20  /
20, SMITH
30, ALLEN
30, WARD
20, JONES
30, MARTIN
30, BLAKE
10, CLARK
20, SCOTT
10, KING
30, TURNER
20, ADAMS
30, JAMES
20, FORD
10, MILLER
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> exec :x := 10
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA9IR2> /
10, CLARK
10, KING
10, MILLER
 
PL/SQL procedure successfully completed.
 

 

Query

June 15, 2005 - 10:33 am UTC

Reviewer: Laxman Kondal from Springfield, VA

Hi Tom

Thanks and you showed one more way to do this.

Thanks and regards

June 15, 2005 - 4:09 pm UTC

Reviewer: A reader

Hi Tom,

I have 2 tables like

create table t1
(
id1 number,
name varchar2(60),
id2 number
);

create table t2
(
id2 number,
xxx char(1)
);

insert into t1 values (1, 'firstname', 1);
insert into t1 values (2, 'secondname', 2);
insert into t2 values (1, 'A');
insert into t2 values (1, 'B');
insert into t2 values (2, 'A');
insert into t2 values (2, 'B');
commit;

I have a query

select t1.id1, t1.name, t1.id2, t2.xxx from t1, t2
where t1.id2 = t2.id2
/

ID1 NAME ID2 X
---------- ------------------------------------------------------------ ---------- -
1 firstname 1 A
1 firstname 1 B
2 secondname 2 A
2 secondname 2 B


Is it possible to get something like

ID1 NAME ID2 XA XB

1 firstname 1 A B
2 secondname 2 A B

The values for columns ID1, NAME, ID2 for all rows for A and B will always be the same.

Thanks.



Tom Kyte

Followup  

June 16, 2005 - 3:31 am UTC

and what happens if firstname has 3 rows?

June 16, 2005 - 10:12 am UTC

Reviewer: A reader

No firstname will always have only 2 rows and so will secondname.

Thanks.

Tom Kyte

Followup  

June 16, 2005 - 1:09 pm UTC

ops$tkyte@ORA9IR2> Select id1, name, id2, max( decode(rn,1,xxx) ) c1, max(decode(rn,2,xxx)) c2
  2    from (
  3  select t1.id1, t1.name, t1.id2, t2.xxx ,
  4         row_number() over (partition by t1.id1, t1.name, t1.id2 order by t2.xxx) rn
  5    from t1, t2
  6   where t1.id2 = t2.id2
  7         )
  8   group by id1, name, id2
  9  /
 
       ID1 NAME                                  ID2 C C
---------- ------------------------------ ---------- - -
         1 firstname                               1 A B
         2 secondname                              2 A B
 


there is of course an easier answer if xxx is always A/B and nothing but nothing else. 

June 16, 2005 - 2:49 pm UTC

Reviewer: A reader

Yes xxx will not have anything else other than A/B. Is there an easier way to do this in that case?

Thanks a lot for your help Tom.


Tom Kyte

Followup  

June 16, 2005 - 3:14 pm UTC

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select t1.id1, t1.name, t1.id2, max(decode(t2.xxx,'A','A')) xa, max(decode(t2.xxx,'B','B')) xb  2    from t1, t2
  3   where t1.id2 = t2.id2
  4   group by t1.id1, t1.name, t1.id2
  5  /
 
       ID1 NAME                                  ID2 X X
---------- ------------------------------ ---------- - -
         1 firstname                               1 A B
         2 secondname                              2 A B
 

June 16, 2005 - 4:07 pm UTC

Reviewer: A reader

I have a similar requirement but I am selecting around 20 fields and so my "group by" clause also has 20 columns. If I try a similar query with the 20 fields, it is taking a very long time, do I have to do anything special for that? Please let me know.

Thanks.

Tom Kyte

Followup  

June 16, 2005 - 9:51 pm UTC

well, very little data to go on.

but, grouping by 20 columns probably leads to "lots more records" than grouping by say 2 right.

so, bigger result set, more temp space, more work, more stuff.


tkprof it, preferably with a 10046 level 12 trace and see what you are waiting on (assuming software written this century like 9ir2 so the waits show up nicely in the tkprof report)

June 17, 2005 - 3:55 pm UTC

Reviewer: A reader

Our database is 10g. I setup the session for 10046 trace level 12 and I am attaching below the last part of the tkprof output. Is this what I should be looking at for the wait times. Please let me know and if it is tell me what I should see to determine how to make my query faster.

OVERALL TOTALS FOR ALL NON-RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 8 0.00 0.00 0 0 0 0
Execute 10 0.00 0.02 0 11 10 10
Fetch 5 39.51 427.26 566787 575769 0 10
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 23 39.51 427.30 566787 575780 10 20

Misses in library cache during parse: 5
Misses in library cache during execute: 4

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 12 0.00 0.00
SQL*Net message from client 11 13.07 13.14
direct path write temp 10800 0.02 3.35
db file sequential read 732 0.03 4.49
db file scattered read 38827 0.06 389.03
direct path read temp 22 0.04 0.33


OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 7 0.00 0.00 0 0 0 0
Execute 14 0.01 0.01 0 2 8 8
Fetch 6 0.00 0.00 0 15 0 6
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 27 0.01 0.01 0 17 8 14

Misses in library cache during parse: 6
Misses in library cache during execute: 5

15 user SQL statements in session.
1 internal SQL statements in session.
16 SQL statements in session.
********************************************************************************
Trace file: wicis_ora_1116.trc
Trace file compatibility: 9.00.01
Sort options: default

3 sessions in tracefile.
18 user SQL statements in trace file.
1 internal SQL statements in trace file.
16 SQL statements in trace file.
13 unique SQL statements in trace file.
51339 lines in trace file.

Thanks.


Tom Kyte

Followup  

June 17, 2005 - 4:17 pm UTC

ops$tkyte@ORA9IR2> select 38827/389.03 from dual;
 
38827/389.03
------------
  99.8046423
 
ops$tkyte@ORA9IR2> select 389.03/38827 from dual;
 
389.03/38827
------------
  .010019574


You are doing 100 multiblock io's/second or about 0.01 seconds per IO.  Does that seem "fast or correct" given your hardware?

but therein lies your low hanging fruit, look for the do'ers of IO and see what you can do to have them do less of it. 

June 20, 2005 - 10:50 am UTC

Reviewer: A reader

I am sorry but I am not able to understamd much from your response. Can you elaborate it a little please?

Thanks.

Tom Kyte

Followup  

June 20, 2005 - 12:43 pm UTC

I was saying "you are doing a lot of physical IO, they are taking about 1/100th of a second per IO, is that reasonable for your hardware and have you looked at tuning SQL in order to reduce the number of physical IO's you have to do"



June 20, 2005 - 11:30 am UTC

Reviewer: A reader

Regd the following query from previous followup

select t1.id1, t1.name, t1.id2, max(decode(t2.xxx,'A','A'))
xa, max(decode(t2.xxx,'B','B')) xb 2 from t1, t2
where t1.id2 = t2.id2
group by t1.id1, t1.name, t1.id2
/

I have about 10 mil rows in t2. I have an index on t2(xxx). But it is still doing a table scan and the query results are very slow. Should I create some sort of functional index or something ?

Thanks.


Tom Kyte

Followup  

June 20, 2005 - 12:53 pm UTC

I would be seriously disappointed if it touched an index, if you want slow, make it use an index.


please do this:

a) say out loud "full scans are not evil"
b) say out loud "indexes are not all goodness"
c) goto (a) until you believe what you are saying out loud

read this too:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:6749454952894#6760861174154 <code>


Now, perhaps you are hashing to disk and would benefit from a larger hash_area_size/pga_aggregate_target

June 21, 2005 - 9:04 am UTC

Reviewer: A reader from VA

Ho Tom,

Will you please help me with this. I have a table that looks like below:

col1 col2
---- ----
1 1
2 2
3 3
4 4

I would like a select statement that displays:

col1 col2
---- ----
1 1
2 1
3 1
4 1

In other words, I'd like the value in col2 to show the smallest value of all rows.

Thank you very much.

Tom Kyte

Followup  

June 21, 2005 - 5:01 pm UTC

select col1, min(col2) over () from t;

June 21, 2005 - 2:49 pm UTC

Reviewer: A reader

Hi Tom,

I have the foll requirement:

create table t1
(
datecol date,
idcol1 number,
idcol2 number,
col1 varchar2(20),
charcol char(1),
opcol varchar2(10)
);

I am doing the following queries in a single procedure all based on t1.

select max(datecol), max(idcol1), max(idcol2)
into tdatecol, tidcol1, tidcol2
from t1
where col1 = '1234'
and charcol = 'A';

select max(datecol), max(idcol2)
into tdatecol1, tidcol21
from t1
where idcol1 = tidcol1
and charcol = 'B';

select opcol into topcol
from t1
where idcol2 = tidcol2;

if (tidcol21 is not null) then
select opcol into topcol1
from t1
where idcol2 = tidcol21;
end if;

Is it possible for me to put this all in a single query? Please help.

Thanks.


Tom Kyte

Followup  

June 23, 2005 - 12:03 pm UTC

yes, but I think it would be just layers of scalar subqueries, so not neccessarily anymore efficient.


select tdatecol, tidcol1, tidcol2,
tdatecol1, tidcol21,
(select opcol from t1 c where c.idcol2 = tidcol2) topcol,
case when tidcol21 is not null then
(select opcol from t1 c where c.idcol2 = tidcol21)
end topcol1
from (
select tdatecol, tidcol1, tidcol2,
to_date(substr(trim(data),1,14),'yyyymmddhh24miss') tdatecol1,
to_number(substr(data,15)) tidcol21
from (
select tdatecol, tidcol1, tidcol2,
(select nvl(to_char( max(datecol), 'yyyymmddhh24miss' ),rpad(' ',14)) || max(idcol2)
from t1 b
where b.idcol1 = a.tidcol1
and b.charcol = 'B') data
from (
select max(datecol) tdatecol, max(idcol1) tidcol1, max(idcol2) tidcol2
from t1
where col1 = '1234'
and charcol = 'A'
) A
)
)
/


select col1, min(col2) over () from t;

June 22, 2005 - 11:22 am UTC

Reviewer: A reader from VA

I thank you for your suggestion but how can we do that on an non-enterprise version? Below is what I have:

SQL> select banner from v$version;

BANNER
----------------------------------------------------------
Oracle8i Release 8.1.7.4.1 - Production
PL/SQL Release 8.1.7.4.0 - Production
CORE    8.1.7.2.1       Production
TNS for 32-bit Windows: Version 8.1.7.4.0 - Production
NLSRTL Version 3.4.1.0.0 - Production

and

SQL> select * from v$option
PARAMETER                        VALUE
---------------------------      -----------
...                              ...
OLAP Window Functions            FALSE

I appreciate your help. 

Tom Kyte

Followup  

June 23, 2005 - 1:19 pm UTC

in 9i you have analytics with standard edition

in 8i without them, you are stuck doing things the old fashioned way


select col1, min_col2
from t, (select min(col2) min_col2 from t)


or

select col1, (select min(col2) from t)
from t;



new query

June 22, 2005 - 1:32 pm UTC

Reviewer: Sudha Bhagavatula from Buffalo, NY

I have a table this way:

eff_date term_date contr_type
01/01/2001 01/31/2001 12
01/01/2001 01/31/2001 13

I want the output to be like this:

01/01/2001 01/31/2001 12,13

Can this be done through sql ? I use Oracle 9i

Tom Kyte

Followup  

June 23, 2005 - 1:40 pm UTC

search site for

stragg


Look up Pivot Table

June 23, 2005 - 1:08 pm UTC

Reviewer: DHP from Mobile, AL

Search for Pivot Table or check out this thread:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:766825833740 <code>

select col1, min(col2) over () from t;

June 23, 2005 - 4:52 pm UTC

Reviewer: A reader from VA

That works great! Thanks again for your help.

SQL Anomaly

June 23, 2005 - 5:37 pm UTC

Reviewer: reader

Tom,

I am running this query and every time getting different answer. Is it a bug or feature mind you I am the only one logged in.

2. Does DISTINCT apply only on first following column or all columns in the list? 

Thank you in advance.

  1  SELECT DISTINCT loan_id, program_name
  2  FROM   loan_history
  3* WHERE ROWNUM < 30

14:16:31 SQL> /

LOAN_ID              PROGRAM_NAME
-------------------- ------------------------------
0000000000           FR 15 Yr CF
1111111111           FR 15 Yr CF
2222222222           FR 15 Yr CF
3333333333           FR 15 Yr CF
4444444444           FR 25-30 Yr CF
5555555555           FR CF 20-30 Yr
6666666666           FR 15 Yr CF
7777777777           CMT ARM 3/1 CF (salable)
8888888888           FR 15 Yr CF

9 rows selected.

14:16:34 SQL> l
  1  SELECT DISTINCT loan_id, program_name
  2  FROM   loan_history
  3* WHERE ROWNUM < 30
14:17:22 SQL> /

LOAN_ID              PROGRAM_NAME
-------------------- ------------------------------
5555555555           FR CF 20-30 Yr
4444444444           FR 25-30 Yr CF
0000000000           FR 15 Yr CF
4141414141           30 Yr Fixed FHA/VA - Salable
4444444444           FR 25-30 Yr CF
4141414141           FR 15 Yr CF
5353535353           FR 15 Yr CF
5454545454           FR 25-30 Yr CF
6565656565           FR 25-30 Yr CF
6767676767           FR 15 Yr CF
8787878787           FR 25-30 Yr CF

11 rows selected.

14:17:23 SQL> l
  1  SELECT DISTINCT loan_id, program_name
  2  FROM   loan_history
  3* WHERE ROWNUM < 30
14:17:25 SQL> /

LOAN_ID              PROGRAM_NAME
-------------------- ------------------------------
3232323232           FR 15 Yr CF
3434343434           FR 15 Yr CF
4545454545           FR 15 Yr CF
5656565656           FR 15 Yr CF
6767676767           FR CF 20-30 Yr
7878787878           FR 15 Yr CF
8989898989           FR CF 20-30 Yr

7 rows selected.

14:17:26 SQL> 

Tom Kyte

Followup  

June 23, 2005 - 7:41 pm UTC

no bug, they are all reasonable.

"get 30 rows"
"distinct them"

or better yet:

"get ANY 30 rows"
"distinct them"


what are you trying to do exactly?

Distinct Question

June 24, 2005 - 7:02 pm UTC

Reviewer: reader from CA

Tom,

Essentially query had to answer very simple question "show me all distinct loan ids and programs" but I started testing and could not understand why same query returns different number of rows.
I always thought that selecting ROWNUN returns a sequential number of rows. Why would Oracle select any random number of rows when I asked to show me all 29 or less?

2. Still not clear whether DISTINCT/UNIQUE apply on first column that follows or all columns in the select list following DISTINCT/UNIQUE.

Thank you,

Tom Kyte

Followup  

June 24, 2005 - 9:51 pm UTC

you asked for 29 rows

and then distincted them. It is free to get any 29 rows it wanted to get, and distinct them. It could return anywhere between 0 and 29 rows at any time.


distinct applies to the entire result set, all columns.

RE: Distinct and Group By

June 27, 2005 - 11:57 am UTC

Reviewer: reader from CA

Tom,

1. Would it be safe to say that Distinct is sort of Group By clause? If so how is it internally different or similar?
2. If Oracle is free to give me any number of rows below 30 how would I find out exact count of unique Last Names of occupants in a 100 stories building below 30th floor?

Thanks,

Tom Kyte

Followup  

June 27, 2005 - 1:52 pm UTC

1) grouping by all columns in the select list and using distinct would have the same net effect, yes.

select distinct <100 columns> from table

is a lot easier to type though :)

2) oracle is giving you 30 rows (assuming table has more than 30 rows). exactly thirty rows. then you asked for the distinct rows from that. that could any number of rows less than or 30.

if you had a table with last names and a floor attribute, it would be

select count(distinct last_name)
from t
where floor <= 30

OK

June 28, 2005 - 1:03 pm UTC

Reviewer: Raju from Hyderabad,India

Hi Tom,
My requirement is
"Retrieve all employees from emp table
who have joined before their manager".

I used this query.
Is this correct??
Do you have a better way to put this query??

SQL> select * from emp e
  2  where hiredate <= all(
  3  select hiredate from emp where empno in(select distinct mgr 

from emp)
  4  and deptno = e.deptno)
  5  /

     EMPNO ENAME      JOB              MGR HIREDATE         SAL   

    COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- 

---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        880   

                 20
      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600   

     300         30
      7521 WARD       SALESMAN        7698 22-FEB-81       1250   

     500         30
      7566 JONES      MANAGER         7839 02-APR-81       2975   

                 20
      7698 BLAKE      MANAGER         7839 01-MAY-81       2850   

                 30
      7782 CLARK      MANAGER         7839 09-JUN-81       2450   

                 10

6 rows selected.

 

Tom Kyte

Followup  

June 28, 2005 - 1:20 pm UTC

no.

you are getting all of the employees hired before ALL managers in the deptno they work in. Given the data, it might appear to work -- but there is no rule that says the manager has to work in the same deptno.


I would have joined

select *
from (
select e1.*, e2.hiredate hd2
from emp e1, emp e2
where e1.mgr = e2.empno(+)
)
where hiredate > hd2 or hd2 is null

probably.


query

July 06, 2005 - 11:46 am UTC

Reviewer: mo

Tom:

I have two tables ORG and CONTACT with one to many relationship between them. One organization can have multiple contacts. They are linked using ORGCD.

ORG
-----
orgcd varchar2(10)
name varchar2(100)

Contact
-------
contactid varchar2(20)
orgcd varchar2(10)
contact_type varchar2(1)

Contact type can be either "M" for Main or "A" for additional.

I am trying to get a query to get the organization record with the main contact.

select a.orgcd,a.name,b.contactid from org a, contact b
where a.orgcd=b.orgcd(+) and b.contact_Type='M' and a.orgcd='122';

The problem is that if i have an organization with no main contact I will not get the organzation data.

IF i used contact_Type(+)='M' it gives me all the contacts.

How can you solve this problem?


Tom Kyte

Followup  

July 06, 2005 - 12:33 pm UTC

you already did????

other ways could be

select ...
from org a, ( select * from contact where contact_type = 'M' )b
where a.ordcd = b.orgcd(+) and a.orgcd = '122';

or

select ..
from org a, contact b
here a.orgcd=b.orgcd(+) and (b.contact_Type='M' or b.contact_type is null) and a.orgcd='122'


but what you did is correct and proper.

query

July 06, 2005 - 1:29 pm UTC

Reviewer: mo

Tom:

My query did not give me what I wanted.

When i added (contact_type = 'M' or contact_type is null) it did give me what I want.

Thanks a lot,

the two queries are not equivalent

July 06, 2005 - 5:05 pm UTC

Reviewer: Daniell from Toronto

16:56:30 SCOTT@ora10g > select * from org;

ORGCD
----------
122

Elapsed: 00:00:00.01
16:57:10 SCOTT@ora10g > select * from contact;

ORGCD C
---------- -
122 A

Elapsed: 00:00:00.01
16:57:17 SCOTT@ora10g > select *
16:57:33 2 from org a, ( select * from contact where contact_type = 'M' ) b
16:57:33 3 where a.orgcd = b.orgcd(+) and a.orgcd = '122'
16:57:34 4 /

ORGCD ORGCD C
---------- ---------- -
122

Elapsed: 00:00:00.01
16:57:35 SCOTT@ora10g > select *
16:58:01 2 from org a, contact b
16:58:01 3 where a.orgcd=b.orgcd(+) and (b.contact_Type='M' or b.contact_type
is null) and a.orgcd = '122';

no rows selected

Elapsed: 00:00:00.01

Tom Kyte

Followup  

July 07, 2005 - 8:57 am UTC

you are correct, went too fast.

re-reading, it would appear that

16:57:17 SCOTT@ora10g > select *
16:57:33 2 from org a, ( select * from contact where contact_type = 'M' ) b
16:57:33 3 where a.orgcd = b.orgcd(+) and a.orgcd = '122'
16:57:34 4 /

ORGCD ORGCD C
---------- ---------- -
122

is the most likely thing he wants.

Insert from another table with more number of columns

July 08, 2005 - 12:03 pm UTC

Reviewer: Thiru

Tom,

I am not sure whether my question fits this thread but if you could reply, shall greatly appreciate.

I have a table :
create table temp(a number, b varchar2(10));
Another table :
create table temp_mv
as
select rowid temp_rid,t.* from temp t where 1=2;

This table temp_mv is populated with data basically from the temp table based on varied conditions and then moved to another db where there is a temp table exactly as the one above.
I would like to insert data into the remote temp table from temp_mv but without using the temp_rid column. Is there a way to do this without writing all the columns. As the tables I am trying to do has lots of columns (200+).

insert into remote.temp
select a,b from temp_mv;
(if I use the one like above I will have to specifiy all 200 columns just to avoid the column temp_rid).

Thanks so much for your time.


Tom Kyte

Followup  

July 08, 2005 - 12:59 pm UTC

when faced with "lots of columns", why not just write a piece of code to write the sql from the dictionary -- I do it all of the time.

Other alternative would be to create a one time view without the columns you don't want.

(insert into t select * from another_t -- that is considered a relatively "bad practice", you would be best served with

insert into t ( c1, c2, c3, .... c200 ) select c1, c2, c3, .... c200 from another_t;

You are protected from someone reordering the columns, adding a column, etc over time.

July 08, 2005 - 1:02 pm UTC

Reviewer: Thiru

Thanks. The sql from the dictionary looks comfortable. The column_id is what I have to order by, right?


Tom Kyte

Followup  

July 08, 2005 - 3:02 pm UTC

yes

A different sql question!!

July 12, 2005 - 5:33 am UTC

Reviewer: Eray from Turkey

Tom;
I have question about sql- customizing the order-.Let me give you an example.I am selecting data starts with A,B,C........Z.I want to sort my data A to Z except K.I want my data which starts with K at the end?If I can how I can?

Tom Kyte

Followup  

July 12, 2005 - 4:59 pm UTC

order by decode( column, 'K', 2, 1 ), column



query efficiency

July 13, 2005 - 1:10 pm UTC

Reviewer: J from CA

regarding query efficiency:

is there any resource saving during query execution using sub-query by pre-selecting columns vs. non-subquery?

for instance:

1. select a.col1, b.col2, b.col3
from a, b, c
where join-criteria

2. select a1.col2,a1.col3, b1.col1
from (select a.col2, a.col3 from a ...) a1,
(select b.col1, b.col2 from b ...) b1
where join on a1 and b1

for sure, we have very complex query from our analysts, with join to more than 10 tables, and 2 or 3 or even 4 tables are big table (more than Gb size, 100+ columns, billion records).

Thanks for any suggestion.


Tom Kyte

Followup  

July 13, 2005 - 1:32 pm UTC

no, those two queries are identical to the optimizer.

How to fine tune this query ?

July 14, 2005 - 6:07 am UTC

Reviewer: Parag Jayant Patankar from India

Hi Tom,

I have very large transaction table ( v8spd800 ) which is consisting

branchcd, client no, client sub no, currency, transaction date and transaction amount. I have to give sum of transactions amount bucketwise for a particular month

For e.g.
1. sum of transactions where amt is less than 500000
2. sum of transactions where amt is >= 500000 and less than 1000000

For this I have written following SQL

select
branchname,
branchaddr1,
branchaddr2,
...
..
( select nvl(sum(v08203),0)
from v8spd800, tdf31
where v09000 between substr(c65401,1,6)||'01' and substr(c65401,1,6)||'30'
and v00090 = branchcd
and v09060 < 50000000 ) x1,
( select sum(v08203)
from v8spd800, tdf31
where v09000 between substr(c65401,1,6)||'01' and substr(c65401,1,6)||'30'
and v00090 = branchcd
and v09060 >= 50000000 and v09060 < 100000000) x2,
( select nvl(sum(v08203),0)
from v8spd800, tdf31
where v09000 between substr(c65401,1,6)||'01' and substr(c65401,1,6)||'30'
and v00090 = branchcd
and v09060 >= 100000000 and v09060 < 250000000) x3
from branchmst
/

But I am sure this kind of SQL is not "GOOD" sql because every time it is accessing same table.

Can you show me how to write efficient SQL for having bucketwise total ?

regards & thanks
pjp


Tom Kyte

Followup  

July 14, 2005 - 10:45 am UTC

i'm missing something -- cartesian joins in the scalar subqueries? I cannot tell what comes from where? are the scalar subqueries correlated or standalone?

use correlation names on all columns

SQL Query

July 14, 2005 - 11:08 am UTC

Reviewer: Parag Jayant Patankar

Hi Tom,

Regarding your answer "i'm missing something -- cartesian joins in the scalar subqueries? I cannot
tell what comes from where? are the scalar subqueries correlated or standalone?"

Sorry I was not clear. In my query my transaction table is v8spd600 whic is joinded to tdf31. Table tdf31 is having only dates ( Current Processing Date, Last Processing Date, Last processed month ..etc ) and having only one record. As this query I am going to generate for previous month I have not hardcoded date in my scalar subquery.

Sorry I have not understood your question "Queries or correlated or standalone".

Basically I want "amount bucketwise no of transactions" from transaction table which is havig many transaction records.

regards & thanks
pjp

Tom Kyte

Followup  

July 14, 2005 - 11:26 am UTC

Please correlate the column names for us. In the query. (get used to doing that on a regular basis! )

Like and between

August 02, 2005 - 5:36 pm UTC

Reviewer: arjun from New York

hi:

I need help with framing a Query.

I have two input values 'B' and 'L'

I have to find usernames starting with 'B' and 'L' and also which are between username starting with 'B' and 'L'


Result should have Ben, David , Elina , Henry and Luca
( assuming these names are there in a table )

select * from dba_users where username like 'B%'
.....

Thanks

Tom Kyte

Followup  

August 02, 2005 - 7:22 pm UTC

where username >= 'B' and username < 'M'

Like and between

August 02, 2005 - 5:44 pm UTC

Reviewer: arjun from New York

I tried this : There might be an easier and better approach.

select du.username
from dba_users du ,
( select username from dba_users where username like 'A%' and rownum=1 ) start_tab ,
( select username from dba_users where username like 'S%' and rownum=1 ) end_tab
where du.username between start_tab.username and end_tab.username

II ]

why does this query doesn't return names starting with 'H' I have records starting with 'H'

select *
from dba_users
where username >= 'A%'
and username <= 'H%'
order by username

Thanks

Tom Kyte

Followup  

August 02, 2005 - 7:28 pm UTC

% is only meaningful in "like" as a wildcard.

you want where username >= 'A' and username < 'I'

to get A...H names (in ascii)

Maybe wont hit the first A-user

August 03, 2005 - 5:42 am UTC

Reviewer: Lolle from Sweden

If you use 'user like 'A%' and rownum = 1', you dont know which user you hit, maybe not the first A in alpha-order. In that approach you must add an order by user.

A question for you

August 11, 2005 - 1:08 am UTC

Reviewer: Murali from India

Tom,

I got a table with two columns

Customer Category
C1 1
C2 2
C1 2
C1 3
C2 3
C2 5
C3 4
C4 3
C4 4
C5 1
C5 5
C3 3
C6 1
C6 5

i.e.,
C1 - 1,2,3
C2 - 2,3,5
C3 - 3,4
C4 - 3,4
C5 - 1,5
C6 - 1,5

When I pass category as 1,5
My output should be

C5 and C6 - 1,5
C1 - 1
C2 - 5

If selected categories are 1,3,4,5
The output should be
C1 - 1,3
C2 - 3
C3, C4 - 3,4
C5,C6 - 1,5

Please help me out in this regard.



Tom Kyte

Followup  

August 11, 2005 - 9:32 am UTC

i would, if I had create tables and insert intos.




Random guess

August 11, 2005 - 10:02 am UTC

Reviewer: Bob B from Albany, NY

CREATE TABLE VALS(
p1 VARCHAR2(2),
p2 NUMBER(1)
)
/

INSERT INTO VALS VALUES('C1', 1 );
INSERT INTO VALS VALUES('C2', 2 );
INSERT INTO VALS VALUES('C1', 2 );
INSERT INTO VALS VALUES('C1', 3 );
INSERT INTO VALS VALUES('C2', 3 );
INSERT INTO VALS VALUES('C2', 5 );
INSERT INTO VALS VALUES('C3', 4 );
INSERT INTO VALS VALUES('C4', 3 );
INSERT INTO VALS VALUES('C4', 4 );
INSERT INTO VALS VALUES('C5', 1 );
INSERT INTO VALS VALUES('C5', 5 );
INSERT INTO VALS VALUES('C3', 3 );
INSERT INTO VALS VALUES('C6', 1 );
INSERT INTO VALS VALUES('C6', 5 );

SELECT
DISTINCT
STRAGG( P1 ) OVER ( PARTITION BY P2 ORDER BY P1 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING ) P1,
P2
FROM (
SELECT DISTINCT P1, STRAGG( P2 ) OVER ( PARTITION BY P1 ORDER BY P2 ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING ) P2
FROM VALS
WHERE INSTR( ',' || :p_categories || ',', ',' || p2 || ',' ) > 0
)
ORDER BY P1

Works in 10gR1. STRAGG as defined here:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:2196162600402 <code>

Don't know if the datatypes are correct or if this will perform nicely. The format of the output wasn't clear either:

C1 and C2 ...
C1,C2 ...
C1, C2 ...

I'm not going to even try to figure that one out.

Tom Kyte

Followup  

August 11, 2005 - 6:10 pm UTC

I would have used stragg and str2tbl, something like:

select cusomter, stragg( category )
from ( select customer, category
from t
where category in (select * from TABLE(str2tbl(:x)))
)
group by customer


where :x := '1, 2, 3, 4' or whatever.

Two different answers to the same question

August 11, 2005 - 10:31 pm UTC

Reviewer: Bob B from Albany, NY

Depends on whether the customers need to be grouped by their category list or not.

One query returns each customer and a list of their categories; the other returns each list of categories and the list of customers that match that list.

One Query

August 12, 2005 - 12:01 am UTC

Reviewer: Murali from India

Hello Tom,
First of all, thanks Bob for creating those insert stmts for me. So very nice of you. And secondly, I need a generic function kind of a thing where in you pass in the Category and I would need the output as mentioned earlier. I would want to use this function in Sybase, Sql Server and MySql without making much changes. Please help me out in this regard.




Tom Kyte

Followup  

August 12, 2005 - 8:37 am UTC

rolling on the floor laughing. (also known as ROTFL)....


sorry, don't see that happening.

On the topic of database independence ...

August 12, 2005 - 11:28 am UTC

Reviewer: Bob B from Albany, NY

Why even pick a programming language for application development? I say we should not only be database neutral, but programming language neutral! What happens if Java is no longer supported or PHP developers become too expensive or ASP.net can no longer deliver the performance we need (etc)? Instead, lets write (lots of) code that will compile in any programming language. *dripping sarcasm*

Being database neutral means you have to write an application in several different languages that needs to do the same thing in about the same time in all of them. I doubt anyone would try to write an app that works in more than one programming language (maybe for fun, but not for a living). You'll see much of the same language and syntax in many languages:

for, while, try/catch/finally, switch, function, (), {}, ;, etc

Same thing for databases:
select, update, delete, from, where, and, or, group by, order by, etc

Query

August 15, 2005 - 2:59 pm UTC

Reviewer: mo

Tom:

I have this query that counts total of records based on a field value of "Null" or "Open". However I find out that query does not work for nulls and it should be where field is null instead of equal sign.

Do I need to create 2 queries and write an IF statement or there is a wa to do this in one query?

IF (i_link_id = 12) THEN
v_request_status := null;
elsif (i_link_id = 13) THEN
v_request_status := 'Open';
END IF;

SELECT count(*) into re_count
FROM parts_request a
WHERE a.user_id = i_user_id and
a.request_status = v_request_status and
not exists (select request_id from parts_shipment b where a.request_id = b.request_id);

Tom Kyte

Followup  

August 15, 2005 - 10:33 pm UTC

in the following, pretend y is user_id and z is request_status, you can union all the "two" queries and then count.  Only one part really executes at run time based on the bind variable sent in


ops$tkyte@ORA9IR2> create table t ( x int primary key, y int, z int );

Table created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> insert into t
  2  select rownum, trunc(rownum/10), case when mod(rownum,10) = 0 then null else 1 end
  3  from all_objects;

27991 rows created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create index t_idx on t(y,z);

Index created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec dbms_stats.gather_table_stats( user, 'T' );

PL/SQL procedure successfully completed.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> variable y number
ops$tkyte@ORA9IR2> variable z number
ops$tkyte@ORA9IR2> @plan "select count(*) from (select x from t where y = :y and z = :z union all select x from t where y = :y and z is null and :z is null)"
ops$tkyte@ORA9IR2> delete from plan_table;

7 rows deleted.

ops$tkyte@ORA9IR2> explain plan for &1;
old   1: explain plan for &1
new   1: explain plan for select count(*) from (select x from t where y = :y and z = :z union all select x from t where y = :y and z is null and :z is null)

Explained.

ops$tkyte@ORA9IR2> select * from table(dbms_xplan.display);

PLAN_TABLE_OUTPUT
-------------------------------------------------------------------------------

--------------------------------------------------------------------
| Id  | Operation            |  Name       | Rows  | Bytes | Cost  |
--------------------------------------------------------------------
|   0 | SELECT STATEMENT     |             |     1 |       |     3 |
|   1 |  SORT AGGREGATE      |             |     1 |       |       |
|   2 |   VIEW               |             |    10 |       |     3 |
|   3 |    UNION-ALL         |             |       |       |       |
|*  4 |     INDEX RANGE SCAN | T_IDX       |     9 |    63 |     1 |
|*  5 |     FILTER           |             |       |       |       |
|*  6 |      INDEX RANGE SCAN| T_IDX       |     1 |     7 |     2 |
--------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

   4 - access("T"."Y"=TO_NUMBER(:Z) AND "T"."Z"=TO_NUMBER(:Z))
   5 - filter(:Z IS NULL)
   6 - access("T"."Y"=TO_NUMBER(:Z) AND "T"."Z" IS NULL)

Note: cpu costing is off

21 rows selected.
 

query

August 17, 2005 - 6:29 pm UTC

Reviewer: mo

Tom:

You are right. I was going to use a ref cursor for the query but your method here is easier.

FOR y in (
select x from t where user_id = i_user_id and request_status = v_request_status
union all
select x from t where user_id = i_user_id and request_status is null and v_request_status is null )
LOOP
...
END LOOP;

error

September 19, 2005 - 8:31 am UTC

Reviewer: khaterali from india

VERSION INFORMATION:
TNS for Solaris: Version 8.1.7.0.0 - Production
Oracle Bequeath NT Protocol Adapter for Solaris: Version 8.1.7.0.0 - Production
Time: 17-SEP-2005 12:07:36
Tracing not turned on.
Tns error struct:
nr err code: 0
ns main err code: 12547
TNS-12547: TNS:lost contact
ns secondary err code: 12560
nt main err code: 517
TNS-00517: Lost contact
nt secondary err code: 32
nt OS err code: 0


***********************************************************************
Fatal NI connect error 12547, connecting to:
(DESCRIPTION=(ADDRESS=(PROTOCOL=beq)(PROGRAM=/u01/app/oracle/product/8.1.7/bin/oracle)(ARGV0=oracleehrd
ev)(ARGS='(DESCRIPTION=(LOCAL=YES)(ADDRESS=(PROTOCOL=beq)))')(DETACH=NO))(CONNECT_DATA=(CID=(PROGRAM=)(H
OST=sparc)(USER=oracle))))

VERSION INFORMATION:
TNS for Solaris: Version 8.1.7.0.0 - Production
Oracle Bequeath NT Protocol Adapter for Solaris: Version 8.1.7.0.0 - Production
Time: 17-SEP-2005 12:07:42
Tracing not turned on.
hsperfdata_root Tns error struct:
nr err code: 0
ns main err code: 12547
TNS-12547: TNS:lost contact
ns secondary err code: 12560
nt main err code: 517
TNS-00517: Lost contact
nt secondary err code: 32
nt OS err code: 0


***********************************************************************
Fatal NI connect error 12547, connecting to:
(DESCRIPTION=(ADDRESS=(PROTOCOL=beq)(PROGRAM=/u01/app/oracle/product/8.1.7/bin/oracle)(ARGV0=oracleehrd
ev)(ARGS='(DESCRIPTION=(LOCAL=YES)(ADDRESS=(PROTOCOL=beq)))')(DETACH=NO))(CONNECT_DATA=(CID=(PROGRAM=)(H
OST=sparc)(USER=oracle))))

VERSION INFORMATION:
TNS for Solaris: Version 8.1.7.0.0 - Production
Oracle Bequeath NT Protocol Adapter for Solaris: Version 8.1.7.0.0 - Production
Time: 17-SEP-2005 12:07:42
Tracing not turned on.
Tns error struct:
nr err code: 0
ns main err code: 12547
TNS-12547: TNS:lost contact
ns secondary err code: 12560
nt main err code: 517
TNS-00517: Lost contact
nt secondary err code: 32
nt OS err code: 0


Tom Kyte

Followup  

September 19, 2005 - 11:49 am UTC

please open an itar - I see the other two postings below as well -- an itar is what you want, not a forum discussion question

errror in exp -00084

September 19, 2005 - 9:02 am UTC

Reviewer: khater ali from india

Export fails with EXP-00084: Unexpected DbmsJava error -1031 at step 6661

Running FULL export on Oracle 8.1.5 database on son solaris 8 Export starts OK, dumps tables under all schemas, then fails with the following errors:

...
. exporting referential integrity constraints
. exporting synonyms
. exporting views
. exporting stored procedures
EXP-00084: Unexpected DbmsJava error -1031 at step 6661
EXP-00008: ORACLE error 1031 encountered
ORA-01031: insufficient privileges
EXP-00000: Export terminated unsuccessfully
how to solve the above problem also i already posted this question in metalink.oracle.com but there is no responsible .please help me

errror in exp -00084

September 19, 2005 - 9:03 am UTC

Reviewer: khater ali from india

Export fails with EXP-00084: Unexpected DbmsJava error -1031 at step 6661

Running FULL export on Oracle 8.1.7 database on son solaris 8 Export starts OK, dumps tables under all schemas, then fails with the following errors:

...
. exporting referential integrity constraints
. exporting synonyms
. exporting views
. exporting stored procedures
EXP-00084: Unexpected DbmsJava error -1031 at step 6661
EXP-00008: ORACLE error 1031 encountered
ORA-01031: insufficient privileges
EXP-00000: Export terminated unsuccessfully
how to solve the above problem also i already posted this question in metalink.oracle.com but there is no responsible .please help me

sqlnet

September 20, 2005 - 12:13 am UTC

Reviewer: khater ali from india

Fatal NI connect error 12547, connecting to:
(DESCRIPTION=(ADDRESS=(PROTOCOL=beq)(PROGRAM=/u01/app/oracle/product/8.1.7/bin/oracle)(ARGV0=oracleehrd
ev)(ARGS='(DESCRIPTION=(LOCAL=YES)(ADDRESS=(PROTOCOL=beq)))')(DETACH=NO))(CONNECT_DATA=(CID=(PROGRAM=)(H
OST=sparc)(USER=oracle))))

VERSION INFORMATION:
TNS for Solaris: Version 8.1.7.0.0 - Production
Oracle Bequeath NT Protocol Adapter for Solaris: Version 8.1.7.0.0 - Production
Time: 17-SEP-2005 12:07:42
Tracing not turned on.
hsperfdata_root Tns error struct:
nr err code: 0
ns main err code: 12547
TNS-12547: TNS:lost contact
ns secondary err code: 12560
nt main err code: 517
TNS-00517: Lost contact
nt secondary err code: 32
nt OS err code: 0

please give some suggestions to solve the above problems.our version is 8.1.7 and our os is sun solaris 8

Tom Kyte

Followup  

September 20, 2005 - 12:20 am UTC

please see my original comment.

Table value

September 21, 2005 - 3:55 am UTC

Reviewer: Tony from USA

Hi Tom,

I am inserting the values to the table from one big sql statement.

The sql statement can change in the future.. so I inserted the sql in the table and taking the value from the table I am doing the ref cursor and inserting but the problem is the query take some parameters so dynamically how can I send the parameter..

bellow is the procedure please guide me on the same..

pmonth is the parameter which i am passing to the SQL.....

CREATE OR REPLACE PROCEDURE CMPR_LOAD_test(CNTRYCDE IN VARCHAR2,
PMONTH IN VARCHAR2,
ERR_CD IN OUT NUMBER,
ERR_TEXT IN OUT VARCHAR2) IS
LN_ROWS NUMBER(7) := '500';
TYPE CMPREXT IS TABLE OF DRI_276_CMPR%ROWTYPE;
CMPRRECS CMPREXT;
TYPE CMPR_REF_CUR IS REF CURSOR;

CMPRCUR CMPR_REF_CUR;
sql_text long;

BEGIN
select sql_value into sql_text from cmpr_sql_text;

OPEN CMPRCUR for sql_text;
LOOP
FETCH CMPRCUR BULK COLLECT
INTO CMPRRECS LIMIT LN_ROWS;
BEGIN
FORALL I IN CMPRRECS.FIRST .. CMPRRECS.LAST
INSERT INTO DRI_276_CMPR VALUES CMPRRECS (I);
EXCEPTION
WHEN OTHERS THEN
ERR_CD := SQLCODE;
ERR_TEXT := 'Sp_Ins_Ext_Mthly_test : Error IN INSERTING INTO TABLE DRI_276_ECS_MISEXT' ||SQLERRM;
RETURN;
END;
EXIT WHEN CMPRCUR%NOTFOUND;
COMMIT;
END LOOP;
CLOSE CMPRCUR;
COMMIT;
END CMPR_LOAD_test;

/

Tom Kyte

Followup  

September 21, 2005 - 7:01 pm UTC

why is this procedure a procedure and not just an INSERT into table SELECT from another table???????

Your logic scares me to death.


You load some records (say the first 2 500 row batches)....

You hit an error on row 1023

You catch the error and basically ignore it (leaving the first two batches sort of hanging out???)

and return.....


Please, just make this an insert into select whatever from and lose all procedural code and don't use "when others" unless you follow it by RAISE;

characterset

September 23, 2005 - 8:37 am UTC

Reviewer: khater ali from india

how to change a characterset for example i have a database called hsusdev and my characterset is us7ascii and now i want to change my characterset to UTF8.one of my friend told me that, recreate the control file.my question is, is there any other option to change my db characterset without recreating the controlfile and now we are inserting xml tables in this database

Tom Kyte

Followup  

September 23, 2005 - 9:43 am UTC

</code> http://docs.oracle.com/docs/cd/B10501_01/server.920/a96529/ch2.htm#101203 <code>

it is not a controlfile rebuild operation.

You'll want to check out that document in its entirety

You are the best and I know this is the only place in the whole world where I will get the answer..

September 23, 2005 - 3:29 pm UTC

Reviewer: A reader from VA

I have similar row to coloum question (like the original post ).Please help.

create table temp_fluids
(code varchar2(13), name varchar2(10), percent number)
/
SQL> desc temp_fluids
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 CODE                                               VARCHAR2(13)
 NAME                                               VARCHAR2(10)
 PERCENT                                            NUMBER


insert into temp_fluids
values ('CODE1','NAME1',10)
/
insert into temp_fluids
values ('CODE1','NAME2',20)
/
insert into temp_fluids
values ('CODE1','NAME3',30)
/
insert into temp_fluids
values ('CODE2','NAME1',10)
/
insert into temp_fluids
values ('CODE2','NAME2',20)
/
insert into temp_fluids
values ('CODE2','NAME3',30)
/
insert into temp_fluids
values ('CODE2','NAME4',40)
/
insert into temp_fluids
values ('CODE3','NAME1',10)
/


Want output something like :

       code1    code2  code3

name1   10      10      10
 
name2   20      20

name3   30      30

name4           40 

Where number of columns (code1, code2 etc) may go up to more than 100 depending on the number of records.

Thanks! 

Tom Kyte

Followup  

September 23, 2005 - 8:51 pm UTC

search this site for PIVOT to see examples of pivots

and remember a sql query has a fixed number of columns in it, you'll have 100 "max(decodes( ... ) )"

SQL QUERY problem

September 24, 2005 - 4:28 pm UTC

Reviewer: Rmais from pak

Hi Tom,
I have problems writing a difficult sql query, please help me
I have a table t in which there are 50000 records 
the table has columns like 

create table t 
(MATCH_ID    NUMBER(4) NOT NULL,
TEAM_ID         NUMBER(4), 
PLAYER_ID    NUMBER(4),
RUNS    NUMBER(3))

here match_id, player_id and team_id are jointly primary key

SQL> SELECT * FORM T WHERE MATCH_ID < 4

/

 MATCH_ID    TEAM_ID      PL_ID RUNS
--------- ---------- ---------- -------------------
        1          2       1228 8
        1          2       1203 82
        1          2       1316 24
        1          1       1150 27
        1          1       1278 13
        1          1       1243 60
        2          1       1278 37
        2          1       1291 0
        2          1       1243 53
        2          2       1228 25
        2          2       1285 103
        2          2       1316 60
        3          2       1228 8
        3          2       1285 25
        3          2        858 43
        3          1       1278 52
        3          1       1394 6
        3          1       1243 31
        4          1       1278 61
        4          1       1394 6
        4          1       1243 3
        4          2       1228 41
        4          2       1285 40
        4          2        858 5
        6          2       1228 20
        6          2       1285 100
        6          2       1408 0
        7          2       1228 15
        7          2       1285 34
        7          2       1408 44
        8          2       1228 0
        8          2       1420 31
        8          2       1340 66
        9          2       1420 19
        9          2       1385 28
        9          2       1340 0

.....so on upto 50000 records..

the problem is that I want to extract how many times each player_id in each 

match exists in the table, prior to that match_id (or current_match_id)

along with that in another column, I also want the sum of 'RUNS' for each 

player_id  prior to that match_id (or current_match_id)



my disired output is:


 MATCH_ID    TEAM_ID   player_ID RUNS   NO_OF_OCCURENCES    SUM(RUNS)
                                       BEFORE_THIS_MATCH   BEFORE_THIS_MATCH
                                       FOR_THIS_PLAYER_ID  FOR_THIS_PLAYER_ID
--------- ---------- ---------- -------------------
        1          2       1228 8      0                   0
        1          2       1203 82     0                   0
        1          2       1316 24     0                   0
        1          1       1150 27     0                   0
        1          1       1278 13     0                   0
        1          1       1243 60     0                   0
        2          1       1278 37     1                   13
        2          1       1291 0      0                   0
        2          1       1243 53     1                   60 
        2          2       1228 25     1                   8
        2          2       1285 103    0                   0 
        2          2       1316 60     1                   24
        3          2       1228 8      2                   33
        3          2       1285 25     1                   103
        3          2        858 43     0                   0
        3          1       1278 52     2                   50
        3          1       1394 6      0                   0
        3          1       1243 31     2                   113
        4          1       1278 61     3                   102 
        4          1       1394 6      1                   6
        4          1       1243 3      3                   144
        4          2       1228 41     3                   41
        4          2       1285 40     2                   128
        4          2        858 5      1                   43
        6          2       1228 20     4                   82
        6          2       1285 100    3                   168
        6          2       1408 0      0                   0
        7          2       1228 15     5                   102
        7          2       1285 34     4                   268
        7          2       1408 44     1                   0
        8          2       1228 0      6                   117
        8          2       1420 31     0                   0
        8          2       1340 66     0                   0
        9          2       1420 19     1                   31
        9          2       1385 28     0                   0
        9          2       1340 0      1                   66


as you can see from the above data (5TH COLUMN), i have mentioned the 

existance of each player_id in each match prior to the current_match_id

since match_id = 1 is the 1st match in the table so no player_id comes in the 

table before match number 1    

in match number 2 , player_id = 1278 was also present in match_id = 1 so 

thats why Number_OF_OCCURENCES = 1 for  player_id = 1278 in match_id = 2 

and so on.. 

same is the case with 'RUNS' column but here RUNS are the SUM of each 

player_id's 'RUNS' before the current match


Note: if some player_id does not exist in the table before the current 

match_ID then the query should return zero for that player_id ( as in 4th and 

5th columns of no_of_occurances and sum(runs) respectively)

for example: in above data

MATCH_ID    TEAM_ID  PLayer_ID RUNS   NO_OF_OCCURENCES    SUM(RUNS)
                                      BEFORE_THIS_MATCH   BEFORE_THIS_MATCH
                                      FOR_THIS_PLAYER_ID  FOR_THIS_PLAYER_ID
       9          2       1385 28     0                   0


I hope this will clear my problem
i would be extremely grateful if you help me out??




here is sample ddl of the above data

create table t 
(MATCH_ID    NUMBER(4) NOT NULL,
TEAM_ID         NUMBER(4), 
PLAYER_ID    NUMBER(4),
RUNS    NUMBER(3))


insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 2, 1228, 8);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 2, 1203, 82);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 2, 1316, 24);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 1, 1150, 27);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 1, 1278, 13);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (1, 1, 1243, 60);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 1, 1278, 37);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 1, 1291, 0);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 1, 1243, 53);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 2, 1228, 25);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 2, 1285, 103);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (2, 2, 1316, 60);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 2, 1228, 8);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 2, 1285, 25);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 2, 858, 43);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 1, 1278, 52);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 1, 1394, 6);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (3, 1, 1243, 31);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 1, 1278, 61);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 1, 1394, 6);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 1, 1243, 3);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 2, 1228, 41);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 2, 1285, 40);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (4, 2, 858, 5);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (6, 2, 1228, 20);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (6, 2, 1285, 100);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (6, 2, 1408, 0);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (7, 2, 1228, 15);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (7, 2, 1285, 34);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (7, 2, 1408, 44);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (8, 2, 1228, 0);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (8, 2, 1420, 31);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (8, 2, 1340, 66);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (9, 2, 1420, 19);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values  (9, 2, 1385, 28);
insert into t (MATCH_ID, TEAM_ID, PLAYER_ID, RUNS) values (9, 2, 1340, 0);


regards
ramis.

               

Tom Kyte

Followup  

September 24, 2005 - 8:26 pm UTC

It was a bit hard to follow, but I believe you want this:

ops$tkyte@ORA10G> select match_id, team_id, player_id, runs,
  2         count(*) over (partition by player_id order by match_id)-1 cnt,
  3         sum(runs) over (partition by player_id order by match_id)-runs runs_tot
  4    from t
  5   order by match_id, player_id
  6  /
 
  MATCH_ID    TEAM_ID  PLAYER_ID       RUNS        CNT   RUNS_TOT
---------- ---------- ---------- ---------- ---------- ----------
         1          1       1150         27          0          0
         1          2       1203         82          0          0
         1          2       1228          8          0          0
         1          1       1243         60          0          0
         1          1       1278         13          0          0
         1          2       1316         24          0          0
         2          2       1228         25          1          8
         2          1       1243         53          1         60
         2          1       1278         37          1         13
         2          2       1285        103          0          0
         2          1       1291          0          0          0
         2          2       1316         60          1         24
         3          2        858         43          0          0
         3          2       1228          8          2         33
         3          1       1243         31          2        113
         3          1       1278         52          2         50
         3          2       1285         25          1        103
         3          1       1394          6          0          0
         4          2        858          5          1         43
         4          2       1228         41          3         41
         4          1       1243          3          3        144
         4          1       1278         61          3        102
         4          2       1285         40          2        128
         4          1       1394          6          1          6
         6          2       1228         20          4         82
         6          2       1285        100          3        168
         6          2       1408          0          0          0
         7          2       1228         15          5        102
         7          2       1285         34          4        268
         7          2       1408         44          1          0
         8          2       1228          0          6        117
         8          2       1340         66          0          0
         8          2       1420         31          0          0
         9          2       1340          0          1         66
         9          2       1385         28          0          0
         9          2       1420         19          1         31
 
36 rows selected.
 
 

compare two tables

September 25, 2005 - 3:09 am UTC

Reviewer: Bhavesh Ghodasara from Junagadh,Gujarat,India

Hi tom,
I have two tables with same structure but different data..
say : t and t_log
when user make changes in t the old data stored in t_log..
now i want to make a report in which i have to display only the columns of t that is changed..
and dont want to hardcoded comparision like t.a=t_log.a
because i have 96 columns..
so how can I get columns only which are changed..
for example:
column_name oldvalue newvalue
a 0 1
Is it possible by just sql query or i have to do it by pl/sql..
thanks in advance
BHavesh

Tom Kyte

Followup  

September 25, 2005 - 9:32 am UTC

well, I will not promise this technique scales up, but I've used this many a time to compare rows column/column down the page:


ops$tkyte@ORA10G> create or replace type myScalarType as object
  2  ( rnum number, cname varchar2(30), val varchar2(4000) )
  3  /
 
Type created.
 
ops$tkyte@ORA10G> create or replace type myTableType as table of myScalarType
  2  /
 
Type created.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> create or replace
  2  function cols_as_rows( p_query in varchar2 ) return myTableType
  3  -- this function is designed to be installed ONCE per database, and
  4  -- it is nice to have ROLES active for the dynamic sql, hence the
  5  -- AUTHID CURRENT_USER
  6  authid current_user
  7  -- this function is a pipelined function -- meaning, it'll send
  8  -- rows back to the client before getting the last row itself
  9  -- in 8i, we cannot do this
 10  PIPELINED
 11  as
 12      l_theCursor     integer default dbms_sql.open_cursor;
 13      l_columnValue   varchar2(4000);
 14      l_status        integer;
 15      l_colCnt        number default 0;
 16      l_descTbl       dbms_sql.desc_tab;
 17      l_rnum          number := 1;
 18  begin
 19          -- parse, describe and define the query.  Note, unlike print_table
 20          -- i am not altering the session in this routine.  the
 21          -- caller would use TO_CHAR() on dates to format and if they
 22          -- want, they would set cursor_sharing.  This routine would
 23          -- be called rather infrequently, I did not see the need
 24          -- to set cursor sharing therefore.
 25      dbms_sql.parse(  l_theCursor,  p_query, dbms_sql.native );
 26      dbms_sql.describe_columns( l_theCursor, l_colCnt, l_descTbl );
 27      for i in 1 .. l_colCnt loop
 28          dbms_sql.define_column( l_theCursor, i, l_columnValue, 4000 );
 29      end loop;
 30
 31          -- Now, execute the query and fetch the rows.  Iterate over
 32          -- the columns and "pipe" each column out as a separate row
 33          -- in the loop.  increment the row counter after each
 34          -- dbms_sql row
 35      l_status := dbms_sql.execute(l_theCursor);
 36      while ( dbms_sql.fetch_rows(l_theCursor) > 0 )
 37      loop
 38          for i in 1 .. l_colCnt
 39          loop
 40              dbms_sql.column_value( l_theCursor, i, l_columnValue );
 41              pipe row
 42              (myScalarType( l_rnum, l_descTbl(i).col_name, l_columnValue ));
 43          end loop;
 44          l_rnum := l_rnum+1;
 45      end loop;
 46
 47          -- clean up and return...
 48      dbms_sql.close_cursor(l_theCursor);
 49      return;
 50  end cols_as_rows;
 51  /
 
Function created.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> select *
  2    from TABLE( cols_as_rows('select *
  3                                from emp
  4                               where rownum = 1') );
 
      RNUM CNAME           VAL
---------- --------------- --------------------
         1 EMPNO           7369
         1 ENAME           SMITH
         1 JOB             CLERK
         1 MGR             7902
         1 HIREDATE        17-dec-1980 00:00:00
         1 SAL             800
         1 COMM
         1 DEPTNO          20
 
8 rows selected.


<b>Now, to see how you can use it:</b>


ops$tkyte@ORA10G> create table emp as select * from scott.emp;
 
Table created.
 
ops$tkyte@ORA10G> create table emp2 as select * from scott.emp;
 
Table created.
 
ops$tkyte@ORA10G> update emp2 set ename = lower(ename) where mod(empno,3) = 0;
 
7 rows updated.
 
ops$tkyte@ORA10G> commit;
 
Commit complete.
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> alter session set nls_date_format ='dd-mon-yyyy hh24:mi:ss';
 
Session altered.
 
 
ops$tkyte@ORA10G>
ops$tkyte@ORA10G> select a.pk, a.cname, a.val, b.val
  2    from (
  3  select cname, val,
  4         max(case when cname='EMPNO' then val end) over (partition by rnum) pk
  5  from table( cols_as_rows( 'select * from emp' ) ) x
  6         ) A,
  7             (
  8  select cname, val,
  9         max(case when cname='EMPNO' then val end) over (partition by rnum) pk
 10  from table( cols_as_rows( 'select * from emp2' ) ) x
 11         ) B
 12   where a.pk = b.pk
 13     and a.cname = b.cname
 14     and decode( a.val, b.val, 0, 1 ) = 1
 15  /
 
PK                   CNAME           VAL                  VAL
-------------------- --------------- -------------------- --------------------
7521                 ENAME           WARD                 ward
7566                 ENAME           JONES                jones
7698                 ENAME           BLAKE                blake
7782                 ENAME           CLARK                clark
7788                 ENAME           SCOTT                scott
7839                 ENAME           KING                 king
7902                 ENAME           FORD                 ford
 
7 rows selected.
 
ops$tkyte@ORA10G>

<b>We had to carry the primary key down by RNUM (by original row) and join primary key+cname to primary key+cname - decode is an easy way to compare columns, even when null.


You can see and obvious enhancement you can make for your specific case, the cols_as_rows function can easily output the primary key (modify the type, add an attribute and output it) so you can skip the analytic.

Yes, there are other ways to transpose a table using a cartesian join to a table with 96 rows and decode, but this is something I had sitting around</b>
 

thanks

September 25, 2005 - 10:03 am UTC

Reviewer: Bhavesh Ghodasara from Junagadh,Gujarat,India

hi tom,
thanks a lot...you are simpally oracle GOD..
I spend my whole sunday behind this question..i try to do it by pl/sql like create two cursors and compare the value and insert into intermidiate table...
but your solutions looks lot better then it and its also genralized...
but i dont know much about pipelined function but just going to read tonight..
I have problem when run this query :
SELECT *
FROM TABLE( cols_as_rows('select *
FROM emp
WHERE ROWNUM = 1') );

ORA-22905: cannot access rows from a non-nested table item

what is table??
by the way we are using here 10g version :10.1.0.2.0

Bhavesh.

Tom Kyte

Followup  

September 25, 2005 - 10:46 am UTC

No one has that title - really.



Table is builtin - part of SQL - but I ran the example in 10.1, did you use my code "as is"?

Sql query

September 26, 2005 - 4:43 am UTC

Reviewer: Jagadeesh Tata from Hyderabad, India

Hi Tom,

I have the following requirement. I have a query as

SELECT A.RESULT_CODE
FROM JTF_IH_RESULTS_TL A,JTF_IH_WRAP_UPS B
WHERE A.RESULT_ID = B.RESULT_ID
AND A.RESULT_CODE IN (
'Billing',
'Voice Service/ Feature Related',
'WAP Corporate Directory')

I want to get the value that is not in the table.

Say for example 'Billing' is not available in table. I want to get the data using a sql statement.

Thanks and Regards,
Jagadeesh Tata



Tom Kyte

Followup  

September 26, 2005 - 9:15 am UTC

does not make sense to me yet......

SQL - HOW TO WRITE

September 26, 2005 - 6:42 am UTC

Reviewer: VIKAS SANGAR from INDIA

Dear Mr. Kyte

Can you pls, kindly help me out with a query that I am trying to work out, to get the following output...

Suppose in my database, I have a Table T1 with its Columns as c1, c2 and c3, and a few rows of records such as, for example Row1 has the data set for above three columns as c1=a, c2=b, c3=c, now I want to write a query based on this Table, the out put of which comes out as:-

Column_name dummy Records
------------- ------- --------
c1 := a
c2 := b
c3 := c

3 Rows selected.

Can you pls suggest, me a way as for how to achive the above output.

Take care, regards...
Vikas.


Tom Kyte

Followup  

September 26, 2005 - 9:23 am UTC

don't get it, i don't know what is really in the table in the first place.

you need a create table and insert into for me to play with.

September 26, 2005 - 8:24 am UTC

Reviewer: Bhavesh Ghodasara from Junagadh,Gujarat,India

hi tom,
yes I use yours code as it is..
with no changes.
Bhavesh.

Tom Kyte

Followup  

September 26, 2005 - 9:37 am UTC

demonstrate for me, create your table with as few columns as possible, insert as little data as you can to simulate the issue and show me what you mean.

September 26, 2005 - 9:24 am UTC

Reviewer: A reader from VA

Thanks Tom! In our real case , we don't know the value of CODE yet (it can be anything ) then how can we write the different decodes ? 


SQL> ed
Wrote file afiedt.buf

  1  select name, max(decode(code,'CODE1',percent,null)) code1,
  2   max(decode(code,'CODE2',percent,null)) code2 ,
  3   max(decode(code,'CODE3',percent,null)) code3,
  4   max(decode(code,'CODE4',percent,null)) code4
  5  from temp_fluids
  6* group by name
SQL> /

NAME            CODE1      CODE2      CODE3      CODE4
---------- ---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40
 

Tom Kyte

Followup  

September 26, 2005 - 9:38 am UTC

you have to run a query then, to get the codes, and then construct the query based on that output and execute it.

which rights I required??

September 26, 2005 - 9:58 am UTC

Reviewer: Bhavesh Ghodasara from Junagadh,Gujarat,India

hi tom,

SQL>  CREATE TABLE t
  2   (
  3        empno NUMBER PRIMARY KEY,
  4       ename VARCHAR2(10)
  5   );

Table created.

SQL> insert into t values(1,'Bhavesh');

1 row created.

SQL> insert into t values(2,'Tom');

1 row created.

SQL> insert into t values(3,'Rahul');

1 row created.

SQL> create table t_log
  2  as select * from t;

Table created.



SQL> create or replace type myTableType as table of myScalarType;
  2  /

Type created.

SQL> CREATE OR REPLACE
  2      FUNCTION Cols_As_Rows( p_query IN VARCHAR2 ) RETURN myTableType
  3      -- this function is designed to be installed ONCE per database, and
  4      -- it is nice to have ROLES active for the dynamic sql, hence the
  5      -- AUTHID CURRENT_USER
  6      authid current_user
  7      -- this function is a pipelined function -- meaning, it'll send
  8      -- rows back to the client before getting the last row itself
  9      -- in 8i, we cannot do this
 10     PIPELINED
 11     AS
 12         l_theCursor     INTEGER DEFAULT dbms_sql.open_cursor;
 13         l_columnValue   VARCHAR2(4000);
 14         l_status        INTEGER;
 15         l_colCnt        NUMBER DEFAULT 0;
 16         l_descTbl       dbms_sql.desc_tab;
 17         l_rnum          NUMBER := 1;
 18     BEGIN
 19             -- parse, describe and define the query.  Note, unlike print_table
 20             -- i am not altering the session in this routine.  the
 21             -- caller would use TO_CHAR() on dates to format and if they
 22             -- want, they would set cursor_sharing.  This routine would
 23             -- be called rather infrequently, I did not see the need
 24             -- to set cursor sharing therefore.
 25         dbms_sql.parse(  l_theCursor,  p_query, dbms_sql.native );
 26         dbms_sql.describe_columns( l_theCursor, l_colCnt, l_descTbl );
 27         FOR i IN 1 .. l_colCnt LOOP
 28             dbms_sql.define_column( l_theCursor, i, l_columnValue, 4000 );
 29         END LOOP;
 30   
 31             -- Now, execute the query and fetch the rows.  Iterate over
 32             -- the columns and "pipe" each column out as a separate row
 33             -- in the loop.  increment the row counter after each
 34             -- dbms_sql row
 35         l_status := dbms_sql.EXECUTE(l_theCursor);
 36         WHILE ( dbms_sql.fetch_rows(l_theCursor) > 0 )
 37         LOOP
 38             FOR i IN 1 .. l_colCnt
 39             LOOP
 40                dbms_sql.column_value( l_theCursor, i, l_columnValue );
 41                 pipe ROW
 42                 (myScalarType( l_rnum, l_descTbl(i).col_name, l_columnValue ));
 43             END LOOP;
 44             l_rnum := l_rnum+1;
 45         END LOOP;
 46   
 47             -- clean up and return...
 48         dbms_sql.close_cursor(l_theCursor);
 49         RETURN;
 50     END cols_as_rows;
 51  /

Function created.

  1  select *
  2      from TABLE( cols_as_rows('select *
  3                                   from t
  4*                                 where rownum = 1') )
SQL> /
    from TABLE( cols_as_rows('select *
         *
ERROR at line 2:
ORA-22905: cannot access rows from a non-nested table item

-------------------------------------
but 

SQL> select cols_as_rows('select * from t where rownum=1') from dual;

COLS_AS_ROWS('SELECT*FROMT(RNUM, CNAME, VAL)
---------------------------------------------------------------------------------------------------
MYTABLETYPE(MYSCALARTYPE(1, 'EMPNO', '1'), MYSCALARTYPE(1, 'ENAME', 'Bhavesh'))
whats that??
what rights are required to execute queries??
I think problem with rights..
Bhavesh 

Tom Kyte

Followup  

September 26, 2005 - 10:57 am UTC

what is your cursor_sharing set to?


you can use


cast( cols_as_rows( .... ) as mytableType )


instead of just cols_as rows - I think you might have cursor_sharing set :(

September 26, 2005 - 10:22 am UTC

Reviewer: A reader

Thanks Tom!

Created a table to hold the distinct codes and able to get the values from there as shown below.Now the issue is 
how to change the label of the columns depending on the values of codes ?


SQL> select * from hold_codes;

CODES                  SEQ
--------------- ----------
CODE1                    1
CODE2                    2
CODE3                    3



SQL> ed
Wrote file afiedt.buf

  1   select name, max(decode(seq,1,percent,null)) code1,
  2    max(decode(seq,2,percent,null)) code2,
  3    max(decode(seq,3,percent,null)) code3
  4   from temp_fluids a ,hold_Codes b
  5   where a.code = b.codes
  6*  group by name
SQL> /

NAME            CODE1      CODE2      CODE3
---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40 

Tom Kyte

Followup  

September 26, 2005 - 11:00 am UTC

you control the name of the label -- you named them code1, code2, code3 here but you can call them a, b, c if you like - you control that entirely.

September 26, 2005 - 11:18 am UTC

Reviewer: A reader

I think I was not clear. I want the output column names same as the data in HOLD_Codes table dynamically.

Lets say my data set looks like below. and instead of hardsetting the names of the output cloumns as code1 ,code2 etc I want to display the actual values from HOLD_CODEs table dynamically.How to do that ?


SQL> select * from hold_codes;

CODES                  SEQ
--------------- ----------
apple                   1
orange                  2
some other label        3



SQL> ed
Wrote file afiedt.buf

  1   select name, max(decode(seq,1,percent,null)) code1,
  2    max(decode(seq,2,percent,null)) code2,
  3    max(decode(seq,3,percent,null)) code3
  4   from temp_fluids a ,hold_Codes b
  5   where a.code = b.codes
  6*  group by name
SQL> /

NAME            CODE1      CODE2      CODE3
---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40
 

Tom Kyte

Followup  

September 27, 2005 - 9:25 am UTC

but as said -- you have to "know" what the number of columns and their names are when the query is parsed.

Therefore, you

a) query codes table in order to
b) construct query with specific information from codes table.

September 26, 2005 - 3:54 pm UTC

Reviewer: A reader

In sqlplus one way is...

SQL> column a new_value b ;
SQL> select codes a from hold_codes where seq =1;

A
---------------
CODE1

SQL> 
SQL> column a1 new_value b1 ;
SQL> select codes a1 from hold_codes where seq =2;

A1
---------------
CODE2

SQL> 
SQL> column a2 new_value b2 ;
SQL> select codes a2 from hold_codes where seq =3;

A2
---------------
CODE3

SQL> 
SQL> select name, max(decode(seq,1,percent,null)) &b,
  2  max(decode(seq,2,percent,null)) &b1,
  3  max(decode(seq,3,percent,null)) &b2
  4  from temp_fluids a ,hold_Codes b
  5  where a.code = b.codes
  6  group by name
  7  /
old   1: select name, max(decode(seq,1,percent,null)) &b,
new   1: select name, max(decode(seq,1,percent,null)) CODE1,
old   2: max(decode(seq,2,percent,null)) &b1,
new   2: max(decode(seq,2,percent,null)) CODE2,
old   3: max(decode(seq,3,percent,null)) &b2
new   3: max(decode(seq,3,percent,null)) CODE3

NAME            CODE1      CODE2      CODE3
---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40 

September 26, 2005 - 4:06 pm UTC

Reviewer: A reader

Can we do the similar thing in plsql?

Tom Kyte

Followup  

September 27, 2005 - 9:50 am UTC

yes, you write some SQL, that SQL queries the code table.

Based on what you find in the code table you build your query.

then, you execute it.




September 26, 2005 - 4:54 pm UTC

Reviewer: A reader

I meant to say , can we do the similar thing in one sql without using sqlplus as sqlplus is not an option for our case. Thanks!

Tom Kyte

Followup  

September 27, 2005 - 9:53 am UTC

you can do anything in code you want - just query the codes, build the query and execute it.

Query help ....

September 26, 2005 - 6:16 pm UTC

Reviewer: A reader

I have table "login"

create table login (user_code varchar2(10),user_session varchar2(30),user_action varchar2(10),user_time date);

insert into login values ('c1','asdfadsfasdfasdf1','LOGIN',sysdate -10);
insert into login values ('c2','asdfadsfasdfasdf2','LOGIN',sysdate -10);
insert into login values ('c3','asdfadsfasdfasdf3','LOGOUT',sysdate -10);
insert into login values ('c4','asdfadsfasdfasdf4','LOGIN',sysdate -10);
insert into login values ('c5','asdfadsfasdfasdf5','LOGIN',sysdate -10);
insert into login values ('c6','asdfadsfasdfasdf6','LOGIN',sysdate -10);
insert into login values ('c7','asdfadsfasdfasdf7','LOGOUT',sysdate -10);
insert into login values ('c8','asdfadsfasdfasdf8','LOGIN',sysdate -10);
insert into login values ('c9','asdfadsfasdfasdf9','LOGIN',sysdate -10);
insert into login values ('c10','asdfadsfasdfasdf10','LOGIN',sysdate -10);

insert into login values ('c1','asdfadsfasdfasdf1','LOGOUT',sysdate -5);
insert into login values ('c3','asdfadsfasdfasdf31','LOGIN',sysdate -10);
insert into login values ('c4','asdfadsfasdfasdf4','LOGOUT',sysdate -5);
insert into login values ('c5','asdfadsfasdfasdf5','RECONNECT',sysdate -5);
insert into login values ('c6','asdfadsfasdfasdf6','LOGOUT',sysdate -5);
insert into login values ('c7','asdfadsfasdfasdf71','LOGIN',sysdate -5);
insert into login values ('c8','asdfadsfasdfasdf8','LOGOUT',sysdate -5);
insert into login values ('c10','asdfadsfasdfasdf10','LOGOUT',sysdate -5);

insert into login values ('c1','asdfadsfasdfasdf101','LOGIN',sysdate -3);
insert into login values ('c3','asdfadsfasdfasdf3','RECONNECT',sysdate -3);
insert into login values ('c4','asdfadsfasdfasdf41','LOGIN',sysdate -3);
insert into login values ('c5','asdfadsfasdfasdf5','LOGOUT',sysdate -3);
insert into login values ('c6','asdfadsfasdfasdf61','LOGIN',sysdate -3);
insert into login values ('c7','asdfadsfasdfasdf71','RECONNECT',sysdate -3);
insert into login values ('c8','asdfadsfasdfasdf81','LOGIN',sysdate -3);
insert into login values ('c9','asdfadsfasdfasdf9','RECONNECT',sysdate -3);
insert into login values ('c10','asdfadsfasdfasdf100','LOGIN'sysdate -3);

insert into login values ('c1','asdfadsfasdfasdf101','LOGOUT',sysdate -2);
insert into login values ('c4','asdfadsfasdfasdf41','RECONNECT',sysdate -2);
insert into login values ('c5','asdfadsfasdfasdf51','LOGIN',sysdate -2);
insert into login values ('c7','asdfadsfasdfasdf71','RECONNECT',sysdate -2);
insert into login values ('c8','asdfadsfasdfasdf81','LOGOUT',sysdate -2);
insert into login values ('c9','asdfadsfasdfasdf9', 'LOGOUT',sysdate -2);
insert into login values ('c10','asdfadsfasdfasdf100','RECONNECT',sysdate -2);


insert into login values ('c1','asdfadsfasdfasdf1010','LOGIN',sysdate -1);
insert into login values ('c4','asdfadsfasdfasdf41','LOGOUT',sysdate -1);
insert into login values ('c5','asdfadsfasdfasdf51','RECONNECT',sysdate -1);
insert into login values ('c7','asdfadsfasdfasdf71','LOGOUT',sysdate -1);
insert into login values ('c8','asdfadsfasdfasdf811','LOGIN',sysdate -1);
insert into login values ('c9','asdfadsfasdfasdf91', 'LOGIN',sysdate -1);
insert into login values ('c10','asdfadsfasdfasdf100','LOGOUT',sysdate -1);


insert into login values ('c1','asdfadsfasdfasdf1010','RECONNECT',sysdate);
insert into login values ('c4','asdfadsfasdfasdf411','LOGIN',sysdate );
insert into login values ('c5','asdfadsfasdfasdf51','LOGOUT',sysdate);
insert into login values ('c8','asdfadsfasdfasdf811','RECONNECT',sysdate);
insert into login values ('c9','asdfadsfasdfasdf91', 'RECONNECT',sysdate);
insert into login values ('c10','asdfadsfasdfasdf1001','LOGIN',sysdate );




Now I want to know how many users(c1,c2..) are "logged in" at any given time.
this is a sample data the real login table contains 500k rows.
and also this login report must calculate logins from prevous days if the
user did not log out..

q1.) is it possible ? can you help me solve this issue.

q2) how would you design this kind of table ?


Query help

September 26, 2005 - 6:18 pm UTC

Reviewer: A reader


In above qestion I want to know
1.) how may and which users are loggin in at given time

TIA

Tom Kyte

Followup  

September 27, 2005 - 10:05 am UTC

select * from v$session?

Query help

September 26, 2005 - 6:21 pm UTC

Reviewer: A reader

the database is : oracle 8.1.7.4
sun sol 2.8


FEEDBACK -> SQL - HOW TO WRITE?

September 27, 2005 - 1:48 am UTC

Reviewer: VIKAS from INDIA

Dear Mr. Kyte,

As desired by you here is the above mentioned Table created for your consideration with some changes and additions.

sql> create table T1(ID number(2), Initials varchar2(4),
JoinDate date);
TABLE CREATED.

Now, Insert a row,

sql> insert into T1 values(01, 'VKS', '01-MAR-04');
1 ROW CREATED.
sql> Commit;

Now, Select records to check,

sql> select * from T1;

ID Initials JoinDate
------ -------- ----------
1 VKS 1-MAR-04

Here, after this, all that I want is to write a query or PL/SQL procedure, which gives the following output from above Table T1.

column Dummy Records
-------- ------- -----------
ID := 1;
Initials := VKS;
JoinDate := 1-MAR-04;

Or may something like this..

column Dummy
-------- ---------------
ID := 1;
Initials := VKS;
JoinDate := 1-MAR-04;

Or even this...

Dummy
-----------------------
ID := 1;
Initials := VKS;
JoinDate := 1-MAR-04;


I hope now its clear, for you to get my point. Can you pls help me out with this.

Take care, regards.
Vikas.


done it

September 27, 2005 - 8:28 am UTC

Reviewer: Bhavesh Ghodasara from Junagadh,Gujarat,India

hi tom,
I solve the problem like
FROM TABLE (CAST (cols_as_rows ('select * FROM mst_personal') AS mytabletype)) x) a

thanks ..I just done it before your answer..
but why some times you have to cast and some time not..
Bhavesh

Tom Kyte

Followup  

September 27, 2005 - 11:35 am UTC

you have cursor sharing set on - it is an issue, cursor sharing <> exact indicates you have a serious bug in your developed applications!



Re:

September 27, 2005 - 8:32 am UTC

Reviewer: Jagjeet Singh malhi from Delhi ( India )

Hi Vikas,

I used this code for that. It is very usefull for day to day
activities


SQL> create or replace procedure p ( p_str   varchar2)
  2  authid current_user
  3  as
  4  v_cur     int := dbms_sql.open_cursor;
  5  v_exe     int ;
  6  v_tot_cols int;
  7  v_tab_desc  dbms_sql.desc_tab;
  8  v_col_value varchar2(4000);
  9  begin
 10  dbms_sql.parse(v_cur,p_str,dbms_sql.native);
 11  dbms_sql.describe_columns(v_cur,v_tot_cols,v_tab_desc);
 12  for i in 1..v_tot_cols loop
 13  dbms_sql.define_column(v_cur,i,v_col_value,4000);
 14  end loop;
 15  --
 16  v_exe := dbms_sql.execute(v_cur);
 17  --------
 18  loop
 19  exit when  ( dbms_sql.fetch_rows(v_cur) <=  0 ) ;
 20  --
 21  for i in 1..v_tot_cols loop
 22  dbms_sql.column_Value(v_cur,i,v_col_value);
 23  dbms_output.put_line(rpad(v_tab_desc(i).col_name,30,' ')||' : '||v_col_value);
 24  end loop;
 25  --
 26  end loop;
 27  -------
 28  dbms_sql.close_cursor(v_cur);
 29* end;

Procedure created.

SQL> set serveroutput on size 100000

SQL> exec p ( ' Select * from v$database ' );

DBID                           : 2903310348                                     
NAME                           : JS                                             
CREATED                        : 01-JAN-99                                      
RESETLOGS_CHANGE#              : 836266                                         
RESETLOGS_TIME                 : 01-JAN-99                                      
PRIOR_RESETLOGS_CHANGE#        : 1                                              
PRIOR_RESETLOGS_TIME           : 01-JAN-99                                      
LOG_MODE                       : ARCHIVELOG                                     
CHECKPOINT_CHANGE#             : 856397                                         
ARCHIVE_CHANGE#                : 0                                              
CONTROLFILE_TYPE               : CURRENT                                        
CONTROLFILE_CREATED            : 01-JAN-99                                      
CONTROLFILE_SEQUENCE#          : 712                                            
CONTROLFILE_CHANGE#            : 856399                                         
CONTROLFILE_TIME               : 01-JAN-99                                      
OPEN_RESETLOGS                 : NOT ALLOWED                                    
VERSION_TIME                   : 01-JAN-99                                      
OPEN_MODE                      : READ WRITE                                     
PROTECTION_MODE                : MAXIMUM PERFORMANCE                            
PROTECTION_LEVEL               : MAXIMUM PERFORMANCE                            
REMOTE_ARCHIVE                 : ENABLED                                        
ACTIVATION#                    : 2903250804                                     
DATABASE_ROLE                  : PRIMARY                                        
ARCHIVELOG_CHANGE#             : 856396                                         
SWITCHOVER_STATUS              : SESSIONS ACTIVE                                
DATAGUARD_BROKER               : DISABLED                                       
GUARD_STATUS                   : NONE                                           
SUPPLEMENTAL_LOG_DATA_MIN      : NO                                             
SUPPLEMENTAL_LOG_DATA_PK       : NO                                             
SUPPLEMENTAL_LOG_DATA_UI       : NO                                             
FORCE_LOGGING                  : NO                                             

PL/SQL procedure successfully completed.


SQL> exec p ( ' select * from dba_tables where table_name = ''T'' ');

OWNER                          : OPS$ORA9                                       
TABLE_NAME                     : T                                              
TABLESPACE_NAME                : TEST                                           
CLUSTER_NAME                   :                                                
IOT_NAME                       :                                                
PCT_FREE                       : 10                                             
PCT_USED                       :                                                
INI_TRANS                      : 1                                              
MAX_TRANS                      : 255                                            
INITIAL_EXTENT                 : 65536                                          
NEXT_EXTENT                    :                                                
MIN_EXTENTS                    : 1                                              
MAX_EXTENTS                    : 2147483645                                     
PCT_INCREASE                   :                                                
FREELISTS                      :                                                
FREELIST_GROUPS                :                                                
LOGGING                        : YES                                            
BACKED_UP                      : N                                              
NUM_ROWS                       : 397                                            
BLOCKS                         : 19629                                          
EMPTY_BLOCKS                   : 339                                            
AVG_SPACE                      : 1871                                           
CHAIN_CNT                      : 397                                            
AVG_ROW_LEN                    : 2019                                           
AVG_SPACE_FREELIST_BLOCKS      : 0                                              
NUM_FREELIST_BLOCKS            : 0                                              
DEGREE                         :          1                                     
INSTANCES                      :          1                                     
CACHE                          :     N                                          
TABLE_LOCK                     : ENABLED                                        
SAMPLE_SIZE                    : 397                                            
LAST_ANALYZED                  : 01-JAN-99                                      
PARTITIONED                    : NO                                             
IOT_TYPE                       :                                                
TEMPORARY                      : N                                              
SECONDARY                      : N                                              
NESTED                         : NO                                             
BUFFER_POOL                    : DEFAULT                                        
ROW_MOVEMENT                   : DISABLED                                       
GLOBAL_STATS                   : NO                                             
USER_STATS                     : NO                                             
DURATION                       :                                                
SKIP_CORRUPT                   : DISABLED                                       
MONITORING                     : NO                                             
CLUSTER_OWNER                  :                                                
DEPENDENCIES                   : DISABLED                                       
COMPRESSION                    : DISABLED                                       
OWNER                          : access                                         
TABLE_NAME                     : T                                              
TABLESPACE_NAME                : SYSTEM                                         
CLUSTER_NAME                   :                                                
IOT_NAME                       :                                                
PCT_FREE                       : 10                                             
PCT_USED                       : 40                                             
INI_TRANS                      : 1                                              
MAX_TRANS                      : 255                                            
INITIAL_EXTENT                 : 10240                                          
NEXT_EXTENT                    : 10240                                          
MIN_EXTENTS                    : 1                                              
MAX_EXTENTS                    : 121                                            
PCT_INCREASE                   : 50                                             
FREELISTS                      : 1                                              
FREELIST_GROUPS                : 1                                              
LOGGING                        : YES                                            
BACKED_UP                      : N                                              
NUM_ROWS                       :                                                
BLOCKS                         :                                                
EMPTY_BLOCKS                   :                                                
AVG_SPACE                      :                                                
CHAIN_CNT                      :                                                
AVG_ROW_LEN                    :                                                
AVG_SPACE_FREELIST_BLOCKS      :                                                
NUM_FREELIST_BLOCKS            :                                                
DEGREE                         :          1                                     
INSTANCES                      :          1                                     
CACHE                          :     N                                          
TABLE_LOCK                     : ENABLED                                        
SAMPLE_SIZE                    :                                                
LAST_ANALYZED                  :                                                
PARTITIONED                    : NO                                             
IOT_TYPE                       :                                                
TEMPORARY                      : N                                              
SECONDARY                      : N                                              
NESTED                         : NO                                             
BUFFER_POOL                    : DEFAULT                                        
ROW_MOVEMENT                   : DISABLED                                       
GLOBAL_STATS                   : NO                                             
USER_STATS                     : NO                                             
DURATION                       :                                                
SKIP_CORRUPT                   : DISABLED                                       
MONITORING                     : NO                                             
CLUSTER_OWNER                  :                                                
DEPENDENCIES                   : DISABLED                                       
COMPRESSION                    : DISABLED                                       

PL/SQL procedure successfully completed.


In 9i - It can print 100000 bytes.
In 10g - It's unlimited "set serveroutput on size unlimited" 

Need diff. type for each table.

September 27, 2005 - 8:36 am UTC

Reviewer: Jagjeet Singh from INIDA

Hi Bhavesh,

I think for that we need diff. type for each diff. table.

Thanks,
Js

Re:

September 27, 2005 - 8:50 am UTC

Reviewer: Jagjeet Singh from INIDA

Bhavesh,

I thought you answered Viaks's query. But you have diff. question.

I apologies.

Js






September 27, 2005 - 10:35 am UTC

Reviewer: A reader

Thanks Tom! pl/sql works okay. 

Can I do this job in one SQL instead?


SQL>  create or replace procedure return_matrix(p_cursor out get_matrix_fluids.refcursor_type ) as
  2   a1 varchar2(20);
  3   a2 varchar2(20);
  4   a3 varchar2(20);
  5   v_query varchar2(1000);
  6   begin
  7    select codes into a1 from hold_codes where seq =1;
  8    select codes into a2 from hold_codes where seq =2;
  9    select codes into a3 from hold_codes where seq =3;
 10    v_query := 'select name, max(decode(seq,1,percent,null)) '|| a1
 11      || ', max(decode(seq,2,percent,null)) '|| a2
 12      ||' , max(decode(seq,3,percent,null)) '|| a3
 13   ||'  from temp_fluids a ,hold_Codes b
 14    where a.code = b.codes
 15    group by name';
 16    open p_cursor for v_query;
 17   end;
 18  /

Procedure created.

SQL> execute return_matrix(:a);

PL/SQL procedure successfully completed.

SQL>  print a

NAME            CODE1      CODE2      CODE3
---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40

SQL>  

Tom Kyte

Followup  

September 27, 2005 - 12:08 pm UTC

I would have thought of code like this:


v_query := 'select name';
for x in ( seledct * from hold_codes order by seq )
loop
v_query := v_query || ', max(decode(seq,' || x.seq || ',percent,null)) "' ||
x.codes || '"'
end loop;
v_query := v_query || ' from ......';



Query help ....

September 27, 2005 - 11:56 am UTC

Reviewer: A reader

Tom,

this is a custom login table, "login"
Whenever user logs in OUR application (not oracle user account hance not v$session), we insert a row as whether he logged in, reconnected or logged out. I have provided
create table and insert stmts. to generate test data
the session there represents java session to OUR custome application.

Please help me find which are the users logged in at given time, from the "login" table.


TIA

Tom Kyte

Followup  

September 27, 2005 - 1:36 pm UTC

I've not a clue what "YOUR" login table which presumably YOU designed to answer the questions you need to ask of it looks like.

Thanks Tom! You are the best!

September 27, 2005 - 2:14 pm UTC

Reviewer: A reader from VA USA

"I would have thought of code like this:"

Thanks for this tips. I think its a great idea! Will write the code accordingly.



September 27, 2005 - 2:30 pm UTC

Reviewer: A reader

Thanks Tom! 

SQL> ed
Wrote file afiedt.buf

  1  create or replace procedure return_matrix(p_cursor out
  2    get_matrix_fluids.refcursor_type ) as
  3    a1 varchar2(20);
  4    a2 varchar2(20);
  5    a3 varchar2(20);
  6    v_query varchar2(1000);
  7  begin
  8   v_query := 'select name';
  9   for x in ( select * from hold_codes order by seq )
 10   loop
 11     v_query := v_query || ', max(decode(seq,' || x.seq || ',percent,null)) "' ||
 12                x.codes || '"';
 13   end loop;
 14   v_query := v_query || 'from temp_fluids a ,hold_Codes b
 15         where a.code = b.codes
 16         group by name';
 17   open p_cursor for v_query;
 18*  end;
SQL> /

Procedure created.

SQL> execute return_matrix(:a);

PL/SQL procedure successfully completed.

SQL> print a

NAME            CODE1      CODE2      CODE3
---------- ---------- ---------- ----------
NAME1              10         10         10
NAME2              20         20
NAME3              30         30
NAME4                         40
 

Query help....

September 27, 2005 - 3:01 pm UTC

Reviewer: A reader


Oracle 8.1.7.4
os : sun sol 2.8

I have table "login"

create table login
(user_code varchar2(10),
user_session varchar2(30), -- "Application java seesion not oracle seesion"
user_action varchar2(10),
user_time date);

insert into login values ('c1','asdfadsfasdfasdf1','LOGIN',sysdate -10);
insert into login values ('c2','asdfadsfasdfasdf2','LOGIN',sysdate -10);
insert into login values ('c3','asdfadsfasdfasdf3','LOGOUT',sysdate -10);
insert into login values ('c4','asdfadsfasdfasdf4','LOGIN',sysdate -10);
insert into login values ('c5','asdfadsfasdfasdf5','LOGIN',sysdate -10);
insert into login values ('c6','asdfadsfasdfasdf6','LOGIN',sysdate -10);
insert into login values ('c7','asdfadsfasdfasdf7','LOGOUT',sysdate -10);
insert into login values ('c8','asdfadsfasdfasdf8','LOGIN',sysdate -10);
insert into login values ('c9','asdfadsfasdfasdf9','LOGIN',sysdate -10);
insert into login values ('c10','asdfadsfasdfasdf10','LOGIN',sysdate -10);

insert into login values ('c1','asdfadsfasdfasdf1','LOGOUT',sysdate -5);
insert into login values ('c3','asdfadsfasdfasdf31','LOGIN',sysdate -10);
insert into login values ('c4','asdfadsfasdfasdf4','LOGOUT',sysdate -5);
insert into login values ('c5','asdfadsfasdfasdf5','RECONNECT',sysdate -5);
insert into login values ('c6','asdfadsfasdfasdf6','LOGOUT',sysdate -5);
insert into login values ('c7','asdfadsfasdfasdf71','LOGIN',sysdate -5);
insert into login values ('c8','asdfadsfasdfasdf8','LOGOUT',sysdate -5);
insert into login values ('c10','asdfadsfasdfasdf10','LOGOUT',sysdate -5);

insert into login values ('c1','asdfadsfasdfasdf101','LOGIN',sysdate -3);
insert into login values ('c3','asdfadsfasdfasdf3','RECONNECT',sysdate -3);
insert into login values ('c4','asdfadsfasdfasdf41','LOGIN',sysdate -3);
insert into login values ('c5','asdfadsfasdfasdf5','LOGOUT',sysdate -3);
insert into login values ('c6','asdfadsfasdfasdf61','LOGIN',sysdate -3);
insert into login values ('c7','asdfadsfasdfasdf71','RECONNECT',sysdate -3);
insert into login values ('c8','asdfadsfasdfasdf81','LOGIN',sysdate -3);
insert into login values ('c9','asdfadsfasdfasdf9','RECONNECT',sysdate -3);
insert into login values ('c10','asdfadsfasdfasdf100','LOGIN'sysdate -3);

insert into login values ('c1','asdfadsfasdfasdf101','LOGOUT',sysdate -2);
insert into login values ('c4','asdfadsfasdfasdf41','RECONNECT',sysdate -2);
insert into login values ('c5','asdfadsfasdfasdf51','LOGIN',sysdate -2);
insert into login values ('c7','asdfadsfasdfasdf71','RECONNECT',sysdate -2);
insert into login values ('c8','asdfadsfasdfasdf81','LOGOUT',sysdate -2);
insert into login values ('c9','asdfadsfasdfasdf9', 'LOGOUT',sysdate -2);
insert into login values ('c10','asdfadsfasdfasdf100','RECONNECT',sysdate -2);


insert into login values ('c1','asdfadsfasdfasdf1010','LOGIN',sysdate -1);
insert into login values ('c4','asdfadsfasdfasdf41','LOGOUT',sysdate -1);
insert into login values ('c5','asdfadsfasdfasdf51','RECONNECT',sysdate -1);
insert into login values ('c7','asdfadsfasdfasdf71','LOGOUT',sysdate -1);
insert into login values ('c8','asdfadsfasdfasdf811','LOGIN',sysdate -1);
insert into login values ('c9','asdfadsfasdfasdf91', 'LOGIN',sysdate -1);
insert into login values ('c10','asdfadsfasdfasdf100','LOGOUT',sysdate -1);


insert into login values ('c1','asdfadsfasdfasdf1010','RECONNECT',sysdate);
insert into login values ('c4','asdfadsfasdfasdf411','LOGIN',sysdate );
insert into login values ('c5','asdfadsfasdfasdf51','LOGOUT',sysdate);
insert into login values ('c8','asdfadsfasdfasdf811','RECONNECT',sysdate);
insert into login values ('c9','asdfadsfasdfasdf91', 'RECONNECT',sysdate);
insert into login values ('c10','asdfadsfasdfasdf1001','LOGIN',sysdate );




Now I want to know which and how many users(c1,c2..) are "logged in" at any given time.


This is a sample data the real login table contains 500k rows.
and also this login report must calculate logins from prevous days if the user did not log out..

q1.)how may and which users are loggin in at given time

q2) how would you design this kind of table ?


TIA



Tom Kyte

Followup  

September 27, 2005 - 3:14 pm UTC

there would be a single record per "session".

those that are logged in - they don't have a logout time, done.

are you sure you always have a logout record, if a session times out, do you have records inserted in there accordingly,

question: can we just look for login records such that there is NO subsequent LOGOUT records?


Query Help....

September 27, 2005 - 5:12 pm UTC

Reviewer: A reader


Yes, that is what I want,

# of logins(and or reconnects) that does not have log out so far.

Yes, there no time out, a user can be logged into system for as many DAYS as he/she wants..
This should give me how many users are connected to the system.


Tom Kyte

Followup  

September 27, 2005 - 8:23 pm UTC

ops$tkyte@ORA10G> select *
  2    from (
  3  select user_code,
  4         user_action,
  5         user_time,
  6         lead(user_action) over (partition by user_code order by user_time) next_action
  7    from login
  8   where user_action in ( 'LOGIN', 'LOGOUT' )
  9         )
 10   where user_action = 'LOGIN'
 11     and next_action is null
 12  /
 
USER_CODE  USER_ACTIO USER_TIME NEXT_ACTIO
---------- ---------- --------- ----------
c1         LOGIN      26-SEP-05
c10        LOGIN      27-SEP-05
c2         LOGIN      17-SEP-05
c3         LOGIN      17-SEP-05
c4         LOGIN      27-SEP-05
c6         LOGIN      24-SEP-05
c8         LOGIN      26-SEP-05
c9         LOGIN      26-SEP-05
 
8 rows selected.
 

SQL QUERY HELP???

September 27, 2005 - 6:29 pm UTC

Reviewer: ramis from pak

Hi,

i have a student quiz scores table in which data is stored in the following 

format

 QUIZ_ID   STUDENT_ID   CLASS_ID    SCORES
--------- ---------- ---------- ----------
        1       1150          1         27
        1       1278          1         13
        1       1243          1         60
        1       1277          1         41
        1       1215          1         12
        1       1364          2         22
        1       1361          2         10
        2       1278          1         13
        2       1243          1         60
        2       1215          1         12
        2       1364          2         22
        2       1361          2         10
        2       1960          6         54

WELL, the problem is that I want the output in the format based on some conditions..


STUDENT_ID    CLASS_ID    SUM(STUDENT    TOTAL_CLASS     TOTAL_QUIZ    
                             _SCORES)         _SCORES        SCORES

here
      1. STUDENT_ID
      2. CLASS_ID is the class_id of the respective student
      3. sum(student_scores) is the sum of SCORES of each
         student in all quizes he participated
      4. TOTAL_CLASS_scores is the SUM of all scores of all
         students belonging to the student's CLASS_ID, ONLY in
         those quizes in which the student also participated  
      5. total_quiz_scores is the sum of all scores of all
         students of all classes ONLY in quizes in which that
         student also participated


hope this will be clear enough for my requiremnet

now here is my disired output



STUDENT_ID   CLASS_ID  SUM(SCORES)   TOTAL_CLASS    TOTAL_QUIZ 
                                        SCORES      SCORES   
      1150          1          27       153         185
      1215          1          24       238         356
      1243          1         120       238         356
      1277          1          41       153         185 
      1278          1          26       238         356
      1361          2          20       64          356
      1364          2          44       64          365
      1960          6          54       54          171 

I can easily get the first three columns by this query

SQL> SELECT STUDENT_ID, CLASS_ID, SUM(SCORES)
     FROM T
     GROUP BY STUDENT_ID, CLASS_ID
/

but unable to get the last two columns as desired..I would most prefer the shortest possible query/yet easy and fast to achieve this for my further calculations


CREATE TABLE T
(QUIZ_ID NUMBER(4),  
STUDENT_ID NUMBER(4),
CLASS_ID  NUMBER(2),
SCORES  NUMBER(3))


INSERT INTO T VALUES (1,1150,1,27);
INSERT INTO T VALUES (1,1278,1,13);
INSERT INTO T VALUES (1,1243,1,60);
INSERT INTO T VALUES (1,1277,1,41);
INSERT INTO T VALUES (1,1215,1,12);
INSERT INTO T VALUES (1,1364,2,22);
INSERT INTO T VALUES (1,1361,2,10);
INSERT INTO T VALUES (2,1278,1,13);
INSERT INTO T VALUES (2,1243,1,60);
INSERT INTO T VALUES (2,1215,1,12);
INSERT INTO T VALUES (2,1364,2,22);
INSERT INTO T VALUES (2,1361,2,10);
INSERT INTO T VALUES (2,1960,6,54);
 

Tom Kyte

Followup  

September 27, 2005 - 8:33 pm UTC

assuming a student may only take a quiz ONCE.

we can assign to each row

o the sum(scores) for that same class_id and quiz_id easily, since the assumption 
  is that a student may take a quiz ONCE, we can sum this again safely.

o the sum(scores) for that same quiz_id, same assumption.


then aggregate...


ops$tkyte@ORA9IR2> select student_id,
  2         class_id,
  3             sum(scores),
  4             sum(t1),
  5             sum(t2)
  6    from (
  7  select student_id,
  8         class_id,
  9             scores,
 10             sum(scores) over (partition by class_id, quiz_id) t1,
 11             sum(scores) over (partition by quiz_id) t2
 12    from t
 13         )
 14   group by student_id, class_id
 15  /

STUDENT_ID   CLASS_ID SUM(SCORES)    SUM(T1)    SUM(T2)
---------- ---------- ----------- ---------- ----------
      1150          1          27        153        185
      1215          1          24        238        356
      1243          1         120        238        356
      1277          1          41        153        185
      1278          1          26        238        356
      1361          2          20         64        356
      1364          2          44         64        356
      1960          6          54         54        171

8 rows selected.


I believe that is what you were looking for - make sure you understand what it does before just using it!  Run the inline view by itself to see what is being assigned at each step. 

Thanx - Mr. Jagjeet Singh malhi

September 28, 2005 - 3:31 am UTC

Reviewer: VIKAS SANGAR from INDIA

Mr. Jagjeet Singh Malhi,

Thanx a ton for the code (Procedure) supplied by you. It really works, But there is small Problem of how to demarcate output of the columns based on their respective column datatypes. It takes even the Number data types as String/varchar. Do you have any way to fix this out. I mean, to put columns with char/varchar/varchar2/date datatype between the ' ' and let remain the columns with number datatype exist freely. This will further increase the utility and effeciiveness of the procedure, by minimising manual edits/changes, reducing errors and saving time.

I think the user_tab_cols view may prove to be handy, to achieve this.

By the way, I was Happy and Surprised to have a person from my Home Town, replying to my query.

Take care, regards..
Vikas

Re:

September 28, 2005 - 10:02 am UTC

Reviewer: Jagjeet Singh malhi from INIDA

Hello Sir,

Good Point.

May be Mr. Tom can tell us better.

My assumptions are :
================

--we can achive this by declaring 3 diff. datatype variables.
--and just check using desc_tab and stores its value in same
--datatype. But I do not see any use of this -- if it is just for printing ..


I see two diff. things in this case.

-- Considering client as SQL*PLUS ----

o One is recordset building and push to client -- at Database Level
o Client is formatting and printing the data in lines. -- at client Level

Whenever we issue any sql using any manipulation with it's
datatype or using any functions. like ..
Select .. to_number(format..),trunc(date), sum(col), min(column) ..

Oracle does all manipulation or building this recordset
at database level. and just sends the result to it's lient.
And sql*plus prints it for us ..

At the time of printing -- it is out of any datatype zone ..
its just printing lines ...

same we are doing here ..

you can issue at sql*prompt

" Select min(number),trunc(date_colum) ... from .. "
or
exec p (' Select min(number),trunc(date_colum) from ' );

I think it is same ..

again waiting for Mr. Tom's comment ..

Thanks,
Js

Query Help...,

September 28, 2005 - 10:51 am UTC

Reviewer: A reader

Thanks, tom.

This works, but the explain plan is not good. and it takes too much time though. can not run this in prod !!

Tom Kyte

Followup  

September 28, 2005 - 11:21 am UTC

that is why we typically model our physical schemas to be able to rapidly answer questions we need to ask of them


this model doesn't support your question very nicely.


You need to look at all of the login/logout records, sort them and find login records that don't have a subsequent logout record.

we could write that in different ways - but it isn't going to be "fast" in any case.

Outputting the result in a single row

September 30, 2005 - 3:06 am UTC

Reviewer: Vikas Khanna from INDIA

Hi Tom,

Please help and show us how to write a combined query to get the output as

Count(A) Count(B) Count(C) Count(D) Count(E) Count(F)
107164 138381 98008 98248 96968 84028

How can these different queries produce the result in a single row.

Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-6) group by request_ter\
ms having count(*) > 1);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-5) group by request_ter\
ms having count(*) > 2);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-4) group by request_ter\
ms having count(*) > 3);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-3) group by request_ter\
ms having count(*) > 4);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-2) group by request_ter\
ms having count(*) > 5);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate-1) group by request_ter\
ms having count(*) > 6);
Select Count(request_terms) from (Select request_terms, Count(*) from request_data w\
here request_date between trunc(sysdate-7) and trunc(sysdate) group by request_terms\
having count(*) > 7);

admin@DWADM> @@try

COUNT(REQUEST_TERMS)
--------------------
107164


COUNT(REQUEST_TERMS)
--------------------
138381


COUNT(REQUEST_TERMS)
--------------------
98008


COUNT(REQUEST_TERMS)
--------------------
98248


COUNT(REQUEST_TERMS)
--------------------
96968


COUNT(REQUEST_TERMS)
--------------------
84028


COUNT(REQUEST_TERMS)
--------------------
83946

Thanks
Vikas

Tom Kyte

Followup  

September 30, 2005 - 9:27 am UTC

if i had a simple create table and some inserts to test with...


Query Help...,

September 30, 2005 - 12:55 pm UTC

Reviewer: A reader

Thanks, tom,

Can you suggest a different model/structure for the "login"
table ? how would you design it provided the objectives are
1.) only to log all login,logout and reconnects from the system
2.) report how many users are logged into system right now
3.) how many times a perticular user disconnected
4.) how often user logout from the system
5.) how long user stays logged into the system.

thanks,


Tom Kyte

Followup  

September 30, 2005 - 2:19 pm UTC

i don't know what a reconnect is, but a login/logout record would be the same record with a login time and a logout time (logout time is null means "not logged out")


the queries to answer the questions are then "trivial"



sql query of sum before a particular value??

October 01, 2005 - 5:04 pm UTC

Reviewer: ramis from pak

Hi,

I am facing a complex problem, hope you would help
I have a table which has four columns

CREATE TABLE T
(MATCH_ID   NUMBER(4),
TEAM_ID NUMBER(2),
PLayer_ID NUMBER(4),
SCORE  NUMBER(3))

here match_id, team_id and pl_id are jointly primary key..


SQL> select * from t

  MATCH_ID    TEAM_ID      PLAYER_ID      SCORE
---------- ---------- ---------- ----------
         2          2       1061          8
        12          2       1061          0
        13          2       1061         18
        14          2       1061         14
        15          2       1061         
        17          2       1061         12
        18          2       1061         33
        19          2       1061         10
        20          2       1061          0
        21          2       1061        100
        22          2       1061         41
         1          1       1361          0
         3          1       1361         11
         4          1       1361         10
         6          1       1361         10
         7          1       1361         99
         8          1       1361         91
         9          1       1361        100
        10          1       1361         76
        15          1       1361         51
        21          1       1361         22
        34          1       1361          0
         1          4       1661          0
         2          4       1661          0
         3          4       1661         70
         4          4       1661         99
         5          4       1661         12
         6          4       1661          0
        10          4       1960         10
        15          4       1960         68
        16          4       1960         14
        17          4       1960         89
        18          4       1960         10
        19          4       1960         45
        21          4       1960         63
        22          4       1960         44
        23          4       1960         86
        24          4       1960          5
        25          4       1960          3
        26          4       1960          8
        27          4       1960         27
        28          4       1960         28
        29          4       1960        141
        30          4       1960          0
        31          4       1960          7
        32          4       1960         37
         1          4       2361        100
         2          4       2361          7
         3          4       2361         10
         4          4       2361         49
         5          4       2361         12
         6          4       2361          0

my requirement is to get an aggregate and max(scores) of players before he made a particluar score for the first time. For exmaple, take player_id = 1061. I want to take his total aggregate and max(score) before he made a score >= 100 (100 or more) for the first time. 

His scores in order of match_id are:


SQL> select * from t where player_id = 1061 order by 1

  MATCH_ID    TEAM_ID      PLAYER_ID      SCORE
---------- ---------- ---------- ----------
         2          2       1061          8
        12          2       1061          0
        13          2       1061         18
        14          2       1061         14
        15          2       1061         
        17          2       1061         12
        18          2       1061         33
        19          2       1061         10
        20          2       1061          0
        21          2       1061        100
        22          2       1061         41

here the match_id shows the actual match number in which the player played..for exmaple, for the above player, he played in match_id = 2 which was actaully his match no. 1 and then he played in match_id = 12 which was actauily his second match. so he missed the remaining matches. The match_id is the key thing here because my desired output is based on that. The query would first sort the data by player_id and match_id in ascending order and then would perhaps loop through each match of the respective player to check in which match player has the score of 100 or more. when it finds such match for the respective player it should aggregate the runs and extract max(score) among all matches before the match in which he made a score of 100 or more.

now for this player my desired output is 

player_id  team_id  sum(scores)  Max(scores)  min(match_id)  max(match_id)
1061             2          95           33              2              20


here 
Player_id: is player_id.
Team_id is player's team_id.

Sum(scores): is the sum of all scores of the player before he made a score of 100 or more for the first time. 

Max(scores): is the maximum score of the player before he made a score of 100 or more for the first time.

Min(match_id): is the minimum match_id of the player 'in or before' which he did not make any score of 100 or more.

Max(match_id): is the maximum match_id of the player in which he played before he made a score of 100 or more in his next match.



thus for all players grouped by player_id and team_id I want the final output 

in the following format


player_id  team_id  sum(scores)  Max(scores)  min(match_id)  max(match_id)
1061             2          95           33              2              20
1361             1         221           99              1              8 
1960             4         500           89              10             28


notice that, if a player has a score of 100 or more in his first match then he would not come into this desired output. similary if a player never had the said score in all matches that he played then he would also not come. For example, two of the players in the data i provided at the top has these issues respectively


SQL> select * from t where player_id = 2361 order by 1

  MATCH_ID    TEAM_ID      PLAYER_ID    SCORE
         1          4       2361        100
         2          4       2361          7
         3          4       2361         10
         4          4       2361         49
         5          4       2361         12
         6          4       2361          0

as you can see he has a score of 100 or more in the first match he played, so he would not come into my desired output as he has not previous matches without a score of less than 100.

SQL> select * from t where player_id = 1661 order by 1

MATCH_ID    TEAM_ID      PL_ID      SCORE
-------- ---------- ---------- ----------
       1          4       1661          0
       2          4       1661          0
       3          4       1661         70
       4          4       1661         99
       5          4       1661         12
       6          4       1661          0


no score of 100 or more so not considered for the output

I hope this will be clear enough to solve problem


here is the sample ddl data

INSERT INTO T VALUES (2,2,1061,8);
INSERT INTO T VALUES (12,2,1061,0);
INSERT INTO T VALUES (13,2,1061,18);
INSERT INTO T VALUES (14,2,1061,14);
INSERT INTO T VALUES (15,2,1061,null);
INSERT INTO T VALUES (17,2,1061,12);
INSERT INTO T VALUES (18,2,1061,33);
INSERT INTO T VALUES (19,2,1061,10);
INSERT INTO T VALUES (20,2,1061,0);
INSERT INTO T VALUES (21,2,1061,100);
INSERT INTO T VALUES (22,2,1061,41);
INSERT INTO T VALUES (1,1,1361,0);
INSERT INTO T VALUES (3,1,1361,11);
INSERT INTO T VALUES (4,1,1361,10);
INSERT INTO T VALUES (6,1,1361,10);
INSERT INTO T VALUES (7,1,1361,99);
INSERT INTO T VALUES (8,1,1361,91);
INSERT INTO T VALUES (9,1,1361,100);
INSERT INTO T VALUES (10,1,1361,76);
INSERT INTO T VALUES (15,1,1361,51);
INSERT INTO T VALUES (21,1,1361,22);
INSERT INTO T VALUES (34,1,1361,0);
INSERT INTO T VALUES (10,4,1960,10);
INSERT INTO T VALUES (15,4,1960,68);
INSERT INTO T VALUES (16,4,1960,14);
INSERT INTO T VALUES (17,4,1960,89);
INSERT INTO T VALUES (18,4,1960,10);
INSERT INTO T VALUES (19,4,1960,45);
INSERT INTO T VALUES (21,4,1960,63);
INSERT INTO T VALUES (22,4,1960,44);
INSERT INTO T VALUES (23,4,1960,86);
INSERT INTO T VALUES (24,4,1960,5);
INSERT INTO T VALUES (25,4,1960,3);
INSERT INTO T VALUES (26,4,1960,8);
INSERT INTO T VALUES (27,4,1960,27);
INSERT INTO T VALUES (28,4,1960,28);
INSERT INTO T VALUES (29,4,1960,141);
INSERT INTO T VALUES (30,4,1960,0);
INSERT INTO T VALUES (31,4,1960,7);
INSERT INTO T VALUES (32,4,1960,37);
INSERT INTO T VALUES (1,4,2361,100);
INSERT INTO T VALUES (2,4,2361,7);
INSERT INTO T VALUES (3,4,2361,10);
INSERT INTO T VALUES (4,4,2361,49);
INSERT INTO T VALUES (5,4,2361,12);
INSERT INTO T VALUES (6,4,2361,0);
INSERT INTO T VALUES (1,4,1661,0);
INSERT INTO T VALUES (2,4,1661,0);
INSERT INTO T VALUES (3,4,1661,70);
INSERT INTO T VALUES (4,4,1661,99);
INSERT INTO T VALUES (5,4,1661,12);
INSERT INTO T VALUES (6,4,1661,0);

thanks in advance,
regards,
 

Query for gap "n days"

October 03, 2005 - 1:57 am UTC

Reviewer: Vikas Khanna from INDIA

Hi Tom,

I have made the query myself to obtain the desired results foa a given 7 days.

Can you please help me formulating the query for a given n days. .

Select a.cnt AS "Gap 1 Day",b.cnt "Gap 2 Day",c.cnt "Gap 3 Day",d.cnt "Gap 4 Day",e.cnt "Gap 5 Day",f.cnt "Gap 6 Day",g.cnt "Gap 7 Day" from
(Select Count(request_terms) cnt from (Select request_terms ,count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-6) group by request_terms having count(*) > 1)) a ,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-5) group by request_terms having count(*) > 2)) b,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-4) group by request_terms having count(*) > 3)) c,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-3) group by request_terms having count(*) > 4)) d,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-2) group by request_terms having count(*) > 5)) e,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate-1) group by request_terms having count(*) > 6)) f,
(Select Count(request_terms) cnt from (Select request_terms, count(*) from request_data where request_date between trunc(sysdate-7) and trunc(sysdate) group by request_terms having count(*) > 7)) g
/

Gap 1 Day Gap 2 Day Gap 3 Day Gap 4 Day Gap 5 Day Gap 6 Day Gap 7 Day
---------- ----------- ----------- ---------- ---------- ----------- ----------
107164 138381 98008 98248 96968 84028 83946

The create DDL scripts is

CREATE TABLE CLICK_DATA(
CLICK_TAG VARCHAR(16) NOT NULL,
REQUEST_TERMS VARCHAR(16) NOT NULL,
REQUEST_DATE DATE
CONSTRAINT CLICK_DATA_PK PRIMARY KEY (CLICK_TAG)
USING INDEX TABLESPACE TS_INDEX
)
TABLESPACE TS_DATA;

Looking forward to the solution.


Regards
Vikas

Tom Kyte

Followup  

October 03, 2005 - 7:32 am UTC

you can do this without running N queries in inline views. eg: you can simplify this.

my question not answered

October 03, 2005 - 8:41 am UTC

Reviewer: ramis from pak

Hi Tom,
you have not answered my question yet two post above
i.e.
sql query of sum before a particular value??

I am waiting for your response!
regards,





Tom Kyte

Followup  

October 03, 2005 - 11:13 am UTC

I do not see every posting, I do not answer every single request.


In this case, I saw something that required me to page down three or four times and said simply "don't have time for this"

In other words - too big, I answer these "quickly" or not at all.

To Ramis; your query

October 03, 2005 - 1:28 pm UTC

Reviewer: A reader from Berwyn, PA

Select t.player_id, sum(t.score), max(t.score), min(match_id), max(match_id)
From t
where match_id < ( Select t1.match_id from t t1 where t1.score=100 and t1.player_id=t.player_id)
group by t.player_id

Thia assumes match_id is in "correct" sequence in your data. If it isn't, try to use datetime stamps for the scores. We were bitten by sequences not guaranteeing the right order for transactions.



Please help

October 04, 2005 - 12:50 am UTC

Reviewer: Vikas Khanna from INDIA

Hi Tom,

That's what I was looking for help. Can you please simplify this for me to generate this for a given "n" number of days.

Would appreciate if you can let me know the query for this.

Regards
Vikas

Tom Kyte

Followup  

October 04, 2005 - 1:41 pm UTC

it is hard when I don't have any simple test data to play with.


I believe this:

(Select Count(request_terms) cnt
from (Select request_terms ,count(*)
from request_data
where request_date between trunc(sysdate-7) and trunc(sysdate-6)
group by request_terms
having count(*) > 1)) a ,
(Select Count(request_terms) cnt
from (Select request_terms, count(*)
from request_data
where request_date between trunc(sysdate-7) and trunc(sysdate-5)
group by request_terms
having count(*) > 2)) b,



can be phrased as this:


select count( case when rt1 > 1 then request_terms ) c1,
count( case when rt2 > 2 then request_terms ) c2,
....
from (
select request_terms
count(
case when request_date between trunc(sysdate-7) and trunc(sysdate-6)
then 1
end ) rt1,
count(
case when request_date between trunc(sysdate-7) and trunc(sysdate-5)
then 1
end ) rt2,
....
from request_data
where reqest_date >= trunc(sysdate-7)
group by request_terms
)



but having no data to test with....

Question on Select Query

October 04, 2005 - 8:50 am UTC

Reviewer: Newbie

I would like to know if there is a select query statement which will return true if and only if all the rows are present in the table.

For ex:
In table ORDER_TYPE
order_id order_type
1 SHIP
2 PLANE


The select query should return true if and only if the ORDER_TYPE table contains both the values i.e SHIP,PLANE















Tom Kyte

Followup  

October 04, 2005 - 4:28 pm UTC

queries don't really return "true" or "false", but rather a set of data.

select 1
from t
where order_type in ( 'SHIP', 'PLANE' )
having count(distinct order_type) = 2;


will return 1 or "nothing"

RE: NEWBIE

October 04, 2005 - 3:57 pm UTC

Reviewer: David Eads from Alpharetta, GA USA

How about:

select count(*) from dual
where exists(select * from order_type where order_type='SHIP')
and exists(select * from order_type where order_type='PLANE')

Tom Kyte

Followup  

October 04, 2005 - 8:08 pm UTC

that works as well - there are many ways to do this.

Sql Query

October 04, 2005 - 7:23 pm UTC

Reviewer: ian gallacher from scotland

Creating a view using where ( select In )
consider this example :-
drop table t1;
create table t1
( t1_a varchar2(1),
t1_b varchar2(1));

drop table t2;
create table t2
( t2_a varchar2(1),
t2_b varchar2(1));

drop view v1;
create view v1 as
select * from t1 where t1_a in
( select distinct t1_b from t2);

Rem t1_b not in table T2! and view created without errors

View is created without errors
why does select distinct t1_b from t2 give no errors
since t1_b is not a valid column on table t2 !

Running
select distinct t1_b from t2 alone gives error
invalid column name as expected

Any comments would be appreciated

Ian

Tom Kyte

Followup  

October 04, 2005 - 9:03 pm UTC

create view v1 as
select * from t1 where t1_a in
( select distinct t1.t1_b from t2);
^^^

is what you coded, perfectly 100% valid SQL and part of the way it is supposed to work.

it is called a correlated subquery, sort of like:

select * from dept
where exists ( select null from emp where emp.deptno = dept.deptno )


ALL columns are "passed" into the subquery as correlation variables.

(correlation names are good.... avoid this problem all together.)

Not a bug, but rather the way the SQL standard says to do it.

Thanks

October 04, 2005 - 11:29 pm UTC

Reviewer: NewBie

Thank you all.Tom this is a very useful site.Good Work Keep it up.And one question? How can I also become an expert like you?



Tom Kyte

Followup  

October 05, 2005 - 7:00 am UTC

time.

</code> http://asktom.oracle.com/Misc/question.html <code>

sql

October 05, 2005 - 2:36 am UTC

Reviewer: tony from usa

Hi tom,

I have a query here.
I have a table

V_FILE_NAM D_MIS_DATE D_SYS_DATE
ED_MISPRI 12/8/2003 1/9/2004 8:08:33 PM
ED_MISEXT 12/10/2003 1/9/2004 8:18:09 PM
ED_MISPRI 12/9/2003 1/9/2004 8:19:05 PM
ED_MISPRI 12/10/2003 1/14/2004 2:50:54 PM
ED_MISSTAT_020 12/10/2003 1/14/2004 4:05:52 PM
ED_MISSTAT_098 12/10/2003 1/14/2004 4:07:40 PM
ED_MISSTAT_101 12/10/2003 1/14/2004 4:07:51 PM
ED_MISSTAT_103 12/10/2003 1/14/2004 4:08:03 PM
ED_MISSTAT_104 12/10/2003 1/14/2004 4:08:13 PM
ED_MISSTAT_107 12/10/2003 1/14/2004 4:08:32 PM
ED_MISEXT 12/11/2003 1/15/2004 2:35:08 PM
ED_MISEXT 12/12/2003 1/15/2004 2:41:27 PM
ED_MISPRI 12/11/2003 1/15/2004 2:45:03 PM
ED_MISPRI 12/12/2003 1/15/2004 2:49:31 PM
ED_MISSTAT_020 12/11/2003 1/15/2004 2:56:49 PM
ED_MISSTAT_101 12/11/2003 1/15/2004 2:57:33 PM
ED_MISSTAT_103 12/11/2003 1/15/2004 2:57:41 PM
ED_MISSTAT_104 12/11/2003 1/15/2004 2:57:48 PM
ED_MISSTAT_107 12/11/2003 1/15/2004 2:57:56 PM
ED_MISSTAT_020 12/12/2003 1/15/2004 3:03:05 PM
ED_MISSTAT_101 12/12/2003 1/15/2004 3:03:26 PM
ED_MISSTAT_103 12/12/2003 1/15/2004 3:03:39 PM

here the D_SYS_DATE is the process time...

I want to get the montly audit statment where i need to get the min start time ,end time,avg time for a month,thease are loading jobs and d_mis_date is the date on which the file came and the process date

Tom Kyte

Followup  

October 05, 2005 - 7:22 am UTC

well, given your data and date format - I'm not sure what the dates represent (dd/mm/yyyy or mm/dd/yyyy).


I don't know what MONTH a given record should fall into (the month of the START (d_mis_date) or the month of the END (d_sys_date))


but, once you figure that out, you just


select trunc(dt,'mm'),
min(d_mis_date),
max(d_sys_date),
avg(d_sys_date-d_mis_date)
from t
group by trunc(dt,'mm')


where DT is the column you picked to be "the month"

sql query using where/in

October 05, 2005 - 12:22 pm UTC

Reviewer: ian gallacher from scotland

Hi Tom,

Still a bit perplexed on behaviour of query but live and learn !

Am I using the where in construct correctly or would you suggest a different approach ?

Real life example is

T1 is view of patient contact details conditioned by a user supplied date

T2 are sets of views of other patient information for patients who are in the T1 view

Have used “where” “distinct” “In” T1 construct so that conditioning for patients selected is controlled by the one view and if conditioning changes only need to amend T1 view

Hope this I have explained my self and look forward to hearing your comments

Thanks

Ian


Tom Kyte

Followup  

October 05, 2005 - 1:42 pm UTC

Yes, I would use IN


select * from t1 where some_key in ( select t2.some_other_key from t2 )


no need for distinct, the semantics of "in" don't necessitate that.

sql query using where/in

October 05, 2005 - 4:10 pm UTC

Reviewer: ian gallacher from scotland

Hi Tom

Thanks - will use In with confidence and remove distinct

Ian


query

October 11, 2005 - 10:29 pm UTC

Reviewer: mo

Tom:

Is there a way to count numbers in a varchar2 field?

ORG_CODE varchar2(10)
------------
ABC
123
456
DEF

For the above data the count should = 2.

THanks,

Tom Kyte

Followup  

October 12, 2005 - 7:10 am UTC

create a plsql function that tries to convert a string to a number.

function returns 1 when conversion is successful
function returns 0

then you can select count(*) from t where is_number(string) = 1;


query

October 12, 2005 - 7:33 am UTC

Reviewer: mo

Tom:

Do you have this function anywhere on the webiste? Would you use to_number(x) and if it works you return 1 else return 0.



Tom Kyte

Followup  

October 12, 2005 - 7:45 am UTC

it is a pretty simple thing - try to covert - return 1, exception block - return 0.

ops$tkyte@ORA10GR1> select is_number( 'a' ) from dual;
 
IS_NUMBER('A')
--------------
             0
 
ops$tkyte@ORA10GR1> select is_number( '1' ) from dual;
 
IS_NUMBER('1')
--------------
             1
 
ops$tkyte@ORA10GR1> select is_number( '1e10' ) from dual;
 
IS_NUMBER('1E10')
-----------------
                1
 


but - if you know your numbers are only to be digits say 0..9 - you can of course simplify this greatly using builtin functions like translate.   

query

October 12, 2005 - 10:13 am UTC

Reviewer: mo

Tom:

This is_number function does not work in 8i and 9i. The database is 8i.


SQL> select is_number( 'a' ) from dual;
select is_number( 'a' ) from dual
       *
ERROR at line 1:

ORA-00904: invalid column name

Also the number value is always numbers 0..9.

What would you do here.


 

Tom Kyte

Followup  

October 12, 2005 - 1:58 pm UTC

i wante you to write it, it is a very simple thing.

create or replace function is_number( p_str in varchar2 ) return number
as
l_num number;
begin
l_num := to_number(p_str);
return 1;
exception
when others then return 0;
end;
/



Missing data found!

October 12, 2005 - 11:51 am UTC

Reviewer: Robert Simpson from Pittsburgh, PA

As for (3) in the original question, the answer to (2) works as long as the "missing" data is added to the table. In this case, the data should be:

AC006 10 DC001 2/1/2002
AC006 20 DC002 2/1/2002

AC006 0 DC001 5/1/2002
AC006 0 DC002 5/1/2002

AC006 100 DC003 5/1/2002
AC006 50 DC004 5/2/2002


SQl QUERY

October 13, 2005 - 12:40 am UTC

Reviewer: Totu from Az

Dear All.

I have below tables:

[Docs]
DocID DocName
1 Doc1
2 Doc2
3 Doc3
....

[DocTasks]
DocID TaskID
1 1
1 2
2 1
2 3
2 2
3 2
3 1
4 5
4 2
4 1
4 3
5 3
5 2
....

[Tasks]
TaskID TaskName
1 Task1
2 Task2
3 Task3
4 Task4
...

Now I want to get TaskID-s from DocTasks table, where each that TaskID belongs to all DocID-s in DocTasks table. For example:
TaskID 1 belongs to DocIDs(1, 2, 3, 4) -> This TaskID is not needed
TaskID 2 belongs to ALL DocIDs(1, 2, 3, 4, 5) -> This TaskID is needed
TaskID 3 belongs to DocIDs(2, 4, 5) -> This TaskID is not needed. So on..
So, Query must return only TaskID=2, because only this TaskID belongs to All DocIDs.

Thanks in advance.

Tom Kyte

Followup  

October 13, 2005 - 10:32 am UTC

i don't really even look at these without create tables and inserts - no promises that when they are placed here I can answer it - but......

Create table

October 13, 2005 - 3:10 am UTC

Reviewer: Bala from Bangalore, India

Hi Tom,
I need to create a table as the table which is available on another db. For eg: I am connected to X and want to create a table on this, which already exists on database Y like,
create table abc as select abc@Y .... etc.
Is there a way to do this?


Tom Kyte

Followup  

October 13, 2005 - 10:34 am UTC

you just gave the entire syntax for it pretty much?

create table abc as select * from abc@y;



generic sql query

October 17, 2005 - 7:44 am UTC

Reviewer: ramis from pak

Hi Tom,

would you please help this out for me

I have a query

select t.*,
case when col2 in (1, 17)
then rank() over (order by case when col2 in (1, 17) then 0 else null end, id)
else 0
end rank
from t
order by id
/

ID COL2 RANK
1 1 1
2 17 2
3 1 3
4 1 4
5 11 0
6 1 5


well that is perfectly fine,
can we make this query a generic one, that means given any set of two col2 values it shows the output


some things like this...

select t.*,
value1 = 1,
value2 = 17,
case when col2 in (value1, value2)
then rank() over (order by case when col2 in (value1, value2) then 0 else null end, id)
else 0
end rank
from t
order by id
/

output

ID COL2 RANK value1 value2
1 1 1 1 17
2 17 2 1 17
3 1 3 1 17
4 1 4 1 17
5 11 0 1 17
6 1 5 1 17

[/pre]

i mean in such a query we would not need to change the col2 values
inside the CASE statement but just pass the two values at the top
which will get the same desired ouput..

also value1 and value 2 should act as columns

best regards,

create table t
(id number,
col2 number)
/


insert into t values ( 1, 1)
insert into t values (2, 17)
insert into t values (3 , 1)
insert into t values (4 , 1)
insert into t values (5 , 11)
insert into t values (6 , 1)




Tom Kyte

Followup  

October 17, 2005 - 8:08 am UTC

sql is like a program - you cannot change the columns/tables whatever in a given query. You would have to write a procedure that dynamically BUILDS a given query based on inputs you send to it.

how to write a dynamic procedure

October 17, 2005 - 9:52 am UTC

Reviewer: ramis from pak

Hi, tom,
thanks for your response,

would you please help me the writing a procedure, as you mentioned above, that dynamically BUILDS a given query based on inputs we send to it.

regards,
Ramis.

Tom Kyte

Followup  

October 17, 2005 - 10:08 am UTC

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>

has an example, there are tons of them - it is just dynamic sql

October 19, 2005 - 11:24 am UTC

Reviewer: A reader from USA

Hi Tom,

Your advice to solve this problem, would be greatly appreciated.

DROP TABLE T
/
create table T
(id number
,qty number
,trn_date date
)
/
insert into t values (1,1,'01-JAN-2005')
/
insert into t values (1,3,'03-JAN-2005')
/
insert into t values (1,7,'05-JAN-2005')
/
select * from t;

ID QTY TRN_DATE
-------------------- -------------------- ---------
1 1 01-JAN-05
1 3 03-JAN-05
1 7 05-JAN-05

For any given day, calculate the qty based on date:
The output required as:

ID QTY TRN_DATE
1 1 01-JAN-05
1 1 02-JAN-05
1 3 03-JAN-05
1 3 04-JAN-05
1 7 05-JAN-05

This is in Data Warehousing environment in Oracle 9.2.0.5.
Table has around 5 million rows with 1.5 million unique ids.
Any pointers to achieve this would be greatly appreciated.
I wrote a function to calucate quantity for any given day. For 1.5M ids, it takes around 25 min to run.
Is there anyway, we can achieve this in single sql.

Thanks in advance.

Tom Kyte

Followup  

October 19, 2005 - 12:37 pm UTC

need more info.

assuming in real life - more than 1 id right and this should be "by id"

assuming in real life you will either

a) expect to find the min/max date by id for trn_date from the table and use that range for each ID

or...

b) expect to find the min/max date OVER ALL records for trn_date and use that range for each ID

or...

c) you input the date range of interest and we only use that range.


(this is a simple carry down, we can do this with analytics)


October 19, 2005 - 8:35 pm UTC

Reviewer: A reader from USA

Hi Tom,

You are correct.

For front end tool to run faster, they want me to create a table with trn_quantity for everyday for all ids. There is no date range. Can you please illustrate, how to achive this with analytics. Thanks for your advice.

Tom Kyte

Followup  

October 20, 2005 - 7:51 am UTC

I asked a three part OR question.

I cannot be correct ;) I don't know which of the three is right.


what is "everyday"

October 20, 2005 - 9:55 am UTC

Reviewer: A reader

Tom,

Table has to be populated with qty and trn_date on a daily basis , eventhough there was no transaction for that date.
The quantity has to be derived from the most recent quantity for that id. Hope I am clear.

Tom Kyte

Followup  

October 20, 2005 - 4:28 pm UTC

Ok, I put this in october to make it have less rows to demo with:

ops$tkyte@ORA10GR1> select * from t;

        ID        QTY TRN_DATE
---------- ---------- ---------
         1          1 01-OCT-05
         1          3 03-OCT-05
         1          7 05-OCT-05

ops$tkyte@ORA10GR1>

Your initial "populate" will insert these values, set start_date to your lowest start date you want:


ops$tkyte@ORA10GR1> variable start_date varchar2(20)
ops$tkyte@ORA10GR1> exec :start_date := '01-oct-2005';

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR1>
ops$tkyte@ORA10GR1> with dates
  2  as
  3  (select to_date(:start_date,'dd-mon-yyyy')+level-1 dt
  4     from dual
  5  connect by level <= sysdate-to_date(:start_date,'dd-mon-yyyy')+1 ),
  6  ids
  7  as
  8  (select distinct id from t ),
  9  dates_ids
 10  as
 11  (select * from dates, ids )
 12  select dates_ids.id, dates_ids.dt, max(t.qty) over (order by dates_ids.dt) qty
 13    from dates_ids left outer join t on (dates_ids.id = t.id and dates_ids.dt = t.trn_date);

        ID DT               QTY
---------- --------- ----------
         1 01-OCT-05          1
         1 02-OCT-05          1
         1 03-OCT-05          3
         1 04-OCT-05          3
         1 05-OCT-05          7
         1 06-OCT-05          7
         1 07-OCT-05          7
         1 08-OCT-05          7
         1 09-OCT-05          7
         1 10-OCT-05          7
         1 11-OCT-05          7
         1 12-OCT-05          7
         1 13-OCT-05          7
         1 14-OCT-05          7
         1 15-OCT-05          7
         1 16-OCT-05          7
         1 17-OCT-05          7
         1 18-OCT-05          7
         1 19-OCT-05          7
         1 20-OCT-05          7

20 rows selected.


<b>and then every day, you run this</b>

ops$tkyte@ORA10GR1>
ops$tkyte@ORA10GR1>
ops$tkyte@ORA10GR1> select id, sysdate, qty
  2    from (select id, trn_date, max(trn_date) over (partition by id) max_dt, qty from t)
  3   where trn_date = max_dt;

        ID SYSDATE          QTY
---------- --------- ----------
         1 20-OCT-05          7

<b>and if you "miss a day" for whatever reason, just use the first query again to fill in the gaps</b>
 

October 20, 2005 - 6:30 pm UTC

Reviewer: A reader

Brilliant, as usual!!!

Thanks a lot.
I need to understand the concept behind your first query.



sql query..

October 23, 2005 - 11:57 am UTC

Reviewer: ramis from karachi

Hi Tom,

i have a db table having thousands of records

two of the columns of that table are



MATCH_ID TEAM_ID
1 2
1 2
1 2
1 2
1 2
1 2
1 2
1 2
1 2
1 2
1 2
1 3
1 3
1 3
1 3
1 3
1 3
1 3
1 3
1 3
1 3
1 3



each MATCH_ID has 22 occurances of two different TEAM_ID's (11 each)
this pattern is followed throghtout the table
i..e in above data MATCH_ID = 1 has 11 occuracnes of TEAM_ID = 2
and 11 occuracnes of TEAM_ID = 3

i want the shortest possible query that shows me the the opposite TEAM_ID
against the other TEAM_ID in the same MATCH_ID

for example (desired output)



MATCH_ID TEAM_ID OPP_TEAM_ID
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 2 3
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2
1 3 2



as you can see there are two diffrent types of TEAM_ID
in the data for MATCH_ID = 1.
So, the third column shows the opposite TEAM_ID for the other
TEAM_ID in the same MATCH


hope ths will clear my requiremnt
I want the shortest possible query to achieve this




create table t
(match_id number(2),
team_id number(2))
/


insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,2);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);
insert into T values (1,3);



Tom Kyte

Followup  

October 23, 2005 - 1:45 pm UTC

ops$tkyte@ORA10GR1> select match_id, team_id,
  2         decode( team_id,
  3                     max(team_id) over (partition by match_id) ,
  4                 min(team_id) over (partition by match_id) ,
  5                     max(team_id) over (partition by match_id) ) other_tid
  6    from t
  7  /

  MATCH_ID    TEAM_ID  OTHER_TID
---------- ---------- ----------
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          2          3
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2
         1          3          2

22 rows selected.
 

sql query for this??

November 01, 2005 - 8:37 am UTC

Reviewer: ramis from karachi

Hi

I have a table with data in the following format


Col1 COL2
A 2
B
C
D
E
F 45
G
H
I 33


I want a query that would fill the gaps with the last non-null value in col2

desired output

Col1 COL2 output_col
A 2 2
B 2
C 2
D 2
E 2
F 45 45
G 45
H 45
I 33 33


as you can see the output_column shows the last non-null value of the col2 for each row..if for any row it finds a new col2 value then it shows that value for that row and for next rows until it finds another new one and so on


how to achieve that from sql query...??

regards,

create table t
(col1 varchar2(10),
col2 number(5))

INSERT INTO T VALUES (A,2);
INSERT INTO T VALUES (B,NULL);
INSERT INTO T VALUES (C,NULL);
INSERT INTO T VALUES (D,NULL);
INSERT INTO T VALUES (E,NULL);
INSERT INTO T VALUES (F,45);
INSERT INTO T VALUES (G,NULL);
INSERT INTO T VALUES (H,NULL);
INSERT INTO T VALUES (I,33);



Tom Kyte

Followup  

November 01, 2005 - 10:58 am UTC

10g and up and then 8i-9i solutions:

ops$tkyte@ORA10GR2> select col1, col2, last_value(col2 ignore nulls ) over (order by col1) oc
  2    from t;

COL1             COL2         OC
---------- ---------- ----------
A                   2          2
B                              2
C                              2
D                              2
E                              2
F                  45         45
G                             45
H                             45
I                  33         33

9 rows selected.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> select col1, col2,
  2         to_number( substr( max(oc1) over (order by col1), 7 ) ) oc
  3    from (
  4  select col1, col2,
  5         case when col2 is not null
  6                  then to_char(row_number() over (order by col1),'fm000000')||
  7                               col2
  8                  end oc1
  9    from t );

COL1             COL2         OC
---------- ---------- ----------
A                   2          2
B                              2
C                              2
D                              2
E                              2
F                  45         45
G                             45
H                             45
I                  33         33

9 rows selected.

 

Creating table on another db

November 02, 2005 - 12:01 am UTC

Reviewer: Kumar from India

Hi Tom,
Earlier one person had asked about creating a table on different db and you had replied

create table abc as select * from abc@y;

But, when I tried this, I am getting
ORA-02019 connection description for remote database not found.

Regards,
kumar



Tom Kyte

Followup  

November 02, 2005 - 5:03 am UTC

you need to create a database link named "Y" first - see the create database link command in the sql reference.

Cursor question

November 04, 2005 - 6:19 am UTC

Reviewer: jp from Dubai

Tom,

I am trying to query information from one table and insert the information in a new table,  but one of the column is an expresion and am alway getting error

SQL> create table tab1
  2  (jobs varchar2(20),
  3  tot_salary number);

Table created.

SQL> create or replace procedure ins_dat is
  2
  3  CURSOR c1_cur is
  4  select job "j", sum(sal) "s" from emp
  5  group by job;
  6  begin
  7  for c1_rec in c1_cur
  8  Loop
  9  insert into tab1 values (c1_rec.j,c1_rec.s);
 10
 11  end loop;
 12  commit;
 13  end;
 14  /

Warning: Procedure created with compilation errors.

SQL> show err
Errors for PROCEDURE INS_DAT:

LINE/COL ERROR
-------- -----------------------------------------------------------------
9/1      PL/SQL: SQL Statement ignored
9/42     PLS-00302: component 'S' must be declared
9/42     PL/SQL: ORA-00984: column not allowed here

Then I tried declaring both variables,  but still getting errors..

SQL> create or replace procedure ins_dat is
  2  j varchar2(20);
  3  s number;
  4  CURSOR c1_cur is
  5  select job "j", sum(sal) "s" from emp
  6  group by job;
  7  begin
  8  for c1_rec in c1_cur
  9  Loop
 10  insert into tab1 values (c1_rec.j,c1_rec.s);
 11
 12  end loop;
 13  commit;
 14  end;
 15  /

Warning: Procedure created with compilation errors.

SQL> show err
Errors for PROCEDURE INS_DAT:

LINE/COL ERROR
-------- -----------------------------------------------------------------
10/1     PL/SQL: SQL Statement ignored
10/42    PLS-00302: component 'S' must be declared
10/42    PL/SQL: ORA-00984: column not allowed here

Can you help me to sort it out this?

thanks  

Tom Kyte

Followup  

November 04, 2005 - 8:49 am UTC

"j" and "s" are lower case

c1_rec."j"

sql query help?

November 07, 2005 - 8:52 am UTC

Reviewer: saad from pak

HI Tom

i have a db table having thousands of records

three of the columns of that table are


NO. M_ID T_ID
1 1 2
2 1 2
3 1 3
4 1 3
5 2 6
6 2 9
7 3 10
8 3 2

The No. column shows the chronlogical number of records in the table (this is a primary key column)

each M_ID has two different T_ID's
this pattern is followed throghout the table
i..e in above data M_ID = 1 has two distinct T_ID's i.e. 2 & 3

i want the shortest possible query that shows the ascending number of distinct "T_ID's" in each "M_id" order by the "No." column

for example (desired output)

No. M_ID T_ID desred_column
1 1 2 1
2 1 2 1
3 1 3 2
4 1 3 2
5 2 6 1
6 2 9 2
7 3 10 1
8 3 2 2


as you can see there are two diffrent types of T_ID's in the data for M_ID = 1.
And T_ID = 2 comes first then T_ID = 3 in M_ID = 1
So, the fourth column shows the 1 for T_ID = 2 and shows 2 for T_ID = 2


hope ths will clear my requiremnt
I want the shortest possible query to achieve this
regards,



create table t
(Num_c number(4),
M_ID number(2),
T_ID number(2))
/


insert into T values (1,1,2) ;
insert into T values (2,1,2) ;
insert into T values (3,1,3) ;
insert into T values (4,1,3) ;
insert into T values (5,2,6) ;
insert into T values (6,2,9);
insert into T values (7,3,10) ;
insert into T values (8,3,2) ;


Tom Kyte

Followup  

November 07, 2005 - 11:29 am UTC

well, count(distinct t_id) over (partition by m_id order by num_c) won't do it - you cannot order by a distinct in this case....


would counting state changes be sufficient with your data? that is, if the data is:


1 1 2 (1)
2 1 3 (2)
3 1 3 (2)
4 1 2 (3) <<<=== does this happen, 2 to 3 to 2? and if so, is double
counting like this permitted?

just a little problem remains...??

November 07, 2005 - 10:39 am UTC

Reviewer: saad from pak

Tom, in my question above "SQL query help?"

i have managed to solve my problem abit but still it is showing wrong result for a row

this was the data


NUM_C M_ID T_ID
---------- ---------- ----------
1 1 2
2 1 2
3 1 3
4 1 3
5 2 6
6 2 9
7 3 10
8 3 2

and this was my desired output

NUM_C M_ID T_ID RESULT_COLUMN
1 1 2 1
2 1 2 1
3 1 3 2
4 1 3 2
5 2 6 1
6 2 9 2
7 3 10 1
8 3 2 2

i used this query

select num_c
, m_id
, t_id
, dense_rank() over (partition by m_id order by t_id) result_column
from t

and it gave me this

NUM_C M_ID T_ID RESULT_COLUMN
--------- ---------- ---------- -------------
1 1 2 1
2 1 2 1
3 1 3 2
4 1 3 2
5 2 6 1
6 2 9 2
8 3 2 1
7 3 10 2



please check the last two rows
the query puts num_c = 8 before num_c = 7 and hence gives wrong ranking
I want to rank the data by distinct T_ID in each M_ID as ordered by the num_c column

please help me to solve this one!
regards,

Tom Kyte

Followup  

November 07, 2005 - 8:17 pm UTC

you ordered by t_id, not by num_c - therefore you have no reason to say "it gives wrong answer", it sorted by a completely different field ?!?!?

query problem??

November 07, 2005 - 8:31 pm UTC

Reviewer: saad from pak

Tom,
in my question above, by wrong result I meant not according to my requirement..or not matching my desired output..
would you please fix that one..ddl data is given with my original question (two posts above..)

regards,

to: Saad.

November 08, 2005 - 12:28 am UTC

Reviewer: Marcio Portes

Saad, as far as I understand here you've got your desired result but the order, so just order it.

select *
from (
select num_c
, m_id
, t_id
, dense_rank() over (partition by m_id order by t_id) result_column
from t
)
order by num_c



problem still not solved??

November 08, 2005 - 2:56 pm UTC

Reviewer: saad from pak

Marcio Portes and Tom,
no my problem is not solved as you have suggested above in your query

select *
from (
select num_c
, m_id
, t_id
, dense_rank() over (partition by m_id order by t_id) result_column
from t
)
order by num_c


it gives this

NUM_C M_ID T_ID RESULT_COLUMN
--------- ---------- ---------- -------------
1 1 2 1
2 1 2 1
3 1 3 2
4 1 3 2
5 2 6 1
6 2 9 2
7 3 10 2
8 3 2 1

see the last two rows, for num_c = 7 it puts RESULT_COLUMN = 2 and for num_c = 8 it puts RESULT_COLUMN = 1

it should have been
NUM_C M_ID T_ID RESULT_COLUMN
7 3 10 1
8 3 2 2

the ranking should be done ordered by the num_c column
as i am said in my original question above..

Tom, looking for your help??



Tom Kyte

Followup  

November 08, 2005 - 10:33 pm UTC

not sure you can do this, but if you give me a create table and insert into's, i'll give it a try (I think i have an idea...)

select distinct

November 08, 2005 - 4:08 pm UTC

Reviewer: A reader

I have a table datflow which has 5 min data
METERID
RECORDERTYPE
TESTDATETIME
AVGOFFLOWVALUE
DATE_
I need to select for each meterid and recorder type
count of distinct number of days in a month(testdatetimestamp)
something like
select meterid, recordertype,
count(distinct number of days in this month trunc(date_,'mm')) datflow_5m
group by meterid, recordertype, trunc(date_,'mm')


To Saad:

November 09, 2005 - 3:45 am UTC

Reviewer: Ravi from India

Saad,
Below is one way to get the result.Its w/o using analytics.
select num_c,
m_id,
t_id,
(select count(distinct(t_id)) from t where m_id=t1.m_id and num_c<=t1.num_c) rank1
from t t1


Tom Kyte

Followup  

November 09, 2005 - 9:48 am UTC

yes, very good - thanks!

missed the obvious, won't be really "performant" but for small sets, that'll work.

To Ravi from India

November 09, 2005 - 9:29 am UTC

Reviewer: saad from pak

Ravi, thank you so much for your query its done!

select num_c,
m_id,
t_id,
(select count(distinct(t_id)) from t where m_id=t1.m_id and
num_c<=t1.num_c) rank1
from t t1

/

NUM_C M_ID T_ID RANK1
------ ---------- ---------- ----------
1 1 2 1
2 1 2 1
3 1 3 2
4 1 3 2
5 2 6 1
6 2 9 2
7 3 10 1
8 3 2 2

regards,

null for duplicate names??sql help

November 09, 2005 - 12:00 pm UTC

Reviewer: ali from pak

Hi,

I am facing s problem hope you would help

I am running a query that shows me name of employees from a table with their
employee_ids

select emp_id, emp_name from t
/

EMP_ID EMP_NAME
1820 Waugh
1920 King
1936 Ric
1940 Taylor
2036 Smith
2123 Paul
2157 ALi
2181 Smith
2189 Joe
2332 Bichel
2333 Usman

I want that if there are more than ONE same EMP_NAMES returned by the query,

then query should not show the emp_name but instead should show 'duplicate

name' for matching names

so in my above data the name SMITH has come twice
so my desired output is

EMP_ID EMP_NAME
1820 Waugh
1920 King
1936 Ric
1940 Taylor
2036 DUPLICATE NAME
2123 Paul
2157 ALi
2181 DUPLICATE NAME
2189 Joe
2332 Bichel
2333 Usman


hope this will clear my requirement, I need the fastest and shortest possible

query to achieve this

CREATE TABLE T
(EMP_ID NUMBER(4),
EMP_NAME VARCHAR2(25))
/

INSERT INTO T VALUES (1820,'Waugh');
INSERT INTO T VALUES (1920,'King');
INSERT INTO T VALUES (1936,'Ric');
INSERT INTO T VALUES (1940,'Taylor');
INSERT INTO T VALUES (2036,'Smith');
INSERT INTO T VALUES (2123,'Paul');
INSERT INTO T VALUES (2157,'ALi');
INSERT INTO T VALUES (2181,'Smith');
INSERT INTO T VALUES (2189,'Joe');
INSERT INTO T VALUES (2332,'Bichel');
INSERT INTO T VALUES (2333,'Usman');


regards,




Tom Kyte

Followup  

November 11, 2005 - 10:21 am UTC

ops$tkyte@ORA10GR2> select emp_id,
  2         case when count(emp_name) over (partition by emp_name) > 1
  3              then 'duplicate name'
  4              else emp_name
  5          end emp_name
  6    from t;

    EMP_ID EMP_NAME
---------- --------------------
      2157 ALi
      2332 Bichel
      2189 Joe
      1920 King
      2123 Paul
      1936 Ric
      2181 duplicate name
      2036 duplicate name
      1940 Taylor
      2333 Usman
      1820 Waugh

11 rows selected.

 

re: null for duplicate names??sql help

November 09, 2005 - 12:14 pm UTC

Reviewer: Jonathan Taylor from Huddersfield, UK

SQL> select emp_id
  2  , decode (count(*) over (partition by emp_name)
  3           ,1,emp_name
  4           ,'DUPLICATE NAME'
  5           ) emp_name
  6  from t
  7  ;

EMP_ID EMP_NAME
------ -------------------------
  2157 ALi
  2332 Bichel
  2189 Joe
  1920 King
  2123 Paul
  1936 Ric
  2036 DUPLICATE NAME
  2181 DUPLICATE NAME
  1940 Taylor
  2333 Usman
  1820 Waugh

11 rows selected
 

November 09, 2005 - 2:22 pm UTC

Reviewer: fz from CA USA

from
A B
---------- -
1 x
1 y
2 y
3 x

is there a simple sql to get following?
A B
---------- -
1 x
2 y
3 x

(whenever 'A' is same, just take value 'x').


Tom Kyte

Followup  

November 11, 2005 - 10:26 am UTC

select a, max(b) from t group by a;

..to fz

November 10, 2005 - 7:58 am UTC

Reviewer: Alex N from Nieuwegein, the Netherlands

select a
, b
from (select a
, b
, Row_Number() over (partition by a
order by b
) rn
from t
)
where rn = 1


understanding not in operator

November 10, 2005 - 8:47 am UTC

Reviewer: Vaibhav from India

SQL> select * from temp1;

CASE_ID    BRIDGE_ID
---------- --------------------
A          id1
B          id2
C          id3

SQL> select * from temp2;

USER_CD    BRIDGE_ID
---------- ---------------
U1         id1
U2
U3         id2

SQL> select * from temp1 where bridge_id not in (select bridge_id from temp2);

no rows selected

SQL> select BRIDGE_ID from temp1
  2  minus
  3  select bridge_id from temp2;

BRIDGE_ID
--------------------
id3


If there's a null value, why doesnt the "not in" query work ?  

Tom Kyte

Followup  

November 11, 2005 - 11:50 am UTC

not in query did work, it did exactly what not in is defined and supposed to do.


when you have:

where x not in ( select y from t );

and some Y is NULL - it is "not known" if X is "not in" that set - nulls change everything


not exists and not in are "not equivalent"

To Ferdinand Maer -: Ename with space

November 10, 2005 - 9:23 am UTC

Reviewer: Jagjeet Singh from Delhi, India


SQL> r
  1  select ename, substr(e,instr(e,':')+1) ename2 from
  2*  ( select ename, replace( dump(ename,17),',',' ') e from emp )

ENAME        ENAME2
------------ ---------------------------------------------
SMITH         S M I T H
ALLEN         A L L E N
WARD          W A R D
JONES         J O N E S
MARTIN        M A R T I N
BLAKE         B L A K E
CLARK         C L A R K
SCOTT         S C O T T
KING          K I N G
TURNER        T U R N E R
ADAMS         A D A M S
JAMES         J A M E S
FORD          F O R D
MILLER        M I L L E R

14 rows selected.
 

To Jagjeet Singh

November 11, 2005 - 11:34 am UTC

Reviewer: Matthias Rogel from Kaiserslautern, Germany

nice idea, but not 100%-correct

insert into emp(ename) values ('A,B')


how to generate seasons??

November 11, 2005 - 1:56 pm UTC

Reviewer: saadia from pak

Tom,

I want to generate all the seasons between year 1950 upto 2005-06 season from a query..

in this format

SEASONS
1950
1950-51
1951
1951-52
1952
1952-53
1953
1953-54
....
....
....
....
2005
2005-06

would would be the query to get this ouput
regards,


Tom Kyte

Followup  

November 12, 2005 - 8:52 am UTC

ops$tkyte@ORA10GR2> with nums
  2  as
  3  (select ceil(level/2)-1 l, rownum r
  4     from dual
  5   connect by level <= (to_number(to_char(sysdate,'yyyy'))-1950+1)*2 )
  6  select to_char( 1950 + l ) || case when mod(r,2) = 0 then '-' || substr(to_char( 1950+l+1, 'fm9999') ,3) end dt
  7    from nums
  8  /

DT
--------------------------------------------
1950
1950-51
1951
1951-52
...
2004
2004-05
2005
2005-06

112 rows selected.

 

To -: Matthias Rogel

November 12, 2005 - 10:52 am UTC

Reviewer: Jagjeet Singh from Delhi, India

I knew this,

Need to generate any single character like '~' or '*' 
or any string which you will not have in your data.

I am using '@!$#%^'

SQL> r
  1  Select ename, replace( substr(e,instr(e,':')+1),'@ ! $ # % ^',',') e from
  2* (select ename,replace(dump(replace(ename,',','@!$#%^'),17),',',' ') e from emp)

ENAME                          E
------------------------------ ------------------------------------------------------------
SMITH                           S M I T H
ALLEN                           A L L E N
WARD                            W A R D
JONES                           J O N E S
MARTIN                          M A R T I N
BLAKE                           B L A K E
CLARK                           C L A R K
SCOTT                           S C O T T
KING                            K I N G
TURNER                          T U R N E R
ADAMS                           A D A M S
JAMES                           J A M E S
FORD                            F O R D
MILLER                          M I L L E R
A,B                             A , B

 

November 13, 2005 - 9:13 am UTC

Reviewer: saadia from pak

Tom, the query given below in your reply to my question (two posts above) is just great! thankyou so much.
the great thing about this query is that it generates the next season with the chnage in SYSDATE..

Tom, currently the process is starting from the season 1950, suppose I want to start it from 1949-50 season then what would be the query for that

desired output

DT
--------------------------------------------
1949-50
1950
1950-51
1951
1951-52
...
2004
2004-05
2005
2005-06


your query is this..

with nums
as
(select ceil(level/2)-1 l, rownum r
from dual
connect by level <= (to_number(to_char(sysdate,'yyyy'))-1950+1)*2 )
select to_char( 1950 + l ) || case when mod(r,2) = 0 then '-' ||
substr(to_char( 1950+l+1, 'fm9999') ,3) end dt
from nums


DT
--------------------------------------------
1950
1950-51
1951
1951-52
...
2004
2004-05
2005
2005-06

112 rows selected.


Tom Kyte

Followup  

November 13, 2005 - 10:35 am UTC

just change my 1950 to 1949? in all cases...



problem not solved

November 13, 2005 - 3:28 pm UTC

Reviewer: saadia from pak

Tom,
thanks for your reply but changing 1950 to 1949 does not solve my problem becasue it starts the season from 1949 but I want to start it from 1949-50

here i ran the query as you said

with nums
as
(select ceil(level/2)-1 l, rownum r
from dual
connect by level <= (to_number(to_char(sysdate,'yyyy'))-1949+1)*2 )
select to_char( 1949 + l ) || case when mod(r,2) = 0 then '-' ||
substr(to_char( 1949+l+1, 'fm9999') ,3) end dt
from nums
/


DT
-------------------------------------------
1949 <==== it starts season from 1949
1949-50 <==== but I want to start from here i.e. 1949-50
1950
1950-51
1951
1951-52
1952
1952-53
1953
1953-54
1954
...
2005-06

114 rows selected.

would you please help me out..
regards.



Tom Kyte

Followup  

November 13, 2005 - 5:10 pm UTC

where dt <> 1949


just add a predicate to get rid of the starting row if that is what you want.

Insert or Update statement in CASE statement

November 14, 2005 - 3:37 am UTC

Reviewer: Tata Jagadeesh from Hyderabad,India

Hi Tom,

1. Is it possible to use insert or update statement in CASE statement. If so, please provide an example.

2. Are there any chances NVL function fail and lead to exception?

Thanks in advance.

Tom Kyte

Followup  

November 14, 2005 - 9:09 am UTC

1) you have that "backwards", you can use case in an update and insert in SQL.

2) sure, nvl(x,1/0) for example

November 14, 2005 - 6:38 am UTC

Reviewer: A reader

Jagdeesh,

Why don't you try it yourself ?

Let's all collectively not waste such a precious gift to oracle community by asking such trivial questions. A gentle plea to all

mosts beofre first occurance

December 15, 2005 - 4:50 pm UTC

Reviewer: Ramis from Pak

Hello,

I am facing a problem hope anyone would help..
I have a table T with 15 columns and data stored in the following format

match_id player_ID Score Place Minutes
1 11 19 A 12
2 12 34 B 24
3 11 101 C 112
4 11 201 D 121
5 12 211 E 222
6 13 181 F 322
7 11 34 A 45
8 12 12 G 10
9 13 45 C 65
10 11 H
10 12 I
10 13 D
10 14 A
11 11 51 H 76
11 12 65 I 98
11 13 76 D 76
11 14 56 A 45

and so on upto 100,000 records..
Null entires show the player didn't get the chance to score

Here match_id and player_id are joinlty primary keys..(i.e. they do not repeat combined)

I want to extract some information for each player before he made his first score between 50 and 99 order by match_id

so my desired output for above data is

player_id =>100 sum(score) sum(minutes) No Place of 1st Match_id
_of_mats 50-99 score
11 2 355 290 5 B 11
12 1 322 256 4 I 11
13 1 226 387 3 D 11

player_id = 14 didn't come because he made score of 56 (i.e between 50 to 99) in his very scoring effort.

Here,
=>100 is the no. of times player scored 100 or more before his first 50-99 score order by match_id
sum(score) is the sum of all scores before his first 50-99 score
sum(minutes) is the sum of all scores before his first 50-99 score
No_of_mts is the no. of matches in which he took part before before his first 50-99 score
place_of_1st_50-99_score is the 'place' where he scored his first 50-99 score for the first time.
MATCH_ID is the match_id in which he scored his first 50-99 score for the first time.


in my desired output, you can see player_id = 11, for example, made two scores of =>100 before he made his first '50 to 99' score. similarly, the sum of his scores was 355, sum of minutes was 290, Total matches were 5 before he made his first score between 50 and 99

same is the case with other player_id's , except 14 how made his 50-99 score in his first scoring effort and hence would not come

hope this will clear my problem..
i would like to have the shortest and most efficient possible query for this..

regards

CREATE TABLE T
(match_id NUMBER(4),
player_ID NUMBER(4),
Score NUMBER(4),
Place VARCHAR2(10),
Minutes NUMBER(4))

INSERT INTO T VALUES (1,11,19,A,12)
INSERT INTO T VALUES (2,12,34,B,24)
INSERT INTO T VALUES (3,11,101,C,112)
INSERT INTO T VALUES (4,11,201,D,121)
INSERT INTO T VALUES (5,12,211,E,222)
INSERT INTO T VALUES (6,13,181,F,322
INSERT INTO T VALUES (7,11,34,A,45)
INSERT INTO T VALUES (8,12,12,G,10)
INSERT INTO T VALUES (9,13,45,C,65)
INSERT INTO T VALUES (10,11,NULL,H,NULL)
INSERT INTO T VALUES (10,12,NULL,I,NULL)
INSERT INTO T VALUES (10,13,NULL,D,NULL)
INSERT INTO T VALUES (10,14,NULL,A,NULL)
INSERT INTO T VALUES (11,11,51,H,76)
INSERT INTO T VALUES (11,12,65,I,98)
INSERT INTO T VALUES (11,13,76,D,76)
INSERT INTO T VALUES (11,14,56,A,45)




Tom Kyte

Followup  

December 15, 2005 - 5:16 pm UTC

(test inserts to discover they don't work).



A solution

December 16, 2005 - 1:22 am UTC

Reviewer: Michel Cadot from France

Hi,

I answer less questions than Tom, so i have more time to correct the test case. ;)

SQL> select player_id, match_id, score, place, minutes
  2  from t
  3  order by match_id, player_id
  4  /
 PLAYER_ID   MATCH_ID      SCORE PLACE         MINUTES
---------- ---------- ---------- ---------- ----------
        11          1         19 A                  12
        12          2         34 B                  24
        11          3        101 C                 112
        11          4        201 D                 121
        12          5        211 E                 222
        13          6        181 F                 322
        11          7         34 A                  45
        12          8         12 G                  10
        13          9         45 C                  65
        11         10            H
        12         10            I
        13         10            D
        14         10            A
        11         11         51 H                  76
        12         11         65 I                  98
        13         11         76 D                  76
        14         11         56 A                  45

17 rows selected.

SQL> select player_id, ge100, sum_score, sum_min, nb_match-1 nb_match,
  2         place, match_id
  3  from ( select player_id, match_id, score, place, 
  4                count(case when score>=100 then 1 end) 
  5                  over (partition by player_id order by match_id) ge100,
  6                sum(score)
  7                  over (partition by player_id order by match_id
  8                        rows between unbounded preceding and 1 preceding)
  9                  sum_score,
 10                sum(minutes)
 11                  over (partition by player_id order by match_id
 12                        rows between unbounded preceding and 1 preceding)
 13                  sum_min,
 14                row_number () 
 15                  over (partition by player_id order by match_id) nb_match,
 16                count(case when score between 50 and 99 then 1 end) 
 17                 over (partition by player_id order by match_id) ok
 18         from t )
 19  where score between 50 and 99
 20    and ok = 1
 21  --  and ge100 > 0 -- to exclude those who never score >= 100
 22  order by player_id
 23  /
 PLAYER_ID      GE100  SUM_SCORE    SUM_MIN   NB_MATCH PLACE        MATCH_ID
---------- ---------- ---------- ---------- ---------- ---------- ----------
        11          2        355        290          5 H                  11
        12          1        257        256          4 I                  11
        13          1        226        387          3 D                  11
        14          0                                1 A                  11

4 rows selected.

Regards
Michel 

Tom Kyte

Followup  

December 16, 2005 - 8:25 am UTC

just a pet peeve of mine. If I get about 1,300 - 1,500 of these every 4 weeks and half of them include a question and I take 1 minute to generate a test case.... it adds up.

all I ask is that the "askee" take the minute to actually run the test case and have it set up. I don't mind removing sqlplus prompts and such (that I can do in milliseconds by now :) so a cut and paste from sqlplus is fine - but scripts that could never have run... or don't create the data the example shows....

another problem

December 16, 2005 - 3:56 am UTC

Reviewer: Ramis from pak

thanks Michel for ur code above

I have encountered another problem, and that is, if some player has never made a score between 50 and 99 then it is not shown in the output of your query..I have also tired with one of other queries..but the problme still remains..

here is the changed data points..notice player_id = 12, he never had a score of 50 to 99 but had two scores of over 100 but it is not shoing up with mine and urs code..

INSERT INTO T VALUES (1,11,19,12);
INSERT INTO T VALUES (2,12,34,24);
INSERT INTO T VALUES (3,11,101,112);
INSERT INTO T VALUES (4,11,201,121);
INSERT INTO T VALUES (5,12,211,222);
INSERT INTO T VALUES (6,13,181,322);
INSERT INTO T VALUES (7,11,34,45);
INSERT INTO T VALUES (8,12,12,10);
INSERT INTO T VALUES (9,13,45,65);
INSERT INTO T VALUES (10,11,NULL,NULL);
INSERT INTO T VALUES (10,12,NULL,NULL);
INSERT INTO T VALUES (10,13,NULL,NULL);
INSERT INTO T VALUES (10,14,NULL,NULL);
INSERT INTO T VALUES (11,11,51,76);
INSERT INTO T VALUES (11,12,165,98);
INSERT INTO T VALUES (11,13,76,76);
INSERT INTO T VALUES (11,14,56,45);



MATCH_ID PLAYER_ID SCORE MINUTES
--------- ---------- ---------- ----------
2 12 34 24
3 11 101 112
4 11 201 121
5 12 211 222
6 13 181 322
7 11 34 45
8 12 12 10
9 13 45 65
10 11
10 12
10 13
10 14
11 11 51 76
11 12 165 98
11 13 76 76
11 14 56 45
1 11 19 12



SELECT
T.PLAYER_ID PLAYER_ID,
COUNT(T.PLAYER_ID) MT,
SUM(T.SCORE) SCORE,
SUM(CASE WHEN SCORE >= 100 THEN 1 ELSE 0 END) HUNDREDS
FROM
T,
(SELECT MIN(MATCH_ID) MATCH_ID,
PLAYER_ID
FROM T
WHERE SCORE BETWEEN 50 AND 99
GROUP BY PLAYER_ID) T2
WHERE
T.PLAYER_ID = T2.PLAYER_ID
AND
T.MATCH_ID < T2.MATCH_ID
GROUP BY T.PLAYER_ID
ORDER BY 4 DESC NULLS LAST
/

PLAYER_ID MT SCORE HUNDREDS
---------- ---------- ---------- ---------- ----------
11 5 355 2
13 3 226 1
14 1 0


as u can see the player_id = 12 is not showing up beacuse he has never made any score between 50 and 99..

so my desired output is


PLAYER_ID MT SCORE HUNDREDS
---------- ---------- ---------- ---------- ----------
11 5 355 2
12 5 422 2
13 3 226 1
14 1 0


I want you to please make the necessary changes in mine and your code oode...
regards,



Another solution

December 16, 2005 - 11:44 am UTC

Reviewer: Michel Cadot from France

Tom,

I agree and understand. I also storm when there is no test case and even more when there is an incorrect one. 
But... i can't resist to a SQL challenge and had nothing to do waiting my bus this morning (it was 6h30AM in France). So...

Ramis,

It is actually not the same question (and not the same table, where is the ddl?). 
Here's a query, you just have to check if you are at the last row of the player without encountered a 50-99 score:

SQL> select player_id, nb_match-ok nb_match,
  2         sum_score+decode(ok,0,score,0) sum_score,
  3         ge100
  4  from ( select player_id, match_id, score, 
  5                count(case when score>=100 then 1 end) 
  6                  over (partition by player_id order by match_id) ge100,
  7                sum(score)
  8                  over (partition by player_id order by match_id
  9                        rows between unbounded preceding and 1 preceding)
 10                  sum_score,
 11                row_number () 
 12                  over (partition by player_id order by match_id) nb_match,
 13                count(case when score between 50 and 99 then 1 end) 
 14                 over (partition by player_id order by match_id) ok,
 15                lead (player_id) 
 16                 over (partition by player_id order by match_id) next_player
 17         from t )
 18  where ( score between 50 and 99 and ok = 1 )
 19     or ( ok = 0 and next_player is null )
 20  order by player_id
 21  /
 PLAYER_ID   NB_MATCH  SUM_SCORE      GE100
---------- ---------- ---------- ----------
        11          5        355          2
        12          5        422          2
        13          3        226          1
        14          1                     0

4 rows selected.

Regards
Michel
 

Question about scalar query in ORACLE 10G

December 17, 2005 - 3:26 pm UTC

Reviewer: Ana

Hello,Tom,
Can i do in

Select x1,x2,x3,(select y from t1 where z=x1),
(select y1 from t1 where z=x1)
from t

instead of 2 selects one select: select y,y1 from t1 where z=x1
but without to define objects,
Show please,
Thank you,
Ana

Tom Kyte

Followup  

December 17, 2005 - 4:32 pm UTC

select x1, x2, x3,
f'( substr( data, 1, n ) ) y,
f''(substr( data, n+1 ) ) y1
from (
select x1, x2, x3,
(select f(y) || y1 from t1 where z = x1) data
from t
)

where f(y) is something to make Y "fixed length" (eg: say Y was a DATE NOT NULL, then f(y) could be to_char(y,'yyyymmddhh24miss')

f'(x) converts the string back into what it was (eg: perhaps to_date(..,'yyyymmddhh24miss' ))

f''(x) converts the other part of the string back into whatever y1 was.

EXTRACT STRING

December 20, 2005 - 11:46 am UTC

Reviewer: A reader

Hi Tom

I want to extract a string ( number ) from a table column which starts fron abcd: and then has number.
I want to insert it into another table.
how can i extract it.



Tom Kyte

Followup  

December 20, 2005 - 12:59 pm UTC

substr() ?

not substr

December 20, 2005 - 1:01 pm UTC

Reviewer: A reader

I have tried but substr, bUT GOT SOLUTION WITH INSTR().

Thanks


reader

December 29, 2005 - 3:17 pm UTC

Reviewer: A reader

HI Tom

i could not understand the answer to these queries....is there an better way to solve these or any other easy way


1)
List the name of cities whose population decreased by more than
10% from the year 1975 to the year 2000.

select city
from CITY
where p2000 < 0.9 * p1975;


2)

List the id of all countries in which the median age of women is
at least 25% below the median age of men.

select p_id
from PEOPLE
where med_age_f <= 0.75 * med_age_m;


Tom Kyte

Followup  

December 29, 2005 - 4:26 pm UTC

I really hope this is not coming from a "relational database class" because to have a table with columns named "p2000" and "p1975" - meaning "population in 2000". That would be "bad"

where p2000 < 0.9 * p1975

assuming p2000 is the population in 2000, this just sort of says "give me the rows where the 2000 population is less than 90% of the 1975 population - pretty straight forward....


same with the second one.

Default value insertion into a column from other Columns - How to achive at DDL level?

December 30, 2005 - 5:43 am UTC

Reviewer: VIKAS SANGAR from INDIA

Dear Mr. Kyte,

Can you pls tell If / How this can be achieved in Sql at table creation level?

Suppose, I create a table as...

create table Names
(Fname varchar2(10)not null,
Mname varchar2(10),
Lname varchar2(10)not null,
Fullname varchar2(35));

Now, If I insert the values in the table Names

insert into Names (Fname, Mname, Lname)
values ('Leo', 'De', 'Nero');

1 row inserted

select * from Names;

FNAME MNAME LNAME FULLNAME
---------- ---------- ---------- -------------
Leo De Nero

Here, if I want that the default value should be automatically inserted into "Fullname" column which should be the result of concatenation of the values from the other three columns "Fname", "Mname", "Lname", i.e. Default value of "Fullname" should be...'LeoDeNero',

Fullname varchar2(35)default (Fname||Mname||Lname));

All I want to know is can this be achieved at Table creation level by providing the default value of Fullname as mentioned above? If yes how?

I tried giving the the default value for Fullname as -
Fullname varchar2(35)default (Fname||Mname||Lname));
at the time of Table creation, but it failed giving me, Error...
ORA-00984: column not allowed here

I even tried using "Concat" function, but my effort went pine. Pls Help.

Take care, regards.
Vikas.






Tom Kyte

Followup  

December 30, 2005 - 9:35 am UTC

No you don't, you want a view!!! Because you don't want to have to maintain that column during an update - update set mname = 'Del'; - now you have to reconstruct the full name.

You want:

create view my_view
as
select fname, mname, lname, fname || ' ' || mname || ' ' || lname fullname
from t;


And if searching on fullname is the goal - you can easily use Oracle text to index fname, mname, lname giving you case insensitive, fuzzy, stem, wildcard, etc searches OR create a function based nidex on fname || ' ' || mname || ' ' || lname.



To the reader above

December 30, 2005 - 7:29 am UTC

Reviewer: A reader

Not sure it can be done at the Table level.
Though you can try an After Insert Trigger.
Let's see what Tom has to say


New Year Greetings...

December 30, 2005 - 9:04 am UTC

Reviewer: Vikas from INDIA.

Dear Mr. Kyte,

I know this is not the right Platform for posting this, but I am ready to take up your scoldings for this... :-)

May I take this Opportunity to...

Wish You, Your Team and Entire Oracle Fraternity

A
VERY HAPPY, PROSPEROUS, PEACEFUL
&
SUCCESFILLED NEW YEAR - 2006.

On My behalf and entire Oracle Community.

Take Care, Regards.

January 05, 2006 - 8:39 am UTC

Reviewer: A reader

Hi tom
I have data like

WILLIAM H FLANAGAN Jr
LINDA R SCOTT ESQ
WILLIAM BELL MARQUIS II

No w i want to extract it into different columns of another table

like If jr or II or esq then suffix and
wiliam in first name h,r in middle name and rest in last name.

how will i do that.

Thanks in advance


Tom Kyte

Followup  

January 05, 2006 - 10:55 am UTC

you'll parse it, process it, insert it.




tried it

January 05, 2006 - 11:04 am UTC

Reviewer: A reader

i have tried it on the bases of "space" but prob is with if the middle name is more than one letter long I want it in last name not middle name.

Thanks

Tom Kyte

Followup  

January 05, 2006 - 11:48 am UTC

sounds like an "if statement" would be needed then.

(this is an algorithm, you need to sit down and specify it out...)

I did something like this for city/state/zip parsing

January 10, 2006 - 3:29 pm UTC

Reviewer: Mark from Boston, MA

You can start with this and modify it:


CREATE OR REPLACE FUNCTION split(
in_expression IN VARCHAR2
,in_delimiter IN VARCHAR2
)
RETURN typ_array
IS
-- TYPE typ_array IS TABLE OF VARCHAR2 (4000);

v_array typ_array := typ_array(NULL);
i_delim_pos PLS_INTEGER;
i_next_delim_pos PLS_INTEGER;
i_start_pos PLS_INTEGER;
i_length PLS_INTEGER;
i_occurence PLS_INTEGER;
bln_done BOOLEAN := FALSE;
s_extract VARCHAR2(4000);
s_expression VARCHAR2(4000) := in_delimiter || in_expression;
BEGIN
i_length := v_array.COUNT;

-- check for nulls...
IF LENGTH(s_expression) IS NULL
OR LENGTH(in_delimiter) IS NULL
THEN
RETURN v_array;
END IF;

IF INSTR(in_expression, in_delimiter) = 0
THEN
-- just return the expression
v_array(1) := in_expression;
RETURN v_array;
END IF;

-- get length of expression to split
i_length := LENGTH(s_expression);
-- initialize
i_occurence := 1;
i_start_pos := 1;

WHILE bln_done = FALSE
LOOP
-- get position of occurence of delimiter
i_delim_pos := INSTR(s_expression, in_delimiter, 1, i_occurence);
-- get position of next occurence of delimiter
i_next_delim_pos :=
INSTR(s_expression, in_delimiter, 1, i_occurence + 1);

-- if next delimiter position > 0 then extract substring between delimiters.
-- if next delimiter position = 0, then extract until end of expression.
IF i_next_delim_pos > 0
THEN
-- string to extract is from i_start_pos to i_delim_pos
s_extract :=
SUBSTR(
s_expression, i_delim_pos + 1, i_next_delim_pos - i_delim_pos -
1
);
i_length := v_array.COUNT;
v_array(i_occurence) := s_extract;
v_array.EXTEND;
i_length := v_array.COUNT;
-- read it back into a var for debug
s_extract := v_array(i_occurence);
-- increment occurence value
i_occurence := i_occurence + 1;
ELSE
IF i_delim_pos > 0
THEN
-- you have not found the second delimiter. Grab the remaining string
s_extract := SUBSTR(s_expression, i_delim_pos + 1);
i_length := v_array.COUNT;
v_array(i_occurence) := s_extract;
v_array.EXTEND;
i_length := v_array.COUNT;
-- set exit flag
END IF;

-- you're done either way
bln_done := TRUE;
END IF;
END LOOP;

-- chop off last added NULL array element.
v_array.TRIM;
-- debug. iterate through collection and check values
/* i_length := v_array.COUNT;

FOR i_count IN 1 .. v_array.COUNT
LOOP
s_extract := v_array (i_count);
END LOOP;
*/
RETURN v_array;
EXCEPTION
WHEN OTHERS
THEN
raise_application_error(-20001, SQLERRM);
END;
/
CREATE OR REPLACE PROCEDURE parse_name(
in_name IN VARCHAR2
)
IS
v_loc_csz typ_array;
v_city VARCHAR2(100);
v_st VARCHAR2(6);
v_zip VARCHAR2(20);
v_count PLS_INTEGER;
v_temp VARCHAR2(100);
v_end PLS_INTEGER;
v_space VARCHAR2(1) := '';
BEGIN
-- parse in_name into components
v_temp := TRIM(in_name);
v_temp := REPLACE(v_temp, ' ', ' ');
SELECT split(v_temp, ' ')
INTO v_loc_csz
FROM dual;
v_count := v_loc_csz.COUNT;

IF v_count >= 4
THEN
/* sigh - happens when the city is TWO part name like 'CHESTNUT HILL'*/
v_zip := SUBSTR(TRIM(v_loc_csz(v_count)), 1, 5);
-- trim it, first 5
v_st := SUBSTR(TRIM(v_loc_csz(v_count - 1)), 1, 2);
v_end := v_count - 2;

FOR v_loop IN 1 .. v_end
LOOP
v_city := v_space || v_city || TRIM(v_loc_csz(v_loop));
v_space := ' ';
END LOOP;

v_city := TRIM(SUBSTR(v_city, 1, 30));
ELSIF v_count = 3
THEN
v_zip := SUBSTR(TRIM(v_loc_csz(v_count)), 1, 5);
-- trim it, first 5
v_st := SUBSTR(TRIM(v_loc_csz(v_count - 1)), 1, 2);
v_city := SUBSTR(TRIM(v_loc_csz(v_count - 2)), 1, 30);
ELSIF v_count = 2
THEN
v_st := SUBSTR(TRIM(v_loc_csz(v_count)), 1, 2);
v_city := SUBSTR(TRIM(v_loc_csz(v_count - 1)), 1, 30);
ELSIF v_count = 1
THEN
v_city := SUBSTR(TRIM(v_loc_csz(v_count)), 1, 30);
END IF;
/* And do Update/insert here
UPDATE ...
INSERT ...
*/



EXCEPTION
WHEN OTHERS
THEN
raise_application_error(-20001, SQLERRM);
END;


The Split() function acts like a simplified Split() VB function.


With a little work, this should do it.


oops...forgot something

January 11, 2006 - 9:08 am UTC

Reviewer: Mark from Boston, MA

typ_array def:

typ_array TABLE OF VARCHAR2(4000)


Question about trim

February 17, 2006 - 9:17 am UTC

Reviewer: A reader

Hi Tom,

For a column in my table a simple query
"select * from users where name='testuser'" is not working but "select * from users where trim(name)='testuser'" is working.
But when I inserted the "testuser" value did not contain any spaces.Can you let me know as to why the above is happening

Thanks for the same.


Tom Kyte

Followup  

February 17, 2006 - 2:51 pm UTC

yes it did.

do this

select '"' || name || '"', dump(name) from users where trim(name) = 'testuser';


you'll see it then.


February 18, 2006 - 12:51 pm UTC

Reviewer: Pat from TX, USA

Excellent.

I have a data which is to be exploded daily, problem i am facing is when there is a tier row. like in table q1 2/18/2006 to 2/20/2006, vol from q2 table should break as show in the output.

Table q1
DSTART DEND VFROM VTO AMT
2/16/2006 2/17/2006 0 0 9
2/18/2006 2/20/2006 0 5000 5
2/18/2006 2/20/2006 5001 10000 2

Table q2
X1 X2 DSTART DEND VOL
k1 111 2/16/2006 2/20/2006 3000
k1 222 2/16/2006 2/20/2006 4000
w1 333 2/16/2006 2/20/2006 5000

I am wondering is it possible to write in a single sql. I coded in pl/sql which is not that efficient.

i want the output like.

X1 X2 DSTART DEND VOL AMT
K1 111 2/16/2006 2/16/2006 3000 9
K1 222 2/16/2006 2/16/2006 4000 9
W1 333 2/16/2006 2/16/2006 5000 9
K1 111 2/17/2006 2/17/2006 3000 9
K1 222 2/17/2006 2/17/2006 4000 9
W1 333 2/17/2006 2/17/2006 5000 9

K1 111 2/18/2006 2/18/2006 3000 5
K1 222 2/18/2006 2/18/2006 2000 5
k1 222 2/18/2006 2/18/2006 2000 2
w1 333 2/18/2006 2/18/2006 5000 2
K1 111 2/19/2006 2/19/2006 3000 5
K1 222 2/19/2006 2/19/2006 2000 5
k1 222 2/19/2006 2/19/2006 2000 2
w1 333 2/19/2006 2/19/2006 5000 2
K1 111 2/20/2006 2/20/2006 3000 5
K1 222 2/20/2006 2/20/2006 2000 5
k1 222 2/20/2006 2/20/2006 2000 2
w1 333 2/20/2006 2/20/2006 5000 2

Tom Kyte

Followup  

February 18, 2006 - 4:48 pm UTC

cool?

terminology is not one I understand (a tier row?)


I mean, you have some interesting looking data there, at a glance - don't see anyway to "put it together and get your output (procedurally or otherwise - the LOGIC appears to be *missing*)


and you missed the bit that says, "if you want anyone to even try to give you a query that might require a bit of testing, you best supply table creates and inserts"

sorry - but missing the algorithm, the logic, the create, the inserts....

(and that is not a promise that should they be supplied I'll have an answer..)

February 18, 2006 - 12:58 pm UTC

Reviewer: pat from TX, USA

sorry i forgot to type the sql,

create table q1
(dstart date,dend date,vfrom number,vto number,amt number);

create table q2
(x1 char(5),x2 number, dstart date,dend date,vol number);

insert into q1 ( dstart, dend, vfrom, vto, amt ) values (
to_date( '02/16/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/17/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 0, 0, 9);
insert into q1 ( dstart, dend, vfrom, vto, amt ) values (
to_date( '02/18/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/20/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 0, 5000, 5);
insert into q1 ( dstart, dend, vfrom, vto, amt ) values (
to_date( '02/18/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/20/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 5001, 10000, 2);
commit;

insert into q2 ( x1, x2, dstart, dend, vol ) values (
'k1 ', 111, to_date( '02/16/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/20/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 3000);
insert into q2 ( x1, x2, dstart, dend, vol ) values (
'k1 ', 222, to_date( '02/16/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/20/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 4000);
insert into q2 ( x1, x2, dstart, dend, vol ) values (
'w1 ', 333, to_date( '02/16/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am'), to_date( '02/20/2006 12:00:00 am', 'mm/dd/yyyy hh:mi:ss am')
, 5000);
commit;

Tom Kyte

Followup  

February 18, 2006 - 4:48 pm UTC

and still don't know what it all "means"

February 19, 2006 - 12:23 am UTC

Reviewer: pat from TX, USA

oops sorry and thanks for quick response.

data is to be exploded daily between min(q1.dstart) and max(q1.dend)

when q1.vfrom = q1.vto then out put gets q2.vol
for 2/16 data looks like
X1 X2 DSTART DEND VOL AMT
K1 111 2/16/2006 2/16/2006 3000 9
K1 222 2/16/2006 2/16/2006 4000 9
W1 333 2/16/2006 2/16/2006 5000 9

there is no problem getting above output, the problem i am facing is
when q1.dstart = q1.dstart(+1) and q1.dend = q1.dend(+1) then
q2.vol should split according q1.vfrom and q1.vto.

for 2/18 - total q1.vfrom/vto has 10000 with different amt.
and total q2.vol has 12000.

first q2.vol 3000 falls between 0 to 5000 with amt 5.
now q1.vfrom/vto 0 - 5000 left with 2000.

second q2.vol 4000 should split from the remaining q1.vfrom/vto 0 to 5000 which is 2000(as 3000 is used by the q2.vol 3000 first row) with amt 5,
and then q2.vol remaining 2000 out of 4000 falls into q1.vfrom/vto 5001 to 10000 with amt 2.

third q2.vol 5000 falls and exceeds q1.vfrom/vto 5001 to 10000 with amt 2.
like this.
X1 X2 DSTART DEND VOL AMT
K1 111 2/18/2006 2/18/2006 3000 5
K1 222 2/18/2006 2/18/2006 2000 5
k1 222 2/18/2006 2/18/2006 2000 2
w1 333 2/18/2006 2/18/2006 5000 2



Response for the space in a column in the Table

February 19, 2006 - 10:34 pm UTC

Reviewer: A reader

Hi Tom,

I did find the spaces in the data for the "name" column in the "testuser" table. Thanks a lot for the responce


February 20, 2006 - 3:22 pm UTC

Reviewer: Pati from tx, usa

Hello Tom,
can you please help me in solving this query.

I have a contract with client that
first 0 - 5000 qty sell at $8
and next 5001 - 10000 qty sell at $7

I got orders for 3000, 4000, and 6000

as per the contract
first order for 3000 is priced at $8
second order 4000 should split into two
2000 is priced at $8
and 2000 is priced $7
and last order for 6000 is priced $7

create table x1
(qfrom number,qto number,amt number);

create table x2
(vol number);

insert into x1 ( qfrom, qto, amt ) values (
0, 5000, 8);
insert into x1 ( qfrom, qto, amt ) values (
5001, 10000, 7);
insert into x2 ( vol ) values ( 3000);
insert into x2 ( vol ) values ( 4000);
insert into x2 ( vol ) values (5000);

select * from x1;
qfrom qto amt
0 5000 8
5001 10000 7

select * from x2;
3000
4000
6000

output i want looks like
vol amt
3000 8
2000 8
2000 7
6000 7

is it possible to write a sql or do i have to code in pl/sql.

Thanks

Tom Kyte

Followup  

February 21, 2006 - 7:22 am UTC

couple of problems - don't know how you got a vol of 6000 on the last line.  You switched from 5000 being inserted to 6000 being selected.  I choose 5000 as the right answer.

second, rows have no "order" in tables - so, to say you have orders 3000, 4000, 5000 - without anything to "order them by" makes this ambigous. Hopefully you have a column to really order by (I used rowid - meaning different people could get different answers from my query as the data is sorted randomly)

ops$tkyte@ORA9IR2> with data1
  2  as
  3  (
  4  select qfrom, case when next_qto is null then 99999 else qto end qto, amt
  5    from (
  6  select qfrom, qto, lead(qto) over (order by qfrom) next_qto, amt
  7    from x1
  8         )
  9  ),
 10  data2
 11  as
 12  (
 13  select vol,
 14             nvl(lag(sum_vol) over (order by rowid)+1,1) lo_vol,
 15         sum_vol hi_vol
 16    from (
 17  select vol, sum(vol) over (order by rowid) sum_vol
 18    from x2
 19         )
 20  )
 21  select qfrom, qto, amt,
 22         least( hi_vol, qto )-greatest( lo_vol, qfrom ) +1 vol
 23    from data1, data2
 24   where lo_vol between qfrom and qto
 25      or hi_vol between qfrom and qto
 26   order by lo_vol
 27  /

     QFROM        QTO        AMT        VOL
---------- ---------- ---------- ----------
         0       5000          8       3000
         0       5000          8       2000
      5001      99999          7       2000
      5001      99999          7       5000

 

Execution Order of Where Clause

February 21, 2006 - 12:44 am UTC

Reviewer: Nikhilesh from India

Dear Tom,
Could you please have a look..........
*********************************************************
SQL*Plus: Release 9.2.0.1.0 - Production on Tue Feb 21 10:48:07 2006

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.


Connected to:
Oracle9i Enterprise Edition Release 9.2.0.6.0 - Production
With the Partitioning, OLAP and Oracle Data Mining options
JServer Release 9.2.0.6.0 - Production

10:48:15 vod@VODP> select * from test;

NAME JOIN_DETAIL
------------------------------ -----------------------------
Ravindra TEMP12-JAN-2005
Rajendra A16-FEB-2005
VILAS A6-FEB-2004
RAMESH COST6-JUN-2004

Elapsed: 00:00:00.03
10:48:26 vod@VODP> select name,substr(join_detail,2)
from test
WHERE
substr(join_detail,1,1)='A'
AND to_date(substr(join_detail,2),'DD-MON-RRRR')=to_date('06-FEB-2004','DD-MON-RRRR');

AND to_date(substr(join_detail,2),'DD-MON-RRRR')=to_date('06-FEB-2004','DD-MON-RRRR')
*
ERROR at line 5:
ORA-01858: a non-numeric character was found where a numeric was expected


Elapsed: 00:00:00.03
10:48:45 vod@VODP> select name,substr(join_detail,2)
from (select * from test where substr(join_detail,1,1)='A')
WHERE
to_date(substr(join_detail,2),'DD-MON-RRRR')=to_date('06-FEB-2004','DD-MON-RRRR');


NAME SUBSTR(JOIN_DETAIL,2)
------------------------------ -----------------------------
VILAS 6-FEB-2004

**********************************************************

Why don't optimizer executes the where clause so that the query won't fail.......

Tom Kyte

Followup  

February 21, 2006 - 7:45 am UTC

you are assuming some order of predicate evaluation.

But there isn't one. SQL is non-procedural. It is free to evaluate that predicate in any order it chooses.


This stuff happens each and every time someone uses a string to store a date or a number. Ugh. You do it to yourself.

In this case, this is "easy",


where decode( substr( join_detail,1,1),
'A', to_date(substr(join_detail,2)),
NULL ) = to_date( ..... );


use DECODE or CASE when you do these conversions.


Actually, STOP PUTTING DATES and NUMBERS IN STRINGS.


Can this query be refined

February 22, 2006 - 10:00 am UTC

Reviewer: Anne from MN

Hi Tom,

I would appreciate your advise on whether my query can be further refined/optimized.

create table run_history
(
run_id number(15) not null,
run_date date not null,
end_control_id number(15) not null,
start_control_id number (15)
)

--Master tables for controls
create table control_history
(
control_id number(15) not null,
create_date date not null,
comments varchar2(50)
)

I have a proc that runs for a set of control_ids and when done, inserts the last processed control_id into the run_history table. When it runs next it takes the
max(end_control_id) from run_history table and starts processing from the "next"
control_id in the control_history table
Objective :
Query to select the max(end_control_id) from run_history table and the "next"
control_id from the control_history table as one record.

select *
from
(
select
prev_control.*
, ch.*
from control_history ch
, ( select
*
from (
select rh.*
from run_history rh
order by run_id desc
)
where rownum = 1
) prev_control
where ch.control_id > prev_control.end_control_id
order by ch.control_id asc
)
where rownum = 1
;

Appreciate your help. Thanks!



Tom Kyte

Followup  

February 22, 2006 - 10:29 am UTC

why not


select *
from (select *
from ch
where control_id > (select max(run_id) from run_history)
order by control_id )
where rownum = 1;


the max subquery should do a min/max scan on an index on run_id in run_history.
then the inline view should index range scan an index on ch.control_id
and rownum will return just the first record.

February 22, 2006 - 12:54 pm UTC

Reviewer: A reader


Can this query be refined

February 23, 2006 - 3:55 pm UTC

Reviewer: Anne

Tom, thanks for your follow up.

select *
from (select *
from ch
where control_id > (select max(run_id) from run_history)
order by control_id )
where rownum = 1;

Your query is great, however it only returns the record for the "next" control_id in the control_history. Maybe I did not explain better : I need to select the latest control_id from the run_history along with the "next"control id record - basically in the same row. I hope this helps... Appreciate your input.
Thanks!

Tom Kyte

Followup  

February 23, 2006 - 7:52 pm UTC

thats what happens when someone doesn't indent like you do and you have no example (table creates, inserts to play with) ;)

(I must say - nothing personal - but your indenting and line breaks are "unique")




since you need them both (from both tables), then your join looks pretty good.

get first row from rh. use that to find first row in other table.

Might use first rows 1 optimization but other than that - it does what it says.


My indentation would look like this:

select *
from ( select prev_control.*, ch.*
from control_history ch,
( select *
from ( select rh.*
from run_history rh
order by run_id desc
)
where rownum = 1
) prev_control
where ch.control_id > prev_control.end_control_id
order by ch.control_id asc
)
where rownum = 1
;



You'll want to comment that query nicely :)

Can this query be refined

February 24, 2006 - 11:49 am UTC

Reviewer: Anne from MN

Hi Tom, thanks for your feeback. I know, don't know how I got into this "unique" indentation! I certainly like yours too and maybe I should change mine. Appreciate your comments. Thanks!

Tom Kyte

Followup  

February 24, 2006 - 11:57 am UTC

this is all opinion remember - pretty printers can always fix this stuff for anyone that needs to see it "their way"...


I've seen the leading comma approach lots - I understand why (you can comment out a column easily that way) but I've never liked it myself.

for some reason, this chunk:

select
prev_control.*
, ch.*
from control_history ch
, ( select
*
from (
select rh.*
from run_history rh
order by run_id desc
)
where rownum = 1
) prev_control


just doesn't read right to me - there is something about it that I just cannot "see it" for some reason.

I literally had to reformat that specific bit to understand it. Strange.

Query format

February 24, 2006 - 4:48 pm UTC

Reviewer: Michel Cadot from France

Not so strange, I often do the same when I receive a query to optimize. I have to reformat it to understand what it does and how it does it.

Regards
Michel


OK

March 03, 2006 - 2:54 am UTC

Reviewer: A reader

Hi Tom,
I would like to get the row having the minimum
value of deptno after grouping them..

I don't want to use * WHERE CLAUSE OR HAVING CLAUSE *.. 
But this is not working...

Any other idea??


SQL> select min(deptno),sum(sal)
  2  from emp
  3  group by deptno
  4  /

MIN(DEPTNO)   SUM(SAL)
----------- ----------
         10      30000
         20      37000
         30      38000

3 rows selected. 

Tom Kyte

Followup  

March 03, 2006 - 8:15 am UTC

Well, we could do it, but it would be rather silly.

scott@ORA10GR2> select max(decode(deptno,min_deptno,deptno)) deptno,
2 max(decode(deptno,min_deptno,sal)) sal
3 from (
4 select deptno, sum(sal) sal ,
5 min(deptno) over () min_deptno
6 from emp
7 group by deptno
8 )
9 /

DEPTNO SAL
---------- ----------
10 8750


please don't do that however, use the tools properly.

SQL query using analytics (How to get rid of this problem..)

March 03, 2006 - 11:41 am UTC

Reviewer: Atavur from India

Tom, 

I believe you will help me out in getting the rid solved.

I have a serious problem..hope u understand better.

We have three different tables

Table #1. QI (Quote Items)
Table #2. QS (Quote Schedules)
Table #3. PRS (PR Schedule)

I am currently working on 10g database and here i am giving the description..

Connected to:
Oracle Database 10g Enterprise Edition Release 10.1.0.4.0 - 64bit Production With the Partitioning, OLAP and Data Mining options

SQL> desc QI
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 QI_SEQ                                    NOT NULL NUMBER(10)
 ITEM_NBR                                  NOT NULL VARCHAR2(4)
 QUOTE_NBR                                 NOT NULL VARCHAR2(10)
 DATE_EFFECTIVE                                     DATE
 VENDOR_LT                                          NUMBER(5)
 DATE_EXP                                           DATE
 AWARD_FLAG                                NOT NULL VARCHAR2(1)
 VERBAL_FLAG                               NOT NULL VARCHAR2(1)
 PART                                               VARCHAR2(32)
 ACCT                                               VARCHAR2(16)
 WO_NBR                                             VARCHAR2(10)
 DESCRIPTION                               NOT NULL VARCHAR2(50)
 PART_REV                                           VARCHAR2(2)
 MFR_PART                                           VARCHAR2(32)
 UM                                                 VARCHAR2(2)
 PURCH_UM                                           VARCHAR2(2)
 UM_CONV_TYPE                                       VARCHAR2(1)
 UM_PURCH_CONV                                      NUMBER(7,2)
 COMMOD_CODE                                        VARCHAR2(4)
 INSP_FLAG                                 NOT NULL VARCHAR2(1)
 INSP_CODE                                          VARCHAR2(1)
 CERT_FLAG                                 NOT NULL VARCHAR2(1)
 PROJECT                                            VARCHAR2(20)
 CONTRACT                                           VARCHAR2(26)
 PRIORITY_RATING                                    VARCHAR2(10)
 WO_OPN                                             VARCHAR2(4)
 SHIP_VIA                                           VARCHAR2(4)
 FOB                                                VARCHAR2(16)
 FREIGHT_CODE                                       VARCHAR2(1)
 PRI_SEQ                                            NUMBER(10)
 REQUESTOR                                          VARCHAR2(30)
 TOOL_CODE                                          VARCHAR2(1)
 SRC_INSP_CODE                                      VARCHAR2(1)
 MATL_CODE                                          VARCHAR2(1)
 COMMENTS                                           VARCHAR2(2000)
 CREATED_BY                                NOT NULL VARCHAR2(30)
 DATE_CREATED                              NOT NULL DATE
 MODIFIED_BY                                        VARCHAR2(30)
 DATE_MODIFIED                                      DATE
 VAT_CODE                                           NUMBER(2)
 USER_01                                            VARCHAR2(50)
 USER_02                                            VARCHAR2(50)
 USER_03                                            VARCHAR2(50)
 USER_04                                            VARCHAR2(50)
 USER_05                                            VARCHAR2(50)
 USER_06                                            VARCHAR2(50)
 USER_07                                            VARCHAR2(50)
 USER_08                                            VARCHAR2(50)
 USER_09                                            VARCHAR2(50)
 USER_10                                            VARCHAR2(50)
 USER_11                                            VARCHAR2(50)
 USER_12                                            VARCHAR2(50)
 USER_13                                            VARCHAR2(50)
 USER_14                                            VARCHAR2(50)
 USER_15                                            VARCHAR2(50)

SQL> desc QS
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 QS_SEQ                                    NOT NULL NUMBER(10)
 QI_SEQ                                    NOT NULL NUMBER(10)
 DATE_DELV                                 NOT NULL DATE
 DATE_PROMISED                                      DATE
 QTY_REQD                                  NOT NULL NUMBER(12,3)
 QTY_PROMISED                                       NUMBER(12,3)
 CREATED_BY                                NOT NULL VARCHAR2(30)
 DATE_CREATED                              NOT NULL DATE
 MODIFIED_BY                                        VARCHAR2(30)
 DATE_MODIFIED                                      DATE
 QUOTE_NBR                                 NOT NULL VARCHAR2(10)
 QUOTE_ITEM                                NOT NULL VARCHAR2(4)
 USER_01                                            VARCHAR2(50)
 USER_02                                            VARCHAR2(50)
 USER_03                                            VARCHAR2(50)
 USER_04                                            VARCHAR2(50)
 USER_05                                            VARCHAR2(50)
 USER_06                                            VARCHAR2(50)
 USER_07                                            VARCHAR2(50)
 USER_08                                            VARCHAR2(50)
 USER_09                                            VARCHAR2(50)
 USER_10                                            VARCHAR2(50)
 USER_11                                            VARCHAR2(50)
 USER_12                                            VARCHAR2(50)
 USER_13                                            VARCHAR2(50)
 USER_14                                            VARCHAR2(50)
 USER_15                                            VARCHAR2(50)

SQL> desc PRS
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 PRS_SEQ                                   NOT NULL NUMBER(10)
 PRI_SEQ                                   NOT NULL NUMBER(10)
 REQ_NBR                                            VARCHAR2(10)
 REQ_ITEM                                           VARCHAR2(4)
 DATE_REQD                                 NOT NULL DATE
 QTY                                       NOT NULL NUMBER(12,3)
 DATE_PLACE                                NOT NULL DATE
 HAS_PO                                             VARCHAR2(1)
 PO_NBR                                             VARCHAR2(10)
 PO_ITEM                                            VARCHAR2(4)
 COMMENTS                                           VARCHAR2(2000)
 CREATED_BY                                NOT NULL VARCHAR2(30)
 DATE_CREATED                              NOT NULL DATE
 MODIFIED_BY                                        VARCHAR2(30)
 DATE_MODIFIED                                      DATE
 USER_01                                            VARCHAR2(50)
 USER_02                                            VARCHAR2(50)
 USER_03                                            VARCHAR2(50)
 USER_04                                            VARCHAR2(50)
 USER_05                                            VARCHAR2(50)
 USER_06                                            VARCHAR2(50)
 USER_07                                            VARCHAR2(50)
 USER_08                                            VARCHAR2(50)
 USER_09                                            VARCHAR2(50)
 USER_10                                            VARCHAR2(50)
 USER_11                                            VARCHAR2(50)
 USER_12                                            VARCHAR2(50)
 USER_13                                            VARCHAR2(50)
 USER_14                                            VARCHAR2(50)
 USER_15                                            VARCHAR2(50)
 DATE_PLACE_ACT                                     DATE


SQL> SELECT qi_seq,item_nbr,quote_nbr,pri_seq FROM qi WHERE quote_nbr = '1108' AND item_nbr = '0001';

    QI_SEQ ITEM QUOTE_NBR     PRI_SEQ
---------- ---- ---------- ----------
      1203 0001 1108             1039

SQL> SELECT qs_seq,qi_seq,quote_nbr,quote_item,date_delv,date_promised FROM qs WHERE quote_nbr = '1108' AND quote_item = '0001';

    QS_SEQ     QI_SEQ QUOTE_NBR  QUOT DATE_DELV DATE_PROM
---------- ---------- ---------- ---- --------- ---------
      1732       1203 1108       0001 08-MAR-06 08-MAR-06
      1734       1203 1108       0001 18-APR-06 18-APR-06
      1733       1203 1108       0001 18-MAY-06 25-MAY-06
      1735       1203 1108       0001 16-JUN-06 20-JUN-06

SQL> SELECT prs_seq,pri_seq,req_nbr,qty FROM prs WHERE pri_seq = 1039( QI.pri_seq where the value is mentioned above);

   PRS_SEQ    PRI_SEQ REQ_NBR           QTY
---------- ---------- ---------- ----------
      1312       1039 995                50
      1313       1039 995                40
      1314       1039 995                60
      1315       1039 995                15

SQL> SELECT ps.prs_seq,qi.pri_seq,ps.req_nbr,
               qs.qs_seq,qs.qi_seq ,qs.date_delv,qs.date_promised,
            qs.qty_reqd,qs.qty_promised,qs.quote_nbr,qs.quote_item
       FROM QS qs, quote_items qi, pr_schedules ps
      WHERE qs.quote_nbr  = '1108'  -- Same quote number used above.
        AND qs.quote_item = '0001'  -- Same quote item used above.
        AND qs.quote_item=qi.item_nbr
        AND qs.quote_nbr=qi.quote_nbr
        AND qi.pri_seq=ps.pri_seq(+);


I am getting a peculiar result where it's multiplying the actual rows(four) into itself which comes to 16 rows. IF there are 3 rows then it's giving the result in 9 rows.

Result of the above query (Just taken few columns from the above query mentioned due to format issue)
----------------------------------------------------------------------------------------------------
PRS_SEQ    PRI_SEQ    REQ_NBR    QS_SEQ    QI_SEQ    QUOTE_NBR  QUOTE_ITEM
1312        1039         995        1732        1203        1108    0001
1312        1039         995        1734        1203    1108        0001
1312        1039         995        1733    1203    1108    0001
1312        1039         995        1735    1203    1108    0001

1313        1039         995        1732    1203    1108    0001
1313        1039         995        1734    1203    1108    0001
1313        1039         995        1733    1203    1108    0001
1313        1039         995        1735    1203    1108    0001

1314        1039         995        1732    1203    1108    0001
1314        1039         995        1734    1203    1108    0001
1314        1039         995        1733    1203    1108    0001
1314        1039         995        1735    1203    1108    0001

1315        1039         995        1732    1203    1108    0001
1315        1039         995        1734    1203    1108    0001
1315        1039         995        1733    1203    1108    0001
1315        1039         995        1735    1203    1108    0001

How to get the result which should give like the below ones?
------------------------------------------------------------
PRS_SEQ    PRI_SEQ    REQ_NBR    QS_SEQ    QI_SEQ    QUOTE_NBR    QUOTE_ITEM
1312        1039         995        1732    1203       1108        0001
1313        1039         995        1734    1203       1108        0001
1314        1039         995        1733    1203       1108        0001
1315        1039         995        1735    1203       1108        0001


Tom, Please help me out ...

 

Tom Kyte

Followup  

March 03, 2006 - 2:02 pm UTC

no. I won't even look at stuff with descs and selects from a table. It sort of says that on the page you used to put all of this stuff that I won't look at here.

I'm sure any example you will create will have far far fewer columns, just the ones you need.

and will include an actual text description of the problem you are trying to solve - not just show queries that do not actually retrieve what you want. That is, "the question", not the failed answer.

March 04, 2006 - 2:20 am UTC

Reviewer: A reader

Tom,


As per my above result, The query i m looking for is to filter only those rows which have a matching quote# and quote item from QI, QS tables

QI.QUOTE_NBR = QS.QUOTE_NBR AND
QI.ITEM_NBR = QS.QUOTE_ITEM

and also get the corresponding PRS_seq from PRS table if PRS table has matching rows( qi.pri_seq = prs.pri_seq(+)).

I tried using the below query but it gives a wrong result in case if QI has a single row and QS table has multiple rows and PRS also has multiple rows.

SELECT qs.*,prs.pri_seq,prs.req_nbr
FROM qs, qi, prs
WHERE qs.quote_nbr = qi.quote_nbr
and qs.quote_item = qs.item_nbr
and qi.pri_seq = prs.pri_seq(+);



Hope this might have given a clear picture..

Tom Kyte

Followup  

March 04, 2006 - 7:11 am UTC

I do not believe you actually read my response above.

ok

March 04, 2006 - 6:32 am UTC

Reviewer: Raj from Hyderabad,India

Hi Tom,

How to TRANSPOSE THE ROWS??

SQL> select deptno,max(sal)
  2  from emp
  3  group by deptno
  4  /

    DEPTNO   MAX(SAL)
---------- ----------
        10       5000
        20       3000
        30       2850

3 rows selected. 

Tom Kyte

Followup  

March 04, 2006 - 7:12 am UTC

search this site for PIVOT

many examples.

ok

March 05, 2006 - 10:06 am UTC

Reviewer: A reader

Hello,
Any other way to put this query??

This query gets the last row of the table EMP..


SQL> with a as (select rownum rn,e.* from emp e),
  2       b as (select max(rn) as rn from a)
  3  select * from a,b where a.rn = b.rn
  4  /

        RN      EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- ---------- --------- ---------- --------- ---------- ---------- ----------
        14       7934 MILLER     CLERK           7782 23-JAN-82       1300                    10

1 row selected. 

Tom Kyte

Followup  

March 05, 2006 - 1:50 pm UTC

there is no such thing as the last row of temp, you are getting a random row from emp.

period.

there is no first row, middle row, last row.

that gets a random row.


define to us what a "last row" is exactly.

OK

March 06, 2006 - 8:09 am UTC

Reviewer: A reader

Hi Tom,
Thanks for your reply.
You just assume that EMP table to be static(it never undergoes any inserts or deletes).

last row in the sense any row inserted lastly.

I want to pick that.

Do you have any timestamp related information for
any row inserts??
If so, we can use max(timestamp).

Please ro reply.
Bye




Tom Kyte

Followup  

March 08, 2006 - 3:52 pm UTC

last row inserted is not the last row.

There is no way to get the last inserted row.

read "the last row" in this really old article of mine:

</code> http://www.oracle.com/technology/oramag/oracle/01-nov/o61asktom.html <code>

multiple inserts

March 06, 2006 - 11:30 am UTC

Reviewer: Reader from NYC

Hello Tom,

I have a table holiday
desc
Name Null? Type
----------------------------------------- -------- ----------------------------
STD_DATE NOT NULL VARCHAR2(11)
HOLIDAY_NAME NOT NULL VARCHAR2(64)

I need to updated this table only once a year with a list holidays( about 15). I aslo have to do this inserts in some other database.

Would please provide a hit how to write these multiple insert statements inside a procedure? Thanks.

insert into holiday values('holiday_name_1','01-jan-2005');
insert into holiday values('holiday_name_2','02-feb-2006');
insert into holiday values('holiday_name_3','05-mar-2006');
insert into holiday values('holiday_name_4','05-apr-2006');
insert into holiday values('holiday_name_5','06-may-2006');

commit;



Tom Kyte

Followup  

March 08, 2006 - 4:06 pm UTC

begin
... code you have
end;

??

but you have a big big big big problem - you seem to be using a string for a date? that is about the wrongest thing you can do ever. don't do that.

Multiples Insert

March 07, 2006 - 10:22 am UTC

Reviewer: Alf from NYC

Hi Tom,

Probably you'd have answered this some where in this site, would you please point out the right keyword to search on wraping multiple inserts as in the above case? Thanks.



query result format

March 07, 2006 - 3:50 pm UTC

Reviewer: Lily from NY,USA

Tom, 
please help with changing query result format in oracle 9.2.0.4 as described below:


SQL> create table tt (txt varchar2(10));

Table created.

SQL> insert into tt values ('AA');

1 row created.

SQL> insert into tt values ('BB');

1 row created.

SQL> insert into tt values ('CC');

1 row created.

SQL> commit;

Commit complete.

SQL> desc tt
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 TXT                                                VARCHAR2(10)

SQL> select * from tt;

TXT
----------
AA
BB
CC

Now we want to get result as 3 returned rows as one line (no space between each row) as

AABBCC

Is there single SQL statement can handle it or Oracle has some build in function we may utilize?

Thanks.

 

Tom Kyte

Followup  

March 09, 2006 - 11:17 am UTC

search this site for pivot

from china!!!

March 08, 2006 - 12:34 am UTC

Reviewer: gaozhiwen

Tom have many many many method,below is among method!!!

select max(txt1) || max(txt2) || max(txt3)
from (select decode(rn, 1, txt, '') txt1,
decode(rn, 2, txt, '') txt2,
decode(rn, 3, txt, '') txt3
from (select row_number() over(order by txt) rn, txt from tt))

Great answer.

March 08, 2006 - 11:27 am UTC

Reviewer: A reader

Many thanks to gaozhiwen and Tom.

Lily

Multiple Inserts

March 09, 2006 - 11:24 am UTC

Reviewer: Alf from NYC

Thanks Tom,

In the above example the tables are already created. However, what would be the best method to correct this problem? 
I was thinking to add the to_date( '02-16-2006', 'mm-dd-yyyy') in the inserts but then the problem would still remain in the base table wouldn't it?

beging
 insert statements
 INSERT INTO hhc_custom.hhc_holiday_cfg VALUES(to_date('02-JAN-2006','dd-mon-yyyy'),'NEW YEAR''S DAY');
 ....
commit;
end;

SQL> desc hhc_custom.hhc_holiday_cfg
 Name                                      Null?    Type
 ----------------------------------------- -------- ----------------------------
 STD_DATE                                  NOT NULL VARCHAR2(11)
 HOLIDAY_NAME                              NOT NULL VARCHAR2(64)
 

Tom Kyte

Followup  

March 09, 2006 - 3:17 pm UTC

I don't know what the problem you are trying to solve or hitting is exactly?

of course the table must exist before the inserts are submitted.

Mulitple Insert

March 10, 2006 - 11:17 am UTC

Reviewer: Alf from NYC

Tom,

In your followup to the Initial how to wrap multiple inserts question, you mentioned there is a wrong thing "using a string" inserting dates.


insert into holiday values('01-jan-2005','holiday_name_1');
...

holiday
=======
Name Null? Type
----------------------------------------- -------- ----------------------------
STD_DATE NOT NULL VARCHAR2(11)
HOLIDAY_NAME NOT NULL VARCHAR2(64)

your initial followup:
Followup:

begin
... code you have
end;

??

but you have a big big big big problem - you seem to be using a string for a
date? that is about the wrongest thing you can do ever. don't do that.

Kindly advice how to correct this problem, thanks.

Tom Kyte

Followup  

March 10, 2006 - 8:22 pm UTC

explicitly convert said string into a date so that no problems could ever go wrong with it.


to_date( '01-jan-2005', 'dd-mon-yyyy' )

that is a date

'01-jan-2005' is a string just like 'aa-bbb-cccc' is

You want to control the format mask when you are supplying a string like that.

Multiple Inserts

March 13, 2006 - 11:32 am UTC

Reviewer: Alf from NYC

Thanks Tom, for your great help!



March 15, 2006 - 12:04 pm UTC

Reviewer: Rish Gupta from Madison, WI USA

Tom,
 Here is a table that I have 
create table rate_test(
ndc number,
eff_date date,
end_date date,
reabte number,
icn varchar2(5))

insert into rate_test
values(1, '01-DEC-05', '31-DEC-05', 5, '101');
insert into rate_test
values(1, '01-NOV-05', '30-NOV-05', 0, '102');
insert into rate_test
values(1, '01-OCT-05', '31-OCT-05', 5, '103');
insert into rate_test(
values(2, '01-OCT-05', '31-OCT-05', 5, '104');
insert into rate_test
values(3, '01-DEC-05', '31-DEC-05', 0, '106');
insert into rate_test
values(2, '01-DEC-05', '31-DEC-05', 0, '105');
insert into rate_test
values(3, '01-NOV-05', '30-NOV-05', 5, '107');
insert into rate_test
values(4, '01-OCT-05', '31-OCT-05', 5, '108');
insert into rate_test
values(5, '01-DEC-05', '31-DEC-05', 0, '109');

SQL> select * from rate_test
  2  /

       NDC EFF_DATE  END_DATE      REBATE ICN
---------- --------- --------- ---------- -----
         1 01-DEC-05 31-DEC-05          5 101
         1 01-NOV-05 30-NOV-05          0 102
         1 01-OCT-05 31-OCT-05          5 103
         2 01-OCT-05 31-OCT-05          5 104
         3 01-DEC-05 31-DEC-05          0 106
         2 01-DEC-05 31-DEC-05          0 105
         3 01-NOV-05 30-NOV-05          5 107
         4 01-OCT-05 31-OCT-05          5 108
         5 01-DEC-05 31-DEC-05          0 109

What I want to do is to select the rows with eff_date = 01-DEC-2005 AND END_DATE = 31-DEC-2005. Simple so far. However, if the rebate is a 0, then it should look at the previous month to determine if the rebate is 0. It is not a zero, that row should be retrieved, else it should look back another month. In cases where the rate is 0 for the preceding months, or the  ndc has no record for the previous months of November or October, then it should return the current month data, i.e. for the month of december.  
In short, i need to create a query that returns data from the latest non zero rebate for each ndc, only if that ndc is valid for the month 01-dec-2005 and 31-dec-2005. So my query should return

1 01-DEC-05 31-DEC-05          5 101
2 01-OCT-05 31-OCT-05          5 104
3 01-NOV-05 30-NOV-05          5 107
5 01-DEC-05 31-DEC-05          0 109 --since this ndc has no record for the months of november and oct

Also, NDC of 4 should not be retrieved because its from a past month of October.

I have this query 
SQL> SELECT x.ndc, NVL((case when (x.rebate = 0 or x.rebate is null) then
  2                (case when (y.rebate = 0 OR Y.REBATE IS NULL)  
  3          then z.eff_date
  4        else y.eff_date end)
  5       else x.eff_date
  6     end), '01-DEC-2005') as eff_date,
  7     NVL((case when (x.rebate = 0 or x.rebate is null)then
  8                (case when (y.rebate = 0 OR Y.REBATE IS NULL)
  9          then z.end_date
 10        else y.end_date end)
 11       else x.end_date 
 12     end), '31-DEC-2005') as end_date,
 13     NVL((case when (x.rebate = 0 or x.rebate is null) then
 14                (case when (y.rebate = 0 OR Y.REBATE IS NULL)
 15          then z.rebate
 16        else y.rebate end)
 17       else x.rebate 
 18     end), 0) as rebate
 19  from
 20   (SELECT NDC,EFF_DATE, END_DATE, rebate
 21   FROM rate_test
 22   where eff_date <= '01-DEC-05' AND END_DATE >= '31-DEC-05')x ,
 23   (SELECT NDC, EFF_DATE, END_DATE, rebate
 24   FROM rate_test
 25   where eff_date <= '01-NOV-05' AND END_DATE >= '30-NOV-05')y,
 26   (SELECT NDC, EFF_DATE, END_DATE, rebate
 27   FROM rate_test
 28   where eff_date <= '01-OCT-05' AND END_DATE >= '31-OCT-05')z
 29  where x.ndc = y.ndc(+) and
 30  X.NDC = Z.NDC(+) ;

       NDC EFF_DATE  END_DATE      REBATE
---------- --------- --------- ----------
         1 01-DEC-05 31-DEC-05          5
         3 01-NOV-05 30-NOV-05          5
         5 01-DEC-05 31-DEC-05          0
         2 01-OCT-05 31-OCT-05          5
There are 2 parts to my question :
1. I was wondering if there was a better way of writing a query to achieve the results I want. It seems too data specific. 
2. This query works because I know that I will not be looking back more than 2 months. What if I wanted to retrieve the latest non zero rebate row, even if it dates back 5-6 months ago? Is it possible to accomplish using SQL? 
Thanks in advance 

Tom Kyte

Followup  

March 15, 2006 - 5:36 pm UTC

ops$tkyte@ORA10GR2> select ndc,
  2         case when rebate = 0 and last_rebate is not null
  3                  then last_eff_date
  4                          else eff_date
  5                  end eff_date,
  6         case when rebate = 0 and last_rebate is not null
  7                  then last_end_date
  8                          else end_date
  9                  end end_date,
 10         case when rebate = 0 and last_rebate is not null
 11                  then last_rebate
 12                          else rebate
 13                  end rebate,
 14         case when rebate = 0 and last_rebate is not null
 15                  then last_icn
 16                          else icn
 17                  end icn
 18    from (
 19  select rate_test.*,
 20                  lag(eff_date) over (partition by ndc order by eff_date) last_eff_date,
 21                  lag(end_date) over (partition by ndc order by eff_date) last_end_date,
 22                  lag(rebate)   over (partition by ndc order by eff_date) last_rebate,
 23                  lag(icn)      over (partition by ndc order by eff_date) last_icn
 24    from rate_test
 25   where (eff_date = to_date( '01-dec-2005', 'dd-mon-yyyy' ) and end_date = to_date( '31-dec-2005', 'dd-mon-yyyy' ))
 26      or rebate > 0
 27         )
 28   where (eff_date = to_date( '01-dec-2005', 'dd-mon-yyyy' ) and end_date = to_date( '31-dec-2005', 'dd-mon-yyyy' ))
 29  /

       NDC EFF_DATE  END_DATE      REBATE ICN
---------- --------- --------- ---------- -----
         1 01-DEC-05 31-DEC-05          5 101
         2 01-OCT-05 31-OCT-05          5 104
         3 01-NOV-05 30-NOV-05          5 107
         5 01-DEC-05 31-DEC-05          0 109
 

March 16, 2006 - 11:45 am UTC

Reviewer: Rish G from Madison, WI USA

For lack of a good vocabulary, that was awesome!
Thanks a terabyte!

SQL

March 20, 2006 - 1:46 pm UTC

Reviewer: Michael from Germany

Tom,

Can you please guide me in creating aggicated table.

I have one table which containts 60 months of data , each month 135 mil of rows.

I have an report which is procesing last 13 months of data

Every month i have to refressh the report. where currently i am refreshing all 13 months data. wheere as i want to refress only current month data. remaning months will be as it is.

can you plz help me how we can do this???

Thanks


Tom Kyte

Followup  

March 22, 2006 - 1:23 pm UTC

sounds like a materialized view? are you aware of them and how they work?

SQL

March 23, 2006 - 3:04 am UTC

Reviewer: michael from Germany

Tom,

I know some thing about materialized view.

But not fully sure how that can be helpful in this case?.

Can you please explain..

Thanks

Tom Kyte

Followup  

March 23, 2006 - 10:45 am UTC

materialized views do this - they aggregate data, they pre-join data, they summarize data, they work with incremental updates (changes only).

You'll want to read:
</code> http://docs.oracle.com/docs/cd/B19306_01/server.102/b14223/basicmv.htm#g1028195 <code>

Update

March 23, 2006 - 11:45 am UTC

Reviewer: Tony from USA

Tom,

What will be the impact on the large table if the rows are regularly updating.

for Example:

I have a table which contains more then 1500 millions of rows and due to some changes in history data I am updating one column value.This is the forth time I am doing this activity for the same column. It is taking more than 10 hours to complete.
Is there any impact on table data fetch?

Thanks

Tom Kyte

Followup  

March 23, 2006 - 1:36 pm UTC

"depends" - as always.

if the data is being read as it is being modified - then the consistent read mechanism will have to rollback the updates for the reads, making the read take a little longer as it accesses the blocks.

Selective Group By

April 11, 2006 - 10:41 am UTC

Reviewer: TS from USA

Hi Tom,

I want to do a selective group by on a bunch of columns
in a table and at the same time display all the columns
eventually. Here's what I want:-

select col_a,col_b,sum(col_c),col_d,col_e
from table_a
group by col_a,col_b

Any help on this is greatly appreciated.



Tom Kyte

Followup  

April 11, 2006 - 4:13 pm UTC

"selective group by"??

I don't know what you mean.


What should the sum(col_c) be in the above - got an example?

re: Selective Group By

April 11, 2006 - 5:22 pm UTC

Reviewer: Oraboy from MI, USA

I think the prev poster (TS) is looking to have summary value along with scalar value in the SQL
(select c1,c2,c3,sum(c2) from table)

I think, Analytics would the way to go..

sQL>select * from test;

C1 C2 C3 C4
---------- ---------- ---------- ----------
1 11 101 499
2 12 102 498
3 13 103 497
4 14 104 496
5 15 105 495
6 16 106 494
7 17 107 493
8 18 108 492
9 19 109 491

9 rows selected.

sQL>select sum(c3) from test;

SUM(C3)
----------
945

sQL>select c1,c2,sum(c3) over () sum_of_c3,c4 from test;

C1 C2 SUM_OF_C3 C4
---------- ---------- ---------- ----------
1 11 945 499
2 12 945 498
3 13 945 497
4 14 945 496
5 15 945 495
6 16 945 494
7 17 945 493
8 18 945 492
9 19 945 491

9 rows selected.

--
option 2: use With clause to get all summaries

sQL>l
1 With sum_values as (select sum(c3) sum_of_c3, sum(c2) sum_of_c2 from test)
2 select c1,c2,sum_of_c2,c3,sum_of_c3,c4
3* from test,sum_values
sQL>/

C1 C2 SUM_OF_C2 C3 SUM_OF_C3 C4
----- ---- ---------- ---------- ---------- ----------
1 11 135 101 945 499
2 12 135 102 945 498
3 13 135 103 945 497
4 14 135 104 945 496
5 15 135 105 945 495
6 16 135 106 945 494
7 17 135 107 945 493
8 18 135 108 945 492
9 19 135 109 945 491

9 rows selected.

Tom Kyte

Followup  

April 11, 2006 - 7:26 pm UTC

I agree, that is what I thought.

But - I would really like to hear it from them. Maybe I'm getting picky - but the ability to state specific requirements - to tell someone "this is what I want......" and have it be meaningful seems to be a lost art :(

INSTR documentation ambiguity?

April 13, 2006 - 3:20 pm UTC

Reviewer: Duke Ganote from a building in western Clermont County, Ohio USA when I should be basking in the sunshine

The documentation for INSTR is pretty short
http://download-east.oracle.com/docs/cd/B19306_01/server.102/b14200/functions068.htm#sthref1467
but is it ambiguous?  Suppose the substring has a length greater than one.  I expected the search for, say, the 2nd occurrence to begin immediately after the <b>end</b> of the first occurrence.  However, it seems to begin after the <b>first character</b> of the first occurrence.

Here's an example.  I'm using CSV, and always enclosing the values in double-quotes.  But suppose the values are themselves commas?  Here I pass 3 values, each of which is a comma:

  1  with input_txt as (
  2     select '",",",",","' AS STRING
  3          , '","'         AS SUBSTRING
  4       from dual )
  5  select INSTR(string,substring,2,1) start_of_1st_occurs
  6       , INSTR(string,substring,2,2) start_of_2nd_occurs
  7       , INSTR(string,substring,2,3) start_of_3nd_occurs
  8* from input_txt
SQL> /

START_OF_1ST_OCCURS START_OF_2ND_OCCURS START_OF_3ND_OCCURS
------------------- ------------------- -------------------
                  3                   5                   7

However, I get a different answer if the payload values are, say, X

  1  with input_txt as (
  2     select '"x","x","x"' AS STRING
  3          , '","'         AS SUBSTRING
  4       from dual )
  5  select INSTR(string,substring,2,1) start_of_1st_occurs
  6       , INSTR(string,substring,2,2) start_of_2nd_occurs
  7       , INSTR(string,substring,2,3) start_of_3nd_occurs
  8* from input_txt
SQL> /

START_OF_1ST_OCCURS START_OF_2ND_OCCURS START_OF_3ND_OCCURS
------------------- ------------------- -------------------
                  3                   7                   0
I'd've expected the same results regardless of the values (well, unless we were passing "," as a value!).   

Tom Kyte

Followup  

April 14, 2006 - 12:07 pm UTC

I must be missing something here - looks right to me?

you have entirely different strings to search, with different numbers if ","'s in them even!

INSTR - looks fine to me

April 13, 2006 - 10:52 pm UTC

Reviewer: Oraboy

Lets see carefully..
<quote>
1 with input_txt as (
2 select '",",",",","' AS STRING
</quote>

",",",","," <-- string data enclosed within single quote
12345678901 <-- character positions for better readability

Now Lets manually search your substring (which is ",")

instr(string,'","',2,1) :
from 2nd position looking at first occurance of ","
you can find character position 345 matching ..

so instr(string,",",2,1) = 3

instr(string,'","',2,2):
from 2nd char position look for 2nd occurance of ","
we know 1st occurance starts at 3rd char..looking for 2nd
you find characters in position 567 matching..

so inst(string,",",2,2) = 5

which is exactly what you got.

Apply the same technique to your other string "x","x","x", you would see instr is working properly

Perhaps, your eyes are splitting and reading the strings in your original data as 123,567,901...

what you missed to read is the fact there are more within the data string..which are
,345,789

hope that helps

Another SQL Query...

April 24, 2006 - 3:58 am UTC

Reviewer: A reader

Hi Tom,
I have a query like this:

I want to select data from a table where the item exists for all the given months. As the in operator is like wrting an or clause it is useless in this scenario.

For e.g. using the Scott schema's emp table:

I wish to select all the employees of a particular dept. who have been hired in the month of say, Jan, Dec and March.

If the hiredate does not fall in any of these months they should not be displayed i.e. the hiredate is only in Jan and Dec then they should not be displayed.

I want to use a single select statement to acheive the same.
I tried using analytics and connect by clause w/o any success.

Kindly help
Thanks as always



Tom Kyte

Followup  

April 24, 2006 - 4:30 am UTC

select empno
from emp
where hiredate in ( to_date( :x ), to_date(:y), to_date(:z) )
group by empno
having count(distinct to_char(hiredate,'mm')) = 3;

find the records (where in)
aggregate the records
count to see that the distinct count of whatever is what you need.

You could use analytics as well if you didn't want to aggregate.

Word search

April 26, 2006 - 8:03 am UTC

Reviewer: tony from USA

Tom,

Can you please guide me how to search the exact word in the string? I am using Oracle ver 9.1

If i have two strings
1) The oracle is great
2) The oracledatabase is great

If i want to search the row where only oracle word exist. so that i can fetch only 1st row.

Many thanks in advance.





Tom Kyte

Followup  

April 26, 2006 - 8:32 am UTC

typically one would use a TEXT index for that.
</code> http://asktom.oracle.com/pls/ask/search?p_string=indextype+ctxsys.context <code>

Approximately 461 records found.

April 26, 2006 - 9:46 am UTC

Reviewer: A reader

I assume
</code> http://asktom.oracle.com/pls/ask/search?p_string=indextype+ctxsys.context <code>
uses a TEXT index, correct ?

However, it also shows
"Approximately 461 records found. "

what is the meaning of this ?
(I can click "Next" 5-times and last hit is
63 Context Index Score(7) 25 Oct 2000 7pm 25 Oct 2000 7pm 5.5 years old
)

however, 63 != 461 not even approximately

Tom Kyte

Followup  

April 27, 2006 - 4:07 am UTC

It is a guess.

Goto google, search for Oracle. Report back

a) how many pages it guessed
b) how many you could actually get to

April 26, 2006 - 9:52 am UTC

Reviewer: A reader

already found the answer on
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:3489618933902#5173364031614 <code>

"...
intermedia uses its index to get a guesstimate
..."

so why does intermedia guess so badly ?

Tom Kyte

Followup  

April 27, 2006 - 4:09 am UTC

because I modify documents constantly and the maintainence of the index is "deferred" - so if I update a document 100 times, it might overcount that document by that much.

but - goto google, search for oracle...

google

April 27, 2006 - 4:32 am UTC

Reviewer: A reader

ok, I went to google and searched for oracle.

to make things perform better, I searched
only for pages written in these language(s): Catalan

google resulted to me 47600 hits, and I managed to get 661.

so, what did we learnt from that ?

a. google estimates even worse than Oracle (at least sometimes, at least once)

b. Oracle doesn't seem to be very ambitious in improving (it seems you are content when you are better than Google)

c. because of that, I'd probably better sell my Oracle stocks and buy ... ?


Tom Kyte

Followup  

April 27, 2006 - 3:00 pm UTC

google is the gold standard for searching.

that is all I have to say. I'm not worried about it *at all*.

I'm not saying "better than google", I'm saying "we should aspire to be as fast as and as good as google when searching on the web"

and counting hits precisely is just "stupid", my humble opinion. To get it right you know what you have to do?

think about it *(you have to do the search, well, guess what - that would not be "fast")*

SQL join

April 27, 2006 - 8:25 am UTC

Reviewer: John from USA

Tom,

I have a table A,B,C and D
A contains idx_no as (PK)
and B,C and D has the idx_no as FK
contains
A :
Idx_no Fld_nam
-------------
1 A
2 B
3 C
4 F
5 G
6 H
7 I
8 J
9 K
10 L

B :
Idx_no Fld_nam
-------------
1 F
2 G
3 H
C :
Idx_no Fld_nam
-------------
4 I
5 J

B :
Idx_no Fld_nam
-------------
6 K
7 L

No the thing is the relation is like : A-B A-C A-D
i.e.


can you please help me to write the query for this?

Tom Kyte

Followup  

April 27, 2006 - 3:15 pm UTC

laughing out loud...

"query for this"

with absolutely zero description of what "this" is? neat.


but also remember-

no creates, no insert into's, no look

with no details - really - no look.

INSTR ambiguity revisited

April 30, 2006 - 9:40 pm UTC

Reviewer: Duke Ganote from Anderson Township, Hamilton County, Ohio USA enjoying a rainy, cool, but not humid Sunday

I've looked at your comment
</code> http://asktom.oracle.com/pls/ask/f?p=4950:61:4666823155820860062::::P61_ID:3083285970877#61672341613426 <code>
and Oraboy's comment following yours.

Please let me try again. "," is my delimiter. And here's the test query:
with input_txt as (
select '",",","' AS STRING
-- 1234567 character positions in STRING
-- , , payload is two strings, each one is just a comma
, '","' AS SUBSTRING -- delimiter
from dual )
select INSTR(string,substring,2,1) start_of_1st_occurs
, INSTR(string,substring,2,2) start_of_2nd_occurs
from input_txt

The first occurrence is in positions 3-5, we all agree. I'd expect the search for the 2nd occurrence to start at position 6 -- after the end of the 1st occurrence. (That's what we need when parsing the CSV.) There really is no 2nd occurrence after the first occurrence when parsing the CSV.

Instead INSTR's search begins at position 4, so it finds a "second occurrence" starting in position 5.

I just think the INSTR documentation is unclear, because it searches for 2nd and subsequent occurrences starting immediately after the position of the prior occurrence -- not after the end of the SUBSTRING (delimiter). And that's an important distinction when parsing the CSV.

What I'd expected was something that behaved more like this formulation:

with input_txt as (
select '",",","' AS STRING
-- 1234567
-- x,xxx,x
, '","' AS SUBSTRING
from dual )
select INSTR(string,substring,2,1) start_of_1st_occurs
, INSTR(string,substring,
INSTR(string,substring,2,1)+length(substring),2)
start_of_2nd_occurs
from input_txt
/
START_OF_1ST_OCCURS START_OF_2ND_OCCURS
------------------- -------------------
3 0

Which is exactly the result if the payload is anything other than commas...

with input_txt as (
select '"#","#"' AS STRING
-- 1234567
, '","' AS SUBSTRING
from dual )
select INSTR(string,substring,2,1) start_of_1st_occurs
, INSTR(string,substring,2,2) start_of_2nd_occurs
from input_txt
/
START_OF_1ST_OCCURS START_OF_2ND_OCCURS
------------------- -------------------
3 0

Tom Kyte

Followup  

May 01, 2006 - 2:05 am UTC

what else can we say other then "sorry"?

I do not think it is fuzzy or anything. You are thinking instr works like "strtok" in C and parses strings.

It did not, it does not. It started looking at the character position after the place where the first string began, if you would like to have it work differently, you would have to specify the character to start from.


Your last example is just misleading - you did not change all of the comma's to #'s, just ones that suited you - instr is NOT a "parser" ala strtok of C, it is what it is. Nothing more.

biggest tablespace size

May 01, 2006 - 6:44 am UTC

Reviewer: Sam from India

Dear Tom,
how can i find out biggest tablespace size in oracle database.

Thanks with Regards,
sam

Tom Kyte

Followup  

May 02, 2006 - 2:40 am UTC

via a query :)

my question to you - what if TWO of the tablespaces are "the biggest" or thirty of them?

Here is one way, it'll return ALL of the largest tablespaces

join 2 tables

May 01, 2006 - 12:30 pm UTC

Reviewer: A reader from MD USA

tom:

I have 2 tables
t1:
a 11
b 11
c 11
t2:
a 22
b 22
d 22
e 22

I want a query result like
a 11 22
b 11 22
c 11
d 22
e 22

All I can think of is union 2 utter join query results, but obviously it is not the best solution, please advice.

Tom Kyte

Followup  

May 02, 2006 - 2:58 am UTC

I would have shown you the syntax for a "full outer join" - but you didn't give any create tables or inserts - so, I won't.

You can read about it on some of these pages:
</code> http://asktom.oracle.com/pls/ask/search?p_string=%22full+outer+join%22 <code>



INSTR vs C's strtok (string tokenizer)

May 01, 2006 - 12:43 pm UTC

Reviewer: Duke Ganote from western, sloggy Clermont County, Ohio USA

I see now that the redoubtable Alberto Dell'Era asked for a native SQL string tokenizer akin to C's strtok
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:23060676216774#50707673544404 <code>
As he said "parsing a comma or tab-separated string is something that happens quite frequently"

Regarding my last example, I did not "change ...just ones [commas] that suited [me]". I changed the payload from 2 strings of one comma each to 2 strings of a pound-sign each. Each example STRING has tokens using double-quotes and comma according to the CSV spec.

Tom Kyte

Followup  

May 02, 2006 - 3:03 am UTC

you are asking for a string tokenizer.

That is not what INSTR does (sorry, just stating a "fact", I cannot change the "fact").

You did just change the comma's that suited you to make the example "work" in your case. You are looking for a STRING TOKENIZER, you are not looking for what INSTR does - for what INSTR is documented to do.

string tokenizer

May 03, 2006 - 10:19 am UTC

Reviewer: Duke Ganote from inside a building on a verdant corporate campus in western Clermont County, Ohio USA

INSTR does what INSTR does; no problem. Just noting that the documentation's statements:
* "position [indicates] the character of string where Oracle Database begins the search"
* "occurrence [indicates] which occurrence of string Oracle should search for"
Don't warn the reader (or -at least- didn't this reader) that when SUBSTRING has a length greater than 1 and OCCURRENCE is greater than 1, there's a difference in functionality between INSTR and a string tokenizer.

Tom Kyte

Followup  

May 03, 2006 - 1:06 pm UTC

"position is an nonzero integer indicating the character of string where Oracle Database begins the search. If position is negative, then Oracle counts backward from the end of string and then searches backward from the resulting position."

You start as position N in the string.
You look for the N'th occurrence of a string from THAT POSITITION.

Instr has no clue about what happend BEFORE that position, it isn't remembering your previous function calls - not like the C function strtok for example.

I'm not sure why such a warning would be necessary since instr makes no claims to be a tokenizer (tokenizers are usually very proud of being such - and would make the claim)

Warning: Instr is not a way to add two numbers
Warning: Instr would not be a good choice to concatenate two strings

?

token comment on INSTR

May 03, 2006 - 3:12 pm UTC

Reviewer: Duke Ganote from an overcast portion of western Clermont County, Ohio USA

I wholly agree that "INSTR has no clue about what happened BEFORE that [starting] position".   To me (at least from the documented description and its examples), it's unclear that INSTR finds "overlapping" occurrences of a SUBSTRING after the starting POSITION, when you ask for more than one occurrence:

select INSTR(',,,,,,,',',,',1,3)
  from dual
SQL> /

INSTR(',,,,,,,',',,',1,3)
-------------------------
                        3 

query to compare data

May 08, 2006 - 10:32 am UTC

Reviewer: thirumaran from INDIA

Hi Tom,

Table_name = EMPLOYEE
Columne_name = SAL
I need to retrieve data only comparing the SAL column .
(ie)
SAL
===
100
110
200
200
i am trying to write a query to check the next below/above value and return the record if it matches.

100 <> 110 (record doesnot match)
110 <>200 (record doesnot match)
200 = 200 (matches and this should be listed).

how do i achive this ?

thanks in adv
thirumaran



Tom Kyte

Followup  

May 08, 2006 - 10:53 am UTC

Need more than "that".

perhaps what you really mean is something like:

select sal, count(*)
from emp
group by sal
having count(*) > 1
order by sal;


that'll print out all repeated sal's and how many times they repeat.

Making copy of Table with Nested Table column.

May 09, 2006 - 6:26 am UTC

Reviewer: Sujit Mondal from India

Hi Tom,
We are maintaining a database developed by other team.
I have a table in which there is a column of type NESTED TABLE. I want to create a copy of this table into some other database schema , while trying with "Creat table as select * " we are getting error because of this nested table type column. Can you please let me know how can I do that?

Tom Kyte

Followup  

May 09, 2006 - 8:27 am UTC

ops$tkyte@ORA10GR2> drop user a cascade;
 
User dropped.
 
ops$tkyte@ORA10GR2> drop user b cascade;
 
User dropped.
 
ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> grant create session, create type, create table to a identified by a;
 
Grant succeeded.
 
ops$tkyte@ORA10GR2> alter user a default tablespace users quota unlimited on users;
 
User altered.
 
ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> grant create session, create table to b identified by b;
 
Grant succeeded.
 
ops$tkyte@ORA10GR2> alter user b default tablespace users quota unlimited on users;
 
User altered.
 
ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> connect a/a
Connected.
a@ORA10GR2> create type myTableType as table of number
  2  /
 
Type created.
 
a@ORA10GR2> create table t ( x int, y myTableType ) nested table y store as y_tab;
 
Table created.
 
a@ORA10GR2>
a@ORA10GR2> grant execute on myTableType to b;
 
Grant succeeded.
 
a@ORA10GR2> grant select on t to b;
 
Grant succeeded.
 
a@ORA10GR2>
a@ORA10GR2> connect b/b
Connected.
b@ORA10GR2> create table t nested table y store as y_tab as select * from a.t;
 
Table created.
 

Sql Question

May 12, 2006 - 2:45 pm UTC

Reviewer: Yoav

Hi Tom,
The following where statment:
where decode(some_column_name,0,:b1,some_column_name) = :b1
can also be written like this:
where (case when some_column_name = 0 then
:b1
else
some_column_name
end ) = :b1
can you suggest another option ?
Thanks

Tom Kyte

Followup  

May 12, 2006 - 9:34 pm UTC

sure, there are thousands of convoluted ways to write that.

but the two you have are more than sufficient. stick with them.

Update statement - need to know old value

May 17, 2006 - 1:19 pm UTC

Reviewer: Anne from MN

Hi Tom,

My need is to write an update statement, but I need to know the old value. Would you please advise on which is the better method performance wise :
1. Method 1: Two update stmts. The first one is just to get the original value :
update transactions_detail
set line_dist_bal_amt = line_dist_bal_amt
where trx_id = cmadj_rec.trx.trx_id
and org_id = cmadj_rec.trx.org_id
and trx_type <> g_cmadj
returning line_dist_bal_amt into l_orig_cmadj_dist_bal_amt;

update transactions_detail
set line_dist_bal_amt = line_dist_bal_amt - l_line_dist_applied_amt
where trx_id = cmadj_rec.trx.trx_id
and org_id = cmadj_rec.trx.org_id
and trx_type <> g_cmadj
returning line_dist_bal_amt into l_new_cmadj_dist_bal_amt ;

2. Method 2 : Using select then update by rowid
select line_dist_bal_amt , rowid
into l_orig_cmadj_dist_bal_amt, l_rowid
from transactions_detail
where trx_id = cmadj_rec.trx.trx_id
and org_id = cmadj_rec.trx.org_id
and trx_type <> g_cmadj ;

update transactions_detail
set line_dist_bal_amt = line_dist_bal_amt - l_line_dist_applied_amt
where rowid = l_rowid
returning line_dist_bal_amt into l_new_cmadj_dist_bal_amt;

Appreciate your comments on this.

Thanks,
Anne

Tom Kyte

Followup  

May 18, 2006 - 10:18 am UTC

it really goes back to your transaction logic here. You are updating a "row blindly" in #1 above.

how can you update this row without having seen this row in the first place? And if you have seen this row (eg: you selected it out on some other page and displayed it to the user), how do you prevent LOST UPDATES....


but if you are doing a blind update, it would be option #2 with a select FOR UPDATE (to lock and protect the row) followed by the update.

Actually, if you just did the blind update, get the new value back - you would know the old value simply by adding l_line_dist_applied_amt to it!

A strange case of case

May 21, 2006 - 4:05 pm UTC

Reviewer: Rish G. from Madison, WI USA

Hi Tom,
  I'm trying to display years as a range. For example, from the emp table, for any employee that has worked more than 24 years, I want to display the number of years worked as 25+, else just display the number of years.
I first tried using the case statement and could find an explanation for the following. 

SQL*Plus: Release 9.2.0.1.0 - Production on Sun May 21 14:47:54 2006

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - 64bit Production
With the Partitioning, OLAP and Data Mining options

SQL> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle Database 10g Enterprise Edition Release 10.2.0.1.0 - 64bi
PL/SQL Release 10.2.0.1.0 - Production
CORE    10.2.0.1.0      Production
TNS for IBM/AIX RISC System/6000: Version 10.2.0.1.0 - Productio
NLSRTL Version 10.2.0.1.0 - Production

Case 1 : works fine without the else statement.

SQL> select empno, hiredate, case when trunc(((sysdate-hiredate)/365.26), 0) > 24 then '25+' end as num_years
  2  from emp;

     EMPNO HIREDATE  NUM
---------- --------- ---
      7369 17-DEC-80 25+
      7499 20-FEB-81 25+
      7521 22-FEB-81 25+
      7566 02-APR-81 25+
      7654 28-SEP-81
      7698 01-MAY-81 25+
      7782 09-JUN-81
      7788 09-DEC-82
      7839 17-NOV-81
      7844 08-SEP-81
      7876 12-JAN-83
      7900 03-DEC-81
      7902 03-DEC-81
      7934 23-JAN-82

14 rows selected.

Case 2 : When I add the else statement to display the number of years worked if less than or equal to 24 then it errors 
SQL> select empno, hiredate, case when trunc((sysdate-hiredate)/365.26) > 24 then '25+'
  2               else  trunc((sysdate-hiredate)/365.26) end as num_years
  3  from emp;
             else  trunc((sysdate-hiredate)/365.26) end as num_years
                   *
ERROR at line 2:
ORA-00932: inconsistent datatypes: expected CHAR got NUMBER

Case 3 : When I convert to char datatypes, it works partially but when it encounters a difference of say 100, it shows the value 100 because of a character compare. 

insert into emp(empno, hiredate, deptno)
values(8888, to_date('01/01/1905', 'mm/dd/yyyy'), 20)    

SQL> select empno, hiredate, case when to_char(trunc((sysdate-hiredate)/365.26)) > to_char(24) then '25+'
  2               else  to_char(trunc((sysdate-hiredate)/365.26)) end as num_years
  3  from emp;

     EMPNO HIREDATE  NUM_YEARS
---------- --------- ----------------------------------------
      7369 17-DEC-80 25+
      7499 20-FEB-81 25+
      7521 22-FEB-81 25+
      7566 02-APR-81 25+
      7654 28-SEP-81 24
      7698 01-MAY-81 25+
      7782 09-JUN-81 24
      7788 09-DEC-82 23
      7839 17-NOV-81 24
      7844 08-SEP-81 24
      7876 12-JAN-83 23
      7900 03-DEC-81 24
      7902 03-DEC-81 24
      7934 23-JAN-82 24
      8888 01-JAN-05 101

15 rows selected.

Can you explain this behavior? Why does it error on adding the else statement whereas and works after an explicit char covnersion after adding the else? 

FYI, this works using the decode function without an explicit conversion to character

SQL> select empno, decode(greatest(trunc((sysdate-hiredate)/365.25), 25), trunc((sysdate-hiredate)/365.25), '25+',
  2                trunc((sysdate-hiredate)/365.25)) years
  3  from emp;

     EMPNO YEARS
---------- ----------------------------------------
      7369 25+
      7499 25+
      7521 25+
      7566 25+
      7654 24
      7698 25+
      7782 24
      7788 23
      7839 24
      7844 24
      7876 23
      7900 24
      7902 24
      7934 24
      8888 25+

15 rows selected.

 

Tom Kyte

Followup  

May 21, 2006 - 8:18 pm UTC

with the case, you are one time returning a string (25+) and one time a number and case says "oh no, you don't get anything implicit from me, TELL me what to do - am I to return a string or a number"

you could use to_char on your number to tell it.


decode on the other hand says "i will peek at the first return value and implicitly convert every other return value to this type". Which is a really bad thing (the side effects I've seen over the years, OUCH)



SQL Query

May 23, 2006 - 9:19 am UTC

Reviewer: A reader

Hi tom, 
i have a data like this.

SQL> select net_name, component from test_table;

NET_NAME                       COMPONENT
------------------------------ ----------
E_S_DIAFI                      CON_PIN
E_S_DIAFI                      Cemi
E_S_DIAFI                      R3
DIAFI_P5_GPIO08                R3
DIAFI_P5_GPIO08                R4

now this table does not have ID-PARENTID column for me to use connect by clause. But my require is something similar.

Based on the start point of a component value 'CON_PIN', i want to start the tree.

so based on CON_PIN value, i will get the net_name, for that net_name, i will again get the components, not for the components again i will get the net_name and so on.

in the process,i want to build the tree based on the retrieved order. something like this.

output 
--------
CON_PIN
       E_S_DIAFI
                Cemi
                R3
                  DIAFI_P5_GPIO08
                                 R4

is this possible with a query.
here is the test case.

create table test_table(net_name varchar2(30), component varchar2(30))
/
insert into test_table values('E_S_DIAFI','CON_PIN')
/
insert into test_table values('E_S_DIAFI','Cemi')
/
insert into test_table values('E_S_DIAFI','R3')
/
insert into test_table values('DIAFI_P5_GPIO08','R3')
/
insert into test_table values('DIAFI_P5_GPIO08','R4')
/
 

Tom Kyte

Followup  

May 23, 2006 - 10:07 am UTC

i don't understand the logic. sometimes you connect by one thing and again by something else.

May 23, 2006 - 10:13 am UTC

Reviewer: A reader

Thanks, Its like start with component, get the net names, for each net name, get the components, for each component get the new names.

in the mean time, if the net name is GND, stop there, if the net name is already been followed, stop there.

Tom Kyte

Followup  

May 23, 2006 - 10:19 am UTC

got version, unless 10g - the "if the net name is already been followed" bit isn't going to happen unless you are on 10g (where the iscycle function exists)

May 23, 2006 - 10:28 am UTC

Reviewer: A reader

Yes we will be migrating to 10g, can you pls give the solution how it might be.

Tom Kyte

Followup  

May 23, 2006 - 3:25 pm UTC

here is an idea of what you could get for example:

ops$tkyte@ORA10GR2> select rpad('*',2*level,'*') || net_name || ',' || component txt
  2    from test_table
  3   start with component = 'CON_PIN'
  4  connect by NOCYCLE
  5             case when mod(level,2) = 0 then prior net_name else prior component end
  6             =
  7             case when mod(level,2) = 0 then net_name else component end
  8  /

TXT
----------------------------------------
**E_S_DIAFI,CON_PIN
****E_S_DIAFI,Cemi
****E_S_DIAFI,R3
******DIAFI_P5_GPIO08,R3
********DIAFI_P5_GPIO08,R4

 

sql auery

May 23, 2006 - 3:39 pm UTC

Reviewer: nn

NET_NAME COMPONENT
------------------------------ ----------
E_S_DIAFI CON_PIN
E_S_DIAFI Cemi
E_S_DIAFI R3
DIAFI_P5_GPIO08 R3
DIAFI_P5_GPIO08 R4

I need your help to format output like

NET_NAME COMPONENT
------------------------------ ----------
E_S_DIAFI CON_PIN,Cemi,R3


Tom Kyte

Followup  

May 24, 2006 - 6:54 am UTC

search site for stragg

stragg

May 24, 2006 - 5:25 pm UTC

Reviewer: nn

select distinct vehicle_id, pl.name
from vehicles_d2d_rules vd,
sales_rules_access_groups srg,
access_groups_prv_label_infos agpl,
private_label_infos pl
where vd.D2D_RULE_ID = srg.SALES_RULE_ID
and srg.ACCESS_GROUP_ID = agpl.ACCESS_GROUP_ID
and agpl.PRIVATE_LABEL_INFO_ID = pl.PRIVATE_LABEL_INFO_ID
and vd.vehicle_id in ( 5102847,4300949)

How can I add stragg here?


Tom Kyte

Followup  

May 25, 2006 - 1:26 pm UTC

select vehicle_id, stragg(pl.name)
from ....
....
group by vehicle_id

error on strag

May 26, 2006 - 1:37 pm UTC

Reviewer: nn

SQL> select vehicle_id, stragg(pl.name) 
  2  from vehicles_d2d_rules vd,
  3  sales_rules_access_groups srg,
  4  access_groups_prv_label_infos agpl,
  5  private_label_infos pl
  6  where vd.D2D_RULE_ID = srg.SALES_RULE_ID
  7  and srg.ACCESS_GROUP_ID = agpl.ACCESS_GROUP_ID
  8  and agpl.PRIVATE_LABEL_INFO_ID = pl.PRIVATE_LABEL_INFO_ID
  9  and vd.vehicle_id in ( 5102847,4300949) group by vehicle_id ;
select vehicle_id, stragg(pl.name)
                   *
ERROR at line 1:
ORA-00904: "STRAGG": invalid identifier
 

Tom Kyte

Followup  

May 27, 2006 - 9:30 pm UTC

so, did you search on stragg on this site (and hence discover it is a package that I wrote and you can use?)

Interesting that this page alone has "search this site for stragg" more than once, more than twice, Heck there is even a comment "STRAGG as defined here: "

May 30, 2006 - 5:32 pm UTC

Reviewer: Pauline from NY,USA

Tom,
We have one query taken from package needs to be tuned from your help.

1. This query will be always slow at first time run but faster if keep execute it because
it is cached in memory. For example, in our development database, it returns result as 3 seconds when first run, 1.5 seconds when second run, 0.9 seconds when 3rd run, 0.5 seconds when forth run.

We really need to speed as faster as 4th run. How to make it fast when application first
execute this package?

2. The speed of returning result related to how many data in result set. For example, when we test the query, in development database, we query campaign_id = 18 which retuns 45 rows, in staging database, we query campaign_id = 1432(no campaign_Id 18 in staging db) which returns more than 180 rows, the speed in staging is much slower(triple time of dev) than development database.
If we query campaign_id = 18 in staging, since no data in result set, it retunrs right away.
How could I tune the query fast based on this behaviour?

The query is as following:

SELECT
cp.campaign_pty_id,
cp.campaign_id,
cp.note_txt,
cp.create_dt,
cp.create_user_id,
cp.last_update_dt,
cp.last_update_user_id,
pas.pty_id ,
pas.party_nm,
cp.number_attending ,
cp.campaign_id,
cp.guest_list_txt,
cp.campaign_id,
cp.campty_stat_id,
cps.campty_status_nm ,
cp.invited_by_txt,
pas.address_id,
pas.address_line_txt,
pas.city_nm,
pas.greg_st_prov_id ,
pas.state_county_nm,
pas.postal_code,
pas.greg_country_id,
pas.country_nm,
i.dietary_list_txt ,
pas.clientsegment_id,
MAIL_TO_PTY_ID,
P.PARTY_NM AS MAIL_TO_PTY_NM
FROM CAMPAIGN_PARTIES cp
, CAMPAIGNS c
, CAMPAIGN_PARTY_STATUSES cps
,( SELECT PTY_ID, ADDRESS_ID, party_nm, address_line_txt, city_nm, greg_st_prov_id , state_county_nm
, postal_code , greg_country_id, country_nm, clientsegment_id, org_or_last_nm_sort, first_nm
FROM PARTY_ADDRESS_SEARCH pas
where SubStr(upper(org_or_last_nm_sort),1,1) = upper('a')) pas
, INDIVIDUALS i
, PARTIES p
where cp.campaign_id = 18
AND cp.campty_stat_id = cps.campty_stat_id
AND cps.campty_stat_id <> 6
AND cp.address_id = pas.address_id
AND cp.pty_id = pas.pty_id
AND cp.campaign_id = c.campaign_id
AND cp.pty_id = i.pty_id(+)
AND cp.MAIL_TO_PTY_ID= P.PTY_ID
ORDER BY pas.address_line_txt
/


The execution plan and cost for the query is:

1.92 SELECT STATEMENT Hint=CHOOSE 92
2.1 SORT ORDER BY 92
3.1 NESTED LOOPS 90
4.1 NESTED LOOPS OUTER 88
5.1 NESTED LOOPS 86
6.1 NESTED LOOPS 85
7.1 NESTED LOOPS 7
8.1 INDEX UNIQUE SCAN XPKCAMPAIGNS UNIQUE
8.2 TABLE ACCESS BY INDEX ROWID CAMPAIGN_PARTIES 6
9.1 INDEX RANGE SCAN XIF3CAMPAIGN_PARTIES NON-UNIQUE 1
7.2 TABLE ACCESS BY INDEX ROWID PARTY_ADDRESS_SEARCH 3
8.1 INDEX RANGE SCAN PA_SEARCH_ADDRESS_ID_IDX NON-UNIQUE 2
6.2 TABLE ACCESS BY INDEX ROWID CAMPAIGN_PARTY_STATUSES 1

7.1 INDEX UNIQUE SCAN XPKCAMPAIGN_PARTY_STATUSES UNIQUE
5.2 TABLE ACCESS BY INDEX ROWID INDIVIDUALS 2
6.1 INDEX UNIQUE SCAN XPKINDIVIDUALS UNIQUE 1
4.2 TABLE ACCESS BY INDEX ROWID PARTIES 2
5.1 INDEX UNIQUE SCAN XPKPARTIES UNIQUE 1

18 rows selected.

Please give the hand or idea of how to speed up the query.

Thanks in adance.

Tom Kyte

Followup  

May 30, 2006 - 7:11 pm UTC

1) buy infinitely fast disk? Think about it - if we have to do physical IO (unavoidable in the REAL WORLD - your development instance is "like a dust free lab", you'll likely never really see "4" in real life as you'll likely have other stuff going on)



2) suggest before you do anything, you dig into "how to use tkprof" to analyze what your queries are

a) doing
b) how they are doing it
c) what they are waiting on

an understanding of that will go a long long way towards understanding what you can and cannot do

(hint, one thing I would be looking for would be index scans that have LOTS of rows returned but the resulting table access by index rowid has FEW rows - by adding a column or two to an index, you might well be able to massively cut down the work performed. For example..

I force the use of an index on just owner, and then on owner,object_type - showing that by simply adding object_type to the index we can massively reduce the work:

select /*+ index( big_table bt_owner_idx ) */ * from big_table
where owner = 'SYS' and object_type = 'SCHEDULE'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 15 12.92 35.70 131052 131188 0 202
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 17 12.93 35.70 131052 131188 0 202

Rows Row Source Operation
------- ---------------------------------------------------
202 TABLE ACCESS BY INDEX ROWID BIG_TABLE (cr=131188 pr=131052 pw=0 time=38076066 us)
4623132 INDEX RANGE SCAN BT_OWNER_IDX (cr=9689 pr=9674 pw=0 time=4692939 us)(object id 66535)

here we see 4,623,132 rows out of the index, resulting in a mere 202 rows from the table - by simply adding another column to the index:

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 15 0.00 0.00
db file sequential read 131052 0.02 25.95
SQL*Net message from client 15 0.01 0.03
********************************************************************************
select /*+ index( big_table bt_owner_object_type_idx ) */ * from big_table
where owner = 'SYS' and object_type = 'SCHEDULE'

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 15 0.03 0.57 165 252 0 202
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 17 0.04 0.58 165 252 0 202

Rows Row Source Operation
------- ---------------------------------------------------
202 TABLE ACCESS BY INDEX ROWID BIG_TABLE (cr=252 pr=165 pw=0 time=41046 us)
202 INDEX RANGE SCAN BT_OWNER_OBJECT_TYPE_IDX (cr=18 pr=3 pw=0 time=12930 us)(object id 66536)


Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 15 0.00 0.00
db file sequential read 165 0.01 0.55
SQL*Net message from client 15 0.01 0.05

we can avoid going to and from the index/table/index/table ..... and avoid the work involved



bits ..

May 30, 2006 - 11:45 pm UTC

Reviewer: Gabe

Regarding the query above … is there any merit to these observations:

1. They don’t select anything from “c” (“campaigns”) … assuming, as the naming seems to suggest, that “campaign_parties” is a child of “campaigns” strictly enforced with a FK constraint then “campaigns” can be taken out of the query all together.

2. Re-write the predicate “cps.campty_stat_id <> 6” against “cp” and investigate adding “cp.campty_stat_id” to the index on “campaign_id” (XIF3CAMPAIGN_PARTIES I assume) … might be there already.


Tom Kyte

Followup  

May 31, 2006 - 8:48 am UTC

1) indeed, in fact:

FROM CAMPAIGN_PARTIES cp
, CAMPAIGNS c
, CAMPAIGN_PARTY_STATUSES cps
,( SELECT PTY_ID, ADDRESS_ID, party_nm, address_line_txt, city_nm,
greg_st_prov_id , state_county_nm
, postal_code , greg_country_id, country_nm, clientsegment_id,
org_or_last_nm_sort, first_nm
FROM PARTY_ADDRESS_SEARCH pas
where SubStr(upper(org_or_last_nm_sort),1,1) = upper('a')) pas
, INDIVIDUALS i
, PARTIES p
where cp.campaign_id = 18
AND cp.campty_stat_id = cps.campty_stat_id
AND cps.campty_stat_id <> 6
AND cp.address_id = pas.address_id
AND cp.pty_id = pas.pty_id
AND cp.campaign_id = c.campaign_id
AND cp.pty_id = i.pty_id(+)
AND cp.MAIL_TO_PTY_ID= P.PTY_ID
ORDER BY pas.address_line_txt
/

could at least be (assuming campaign_id is primary key of campaigns - as it seems it "would be")

FROM CAMPAIGN_PARTIES cp
, CAMPAIGN_PARTY_STATUSES cps
,( SELECT PTY_ID, ADDRESS_ID, party_nm, address_line_txt, city_nm,
greg_st_prov_id , state_county_nm
, postal_code , greg_country_id, country_nm, clientsegment_id,
org_or_last_nm_sort, first_nm
FROM PARTY_ADDRESS_SEARCH pas
where SubStr(upper(org_or_last_nm_sort),1,1) = upper('a')) pas
, INDIVIDUALS i
, PARTIES p
where cp.campaign_id = 18
AND cp.campty_stat_id = cps.campty_stat_id
AND cps.campty_stat_id <> 6
AND cp.address_id = pas.address_id
AND cp.pty_id = pas.pty_id
AND exists ( select null from campaigns where campaign_id=18)

AND cp.pty_id = i.pty_id(+)
AND cp.MAIL_TO_PTY_ID= P.PTY_ID
ORDER BY pas.address_line_txt
/

also,

where SubStr(upper(org_or_last_nm_sort),1,1) = upper('a')) pas


could be

where org_or_last_nm_sort like 'A%' or org_or_last_nm_sort like 'a%'

leading *possibly* to using an index on org_or_last_nm_sort if applicable

excellent help

June 01, 2006 - 1:43 pm UTC

Reviewer: Pauline from NY,USA

Tom,
Thanks so much for your great help with analyzing the query and suggestion. I have used
tkprof and see the change from

where SubStr(upper(org_or_last_nm_sort),1,1) = upper('a')

to

where org_or_last_nm_sort like 'A%' or org_or_last_nm_sort like 'a%'

making big difference.


The former is showing in the report as


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.08 1.34 1 6 0 0
Execute 1 0.00 0.02 0 0 0 0
Fetch 4 0.41 6.42 607 6306 0 45
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 6 0.49 7.79 608 6312 0 45


The latter is showing in the report as

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.10 0.10 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 4 0.24 0.44 1 6306 0 45
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 6 0.34 0.55 1 6306 0 45




Tom Kyte

Followup  

June 01, 2006 - 2:36 pm UTC

not really - you just hit the cache the second time, you missed it the first.

The time was spent doing physical IO for the first query. Nothing has changed.

SQL Query

June 10, 2006 - 12:48 pm UTC

Reviewer: Sankar Kumar from Hyderabad, India

Hi Tom,

Similar to the first question of this page, I have a table like this:

Personid Change_Sequence Class Cls_EffDate Location Loc_EffDate
----------------------------------------------------------------------------
1000 1 FullTime Hawaii
1000 2 FullTime California 1/1/2005
1000 3 PartTime 1/1/2006 California 1/1/2005
1000 4 PartTime 1/1/2006 Texas 10/1/2005
1000 5 FullTime 1/1/2007 Boston 1/1/2007

1. The primary key is (Personid, change_sequence)

2. The effective dates of the first row for each person is null (i.e. for change_sequence = 1)

3. For each row only one column value will be effected (i.e. Either Class or Location can be changed) and the remaining data will be copied from the previous row

4. Both Class and Location can be changed in a row, only if the effective date is same. [See where change_sequence = 5]

I am using the following queries for getting Class and Location of the person as per given Effective Date.

Using Correlated SubQuery.

Select Cls.personid, Cls.Class, Loc.Location
from employee Cls, employee Loc
where Cls.personid = Loc.personid
and Cls.change_sequence =
(select max(change_sequence)
from employee
where personid = Cls.Personid
and nvl(Cls_EffDate, to_date('&givenDate','MM/DD/YYYY')) <= to_date('&givenDate','MM/DD/YYYY'))
and Loc.change_sequence =
(select max(change_sequence)
from employee
where personid = Loc.Personid
and nvl(Loc_Effdate, to_date('&givenDate','MM/DD/YYYY')) <= to_date('&givenDate','MM/DD/YYYY'))


Using Analytical functions

Select ECls.personid, ECls.class, ELoc.Location
from (select *
from (select personid,
class,
row_number() over(partition by personid order by change_sequence desc) r
from employee
where nvl(Cls_EffDate, to_date('&givenDate','MM/DD/YYYY')) <= to_date('&givenDate','MM/DD/YYYY')) Cls
where Cls.r = 1) ECls,
(Select *
from (select personid,
Location,
row_number() over(partition by personid order by change_sequence desc) r
from employee
where nvl(Loc_EffDate, to_date('&givenDate','MM/DD/YYYY')) <= to_date('&givenDate','MM/DD/YYYY')) Loc
where Loc.r = 1) ELoc
where ECls.personid = ELoc.personid;



The table has more than 1 Lakh rows and more than 12 columns based on effective dates. (For example Dept,Dept_EffDate,Status, Status_EffDate,.....)

I am creating a separate instance in the query, for getting each columns data, based on the given effective date.

My question is, Is there any way to get all the Columns using only single instance (Employee)?
If not, Is there any other good design to handle this type of data?

create table employee
(personid number(10),
change_sequence number(3),
class varchar2(50),
cls_effdate date,
location varchar2(50),
loc_effdate date,
primary key (personid,change_sequence));

insert into employee values(1000,1,'FullTime',null,'Hawaii',null);
insert into employee values(1000,2,'FullTime',null,'California',to_date('1/1/2005','MM/DD/YYYY'));
insert into employee values(1000,3,'PartTime',to_date('1/1/2006','MM/DD/YYYY'),'California',to_date('1/1/2005','MM/DD/YYYY'));
insert into employee values(1000,4,'PartTime',to_date('1/1/2006','MM/DD/YYYY'),'Texas',to_date('10/1/2005','MM/DD/YYYY'));
insert into employee values(1000,5,'FullTime',to_date('1/1/2007','MM/DD/YYYY'),'Boston',to_date('1/1/2007','MM/DD/YYYY'));


Thanks in Advance
Sankar




Tom Kyte

Followup  

June 11, 2006 - 11:50 am UTC

wouldn't you just need the record where the sequence is the maximum for that person???

suppose record 5 did not exist, wouldn't you just want record 4 - even though both values were not modified.

create table

June 12, 2006 - 7:52 am UTC

Reviewer: Tony from USA

Tom,

I want to create one table from another table with partition and indexes.

like if I have a table emp which is partition table and having 5 indexes.

I want to create a table emp_temp witch will be the mirror image of emp table.

create table emp_temp as select * from emp.

this script will not generate the partitions and indexes.

Tom Kyte

Followup  

June 12, 2006 - 10:04 am UTC

what script, we are not even talking about creating tables here.

read about dbms_metadata, it is something you'll likely be able to use as you develop your script to do this.

test

June 12, 2006 - 10:35 am UTC

Reviewer: test from UK

test

test

June 12, 2006 - 10:42 am UTC

Reviewer: test from UK

test

rowid into column

June 12, 2006 - 12:03 pm UTC

Reviewer: A reader

Hi tom

How can we capture rowid into column of another table for
debugging purpose.

Tom Kyte

Followup  

June 13, 2006 - 10:35 am UTC

anyway you want to???

sorry, but this is too vague to answer. What rowid do you want to capture, under what circumstances and how does this help "debugging"

SQL Query

June 12, 2006 - 12:58 pm UTC

Reviewer: A reader

Hi,

Sorry Tom, I would have added these two rows too.

insert into employee values(1000,6,'COBRA-Class',to_date('1/1/2005','MM/DD/YYYY'),'Boston',to_date('1/1/2007','MM/DD/YYYY'));

insert into employee values(1000,7,'COBRA-Terminated',to_date('5/1/2006','MM/DD/YYYY'),'Boston',to_date('1/1/2007','MM/DD/YYYY'));

Now lets say givenDate = 1/1/2005

Then the output would be

PERSONID CLASS LOCATION CLS_CHANGE_SEQ LOC_CHANGE_SEQ
------------------------------------------------------------------------------
1000 COBRA-Class California 6 3


when givenDate = 1/1/2006 the output would be

PERSONID CLASS LOCATION CLS_CHANGE_SEQ LOC_CHANGE_SEQ
------------------------------------------------------------------------------
1000 COBRA-Class Texas 6 4


when givenDate = 1/1/2007 the output would be

PERSONID CLASS LOCATION CLS_CHANGE_SEQ LOC_CHANGE_SEQ
------------------------------------------------------------------------------
1000 COBRA-Terminated Boston 7 7

Thanks,
Sankar

Tom Kyte

Followup  

June 13, 2006 - 10:41 am UTC

explain what I'm looking at here - basically "start over" (I cannot patch together everything spread all over the place) and explain using TEXT what your goal is.

create table

June 13, 2006 - 4:47 am UTC

Reviewer: Tony from USA

Hi Tom,

Thanks a lot for info.

But what i am looking for is creating the table from other table with partition and indexes.

I created the DB link and now i am creating the same tables with the contants.

Like in SCOTT schema i have the product table with 1 index and partition on mis_date.

No i am creating the table product_back in testing schema.
but the product_back shuld contain all the data with partition and index which has the table product in scott schema.

Like this i have 1000+ tables. So i want to write a sql statment where it will genrate the table with all the Partition and indexes.

Like
create table testing.product_back as select * from scott.product.

Can you please help in writing this.

Many thanks in advance.

Tony



Tom Kyte

Followup  

June 13, 2006 - 12:20 pm UTC

use dbms_metadata


that is all I can say and all I'll keep saying over and over. create table as select does not do that.

There are tools in graphical interfaces like Enterprise manager that can do a "copy table and make it look like that table"

But - read about dbms_metadata.

SQL Queries - Different Syntax, Same Output, Plan Variations.

June 22, 2006 - 2:51 am UTC

Reviewer: Vikas Sangar from INDIA

Dear Mr. Kyte

Please refer to the Queries and their respective Execution plans given below.

A) SELECT * FROM ACCOUNTS
SELECT STATEMENT, GOAL = CHOOSE Cost=3 Cardinality=458 Bytes=67784
TABLE ACCESS FULL Object name=ACCOUNTS Cost=3 Cardinality=458 Bytes=67784

B) SELECT * FROM ACCOUNTS ORDER BY ACCOUNTID
SELECT STATEMENT, GOAL = CHOOSE Cost=14 Cardinality=458 Bytes=67784
SORT ORDER BY Cost=14 Cardinality=458 Bytes=67784
TABLE ACCESS FULL Object name=ACCOUNTS Cost=3 Cardinality=458 Bytes=67784

c) SELECT * FROM ACCOUNTS ORDER BY ACCOUNTID ASC
SELECT STATEMENT, GOAL = CHOOSE Cost=14 Cardinality=458 Bytes=67784
SORT ORDER BY Cost=14 Cardinality=458 Bytes=67784
TABLE ACCESS FULL Object name=ACCOUNTS Cost=3 Cardinality=458 Bytes=67784

D) SELECT * FROM ACCOUNTS WHERE 1 = 1 ORDER BY 1
SELECT STATEMENT, GOAL = CHOOSE Cost=14 Cardinality=458 Bytes=67784
SORT ORDER BY Cost=14 Cardinality=458 Bytes=67784
TABLE ACCESS FULL Object name=ACCOUNTS Cost=3 Cardinality=458 Bytes=67784

All these queries return the same number (Count) of records in a similar Format. What I want to know here is-


1. Why are the above queries returning the similar records but with the diffrent Plan output?

2. I have learnt that by default Oracle displays its output, sorted in ascending order; Then - Why are queries B & c, different from A in their Execution scheme? Is not oracle internally applying ASC to my query A? if yes, then why does it feels bad of my adding up explicit "ORDER BY" and "ASC" clauses?

3. Why does Queries B, C, & D have same execution plan?

4. Is query D syntactically right? Why at all the query D executes and displays output with "ORDER BY 1" and not ORDER BY 2?

Take care, regards.
Vikas.



Tom Kyte

Followup  

June 22, 2006 - 12:19 pm UTC

1) because they do entirely DIFFERENT things????

is that not "obvious"?

query 1 - select * from t;
query 2 - select * from t order by something;


entirely different queries - totally different - radically different, not even close to being the same. Night and Day different.


2) you have learnt "wrong". By default, results from a query are returned in any order we like. If you use order by column, the default sort order for column is in fact ASCENDING.

Unless and until you add "order by" to a query, you cannot say ANYTHING about the order of the rows returned. Well, short of "you cannot rely on the order of the rows being returned"

Until you have order by - NO ASSUMPTION CAN BE MADE ABOUT THE ORDER OR ROWS.


3) order by 1 - by definition - orders by the first selected column in the SELECT list.

Using Cursor

June 29, 2006 - 5:26 pm UTC

Reviewer: Ramu from India

Hi,

my table is having above 15 million records, I want to delete duplicate records from that table, can any one suggest by writing pl/sql(cursor) it will be faster or simply with delete statement using partition clasue will be faster. pls suggest me feasible solution.

Regards
Ramu

Tom Kyte

Followup  

June 29, 2006 - 6:51 pm UTC

delete from t
where rowid in ( select rid
from (select rowid rid,
row_number() over (PARTITION BY KEY-COLUMNS
order by rn)
from t )
where rn <> 1 );

single sql statement - you have to find the duplicates (the subquery) and then delete them - that does it.

SQL Queries - Different Syntax, Same Output, Plan Variations.

June 30, 2006 - 2:26 am UTC

Reviewer: Vikas from INDIA

Dear Mr. Kyte

Thanks a lot. It really helped me in refinement of Concepts(especially sort related stuf).

Take care.
Vikas.

SQL-query

June 30, 2006 - 3:13 am UTC

Reviewer: gunasekaran Radhika from Singapore

Tom please answer me,
Film {title(pk),director,language,genre,releaseyear,price}
video{videono(pk)title(fk), location, maxdaysloan, overdue}
customer{name(pk),address,maxnovideosforloan}
loan{name(fk),videono(fk),dateout,returndate}
Query : list all customer(name,address) who have videos overdue,togeather with the titles of the videos-a video is considered as overdue if it was not returned and it was on loan for more than the maxdaysloan.



Tom Kyte

Followup  

June 30, 2006 - 7:22 am UTC

do I get your grade too?

Split the column and create multiple rows

June 30, 2006 - 3:45 pm UTC

Reviewer: ST from MI, USA

How do we split the string in column C to have multiple records. The first characters, ('ABC') before ';' should be concatenated with the characters ('A200') after the space to the end of ';'. The same for the second set of characters, 'ABCD' which is after the first ';' should be concatenated with the string, 'A1001', comming after the first ';' after the space. Here is the sample data and expecting to get the desired output. Where as line 2 has 3 different valuse with a space before 'A201'.

create table test1 (
a number,
b varchar2(10)'
c varchar2(20));

create table test2 (
a number,
b varchar2(10)'
c varchar2(20));

insert into test1 values(1,1001,'ABC;ABCD A200;A1001');

insert into test1 values(1,'1002','ABD;BCD;CDEF;DEFG A201;B102;C1003;D4001');
commit;


Table TEST1
A B C
- ---- -------------------
1 1001 ABC;ABCD A200;A1001
1 1002 ABD;BCD;CDEF;DEFG A201;B102;C1003;D4001



Should be loaded into table TEST2 as shown below.

A B C
- ---- --------------
1 1001 ABC A200
1 1001 ABCD A1001
1 1002 ABD A201
1 1002 BCD B102
1 1002 CDEF C1003
1 1002 DEFG D4001




Tom Kyte

Followup  

June 30, 2006 - 5:09 pm UTC

I added "d" to test2 - you don't want to create yet another string problem right - we'll keep them as two fields. 20 is a number I picked, you can increase if needed:

ops$tkyte@ORA10GR2> insert into test2(a,b,c,d)
  2  with data
  3  as
  4  (select level r
  5     from dual
  6  connect by level <= 20
  7  ),
  8  t
  9  as
 10  (
 11  select a, b, ';'||substr(c,1,instr(c,' ')-1)||';' part1, ';'||substr(c,instr(c,' ')+1)||';' part2,
 12         (length(c)-length(replace(c,';')))/2+1 r
 13    from test1
 14  )
 15  select t.a, t.b,
 16         substr( part1, instr(part1,';',1,data.r)+1, instr(part1,';',1,data.r+1)- instr(part1,';',1,data.r)-1 ) p1,
 17         substr( part2, instr(part2,';',1,data.r)+1, instr(part2,';',1,data.r+1)- instr(part2,';',1,data.r)-1 ) p2
 18    from data, t
 19   where data.r <= t.r
 20   order by t.a, t.b, data.r
 21  /

6 rows created.

ops$tkyte@ORA10GR2> select * from test2;

         A B          C                    D
---------- ---------- -------------------- --------------------
         1 1001       ABC                  A200
         1 1001       ABCD                 A1001
         1 1002       ABD                  A201
         1 1002       BCD                  B102
         1 1002       CDEF                 C1003
         1 1002       DEFG                 D4001

6 rows selected.
 

Split the column and create multiple rows

June 30, 2006 - 5:18 pm UTC

Reviewer: ST from MI, USA

Thank you for your response.
Creating an additional column does not serve my purpose. I gave as an example with just two records. But my data may contain more than those three combinations in column C.
So when we have like more than 10 different combinations in column C, then I need to create them into that many different columns which is not what I am looking for. Is there any way using 'substr' and 'instr' functions to have them concatenated instead. Appreciate your helps.



Tom Kyte

Followup  

July 01, 2006 - 7:38 am UTC

you do not see how you could concatenate them yourself easily instead of selecting out p1 and p2?

Just || them

Split the column and create multiple rows

June 30, 2006 - 6:23 pm UTC

Reviewer: ST from MI, USA

Sorry for posting this on another review. But still the same request for splitting the string based on separators and concatenating them when more than three occurances exists within the column.

Tom Kyte

Followup  

July 01, 2006 - 7:47 am UTC

I believe you have everything you need above right? It shows the technique, you can concatenate output any which way you like.

Query Time

July 01, 2006 - 2:51 am UTC

Reviewer: Jal

CREATE TABLE problem (
KEY NUMBER,
KEYNAME VARCHAR2 (4000),
VALUE1 VARCHAR2 (4000),
VALUE2 VARCHAR2 (4000),
VALUE3 VARCHAR2 (4000) ) ;

this table contains 1236742 + rows and i want to run following querie on this table which is taking too much time !!

SELECT value2
FROM weo_itr_gen_param_drm
WHERE keyname='Action'
AND value1='Sent to HO'
AND KEY=:1
AND value2= (
SELECT MIN(value2)
FROM weo_itr_gen_param_drm
WHERE keyname='Action' AND
VALUE1='Sent to HO' AND
KEY = :1
)
Please guide as to what should be done to increase speed !! Kindly note currently there is index on
1)key 2) keyname 3)value1

Explain Plan

Operation Object Name Rows Bytes Cost TQ In/Out PStart PStop

SELECT STATEMENT Hint=CHOOSE
TABLE ACCESS BY INDEX ROWID WEO_ITR_GEN_PARAM_DRM
AND-EQUAL
INDEX RANGE SCAN WEO_ITR_GENPRM_KEY_INDX
INDEX RANGE SCAN IDX_VALUE1
INDEX RANGE SCAN WEO_ITR_GENPRM_KEY_DRM_INDX
INDEX RANGE SCAN IDX_VALUE2
SORT AGGREGATE
TABLE ACCESS BY INDEX ROWID WEO_ITR_GEN_PARAM_DRM
AND-EQUAL
INDEX RANGE SCAN WEO_ITR_GENPRM_KEY_INDX
INDEX RANGE SCAN IDX_VALUE1
INDEX RANGE SCAN WEO_ITR_GENPRM_KEY_DRM_INDX


Tom Kyte

Followup  

July 01, 2006 - 7:54 am UTC

Isn't:

SELECT value2
FROM weo_itr_gen_param_drm
WHERE keyname='Action'
AND value1='Sent to HO'
AND KEY=:1
AND value2= (
SELECT MIN(value2)
FROM weo_itr_gen_param_drm
WHERE keyname='Action' AND
VALUE1='Sent to HO' AND
KEY = :1
)

Just a complex way pretty much to say:

select min(value2)
from weo_itr_gen_param_drm
WHERE keyname='Action'
AND VALUE1='Sent to HO'
AND KEY = :1


and a CONCATENATED index would be called for - seems you have a bunch of them being used.

create index t_idx on t(keyname,value1,key,value2);



another query

July 01, 2006 - 2:59 pm UTC

Reviewer: hash

Hi,
May be this query is not related to this thread but I m sure I'll get an answer

Consider this:

SQL> create table t (
  2  ca_no varchar2(6),
  3  ltr_no varchar2(30),
  4  ltr_date date);

--case 1: the three rows are identical except the ltr_date
insert into t values('01/04','30/27/Stores/DH-01/04', '16/12/2005');
insert into t values('01/04','30/27/Stores/DH-01/04', '20/12/2005');
insert into t values('01/04','30/27/Stores/DH-01/04', '25/12/2005');

--case 2: ltr_no are different
insert into t values('12/05','30/27/Stores/DH-12/05/1','25/05/2005');
insert into t values('12/05','30/27/Stores/DH-12/05/2','25/05/2005');

--case 3: they are identical
insert into t values('20/04','30/27/Stores/DH-20/04','17/07/2005');
insert into t values('20/04','30/27/Stores/DH-20/04','17/07/2005');

Now I want a string value for each ca_no like:

for case 1, I want:
our letter number 30/27/Stores/DH-01/04 dated 16/12/2005, even number dated 20/12/2005 and even number dated 25/12/2005.

for case 2, I want:
our letter number 30/27/Stores/DH-12/05/1 and 30/27/Stores/DH-12/05/2 both dated 25/05/2005.

for case 3:
our letter number 30/27/Stores/DH-20/04 and even number both dated 17/07/2005.

The number of rows can vary from 1 to 4 for each ca_no and the combination of ltr_no and ltr_date can be of any number.

can I achieve this in SQL or PL/SQL? I m using 8.0.5

Thanks 

Split the column and create multiple rows

July 03, 2006 - 9:24 am UTC

Reviewer: ST from MI, USA

Tom,
The solution for splitting the data is perfect and I appreciate your help. Just a quick question, Instead of loading data into temp table and then manipulating it, can this be done using sqlldr when we have the data in the same format like

1 1001 ABC;ABCD A200;A1001
1 1002 ABD;BCD;CDEF;DEFG A201;B102;C1003;D4001
.......
.......

in a csv file.

Tom Kyte

Followup  

July 07, 2006 - 6:49 pm UTC

two words for you:

external tables

Split the column and create multiple rows

July 03, 2006 - 9:34 am UTC

Reviewer: ST from MI, USA

I have given the wrong format above. Here is the correct format that needs to be loaded using sqlldr.

1,1001,ABC;ABCD A200;A1001
1,1002,ABD;BCD;CDEF;DEFG A201;B102;C1003;D4001
.....
.....

Select just after where clause in PL/SQL

July 03, 2006 - 10:49 am UTC

Reviewer: Ravi Kumar from London

I am trying to write this statement, It is working in SQL but not in PL/SQL.

SQL> insert into currency select * from currency where (select 5 from dual) between 10 and 20;

0 rows created.

Now in a PLSQL Block

SQL> begin
  2  insert into currency select * from currency where (select 5 from dual) between 10 and 20;
  3  end;
  4  /
insert into currency select * from currency where (select 5 from dual) between 10 and 20;
                                                   *
ERROR at line 2:
ORA-06550: line 2, column 52:
PLS-00103: Encountered the symbol "SELECT" when expecting one of the following:
( - + mod not null others <an identifier>
<a double-quoted delimited-identifier> <a bind variable> avg
count current exists max min prior sql stddev sum variance
execute forall time timestamp interval date
<a string literal with character set specification>
<a number> <a single-quoted SQL string>
ORA-06550: line 2, column 72:
PLS-00103: Encountered the symbol "BETWEEN" when expecting one of the
following:
; return returning and or
ORA-06550: line 3, column 1:
PLS-00103: Encountered the symbol "END"


Can you please suggest me what can I do to make it run in PL/SQL ? 

Tom Kyte

Followup  

July 07, 2006 - 6:58 pm UTC

upgrade to software written this century?  I believe you must be in 8i (not stated anywhere) and in 8i, using scalar subqueries in PLSQL was a non-starter (not supported)

ops$tkyte@ORA10GR2> create table t ( x varchar2(1) );

Table created.



ops$tkyte@ORA10GR2> insert into t select * from dual where (select 5 from dual) between 10 and 20;

0 rows created.

ops$tkyte@ORA10GR2> begin insert into t select * from dual where (select 5 from dual) between 10 and 20; end;
  2  /

PL/SQL procedure successfully completed.



Of course your query is the same as:

insert into currency
select * 
  from currency
 where EXISTS ( select null
                  from dual
                 where 5 between 10 and 20 );

so perhaps you can simply rewrite using an EXISTS. 

July 03, 2006 - 6:13 pm UTC

Reviewer: Pat from TX

create table pub1
(stdt date,
eddt date,
pubdt date,
amt number)

insert into pub1
values('01-MAY-2006','01-MAY-2006','08-MAY-2006',6.25);
insert into pub1
values('02-MAY-2006','02-MAY-2006','08-MAY-2006',6.38);
insert into pub1
values('03-MAY-2006','03-MAY-2006','08-MAY-2006',6.12);
insert into pub1
values('04-MAY-2006','04-MAY-2006','08-MAY-2006',6.05);
insert into pub1
values('05-MAY-2006','05-MAY-2006','08-MAY-2006',6.00);
insert into pub1
values('06-MAY-2006','06-MAY-2006',NULL,6.42);
insert into pub1
values('07-MAY-2006','07-MAY-2006',NULL,6.25);
insert into pub1
values('08-MAY-2006','08-MAY-2006',NULL,6.80);
insert into pub1
values('09-MAY-2006','09-MAY-2006',NULL,6.45);
insert into pub1
values('10-MAY-2006','10-MAY-2006',NULL,6.98);
insert into pub1
values('11-MAY-2006','11-MAY-2006',NULL,6.45);
insert into pub1
values('12-MAY-2006','12-MAY-2006',NULL,6.11);
insert into pub1
values('13-MAY-2006','13-MAY-2006',NULL,6.55);
insert into pub1
values('14-MAY-2006','14-MAY-2006',NULL,6.12);
insert into pub1
values('15-MAY-2006','15-MAY-2006','19-MAY-2006',6.45);
insert into pub1
values('16-MAY-2006','16-MAY-2006','19-MAY-2006',6.45);
insert into pub1
values('17-MAY-2006','17-MAY-2006','19-MAY-2006',6.45);
insert into pub1
values('18-MAY-2006','18-MAY-2006','19-MAY-2006',6.12);
insert into pub1
values('19-MAY-2006','19-MAY-2006','24-MAY-2006',6.91);
insert into pub1
values('20-MAY-2006','20-MAY-2006',NULL,6.72);
insert into pub1
values('21-MAY-2006','21-MAY-2006',NULL,6.34);
insert into pub1
values('22-MAY-2006','22-MAY-2006',NULL,6.78);
insert into pub1
values('23-MAY-2006','23-MAY-2006',NULL,6.28);
insert into pub1
values('24-MAY-2006','24-MAY-2006',NULL,6.38);
insert into pub1
values('25-MAY-2006','25-MAY-2006',NULL,6.18);
insert into pub1
values('26-MAY-2006','26-MAY-2006',NULL,6.72);
insert into pub1
values('27-MAY-2006','27-MAY-2006',NULL,6.56);
insert into pub1
values('28-MAY-2006','28-MAY-2006',NULL,6.24);
insert into pub1
values('29-MAY-2006','29-MAY-2006',NULL,6.43);
insert into pub1
values('30-MAY-2006','30-MAY-2006','05-jun-2006',6.22);
insert into pub1
values('31-MAY-2006','31-MAY-2006','05-jun-2006',6.44);
insert into pub1
values('01-JUN-2006','30-JUN-2006',NULL,6.72);

SELECT * FROM PUB1;
STDT EDDT PUBDT AMT
1-May-2006 1-May-2006 8-May-2006 6.25
2-May-2006 2-May-2006 8-May-2006 6.38
3-May-2006 3-May-2006 8-May-2006 6.12
4-May-2006 4-May-2006 8-May-2006 6.05
5-May-2006 5-May-2006 8-May-2006 6
6-May-2006 6-May-2006 [NULL] 6.42
7-May-2006 7-May-2006 [NULL] 6.25
8-May-2006 8-May-2006 [NULL] 6.8
9-May-2006 9-May-2006 [NULL] 6.45
10-May-2006 10-May-2006 [NULL] 6.98
11-May-2006 11-May-2006 [NULL] 6.45
12-May-2006 12-May-2006 [NULL] 6.11
13-May-2006 13-May-2006 [NULL] 6.55
14-May-2006 14-May-2006 [NULL] 6.12
15-May-2006 15-May-2006 19-May-2006 6.45
16-May-2006 16-May-2006 19-May-2006 6.45
17-May-2006 17-May-2006 19-May-2006 6.45
18-May-2006 18-May-2006 19-May-2006 6.12
19-May-2006 19-May-2006 24-May-2006 6.91
20-May-2006 20-May-2006 [NULL] 6.72
21-May-2006 21-May-2006 [NULL] 6.34
22-May-2006 22-May-2006 [NULL] 6.78
23-May-2006 23-May-2006 [NULL] 6.28
24-May-2006 24-May-2006 [NULL] 6.38
25-May-2006 25-May-2006 [NULL] 6.18
26-May-2006 26-May-2006 [NULL] 6.72
27-May-2006 27-May-2006 [NULL] 6.56
28-May-2006 28-May-2006 [NULL] 6.24
29-May-2006 29-May-2006 [NULL] 6.43
30-May-2006 30-May-2006 5-Jun-2006 6.22
31-May-2006 31-May-2006 5-Jun-2006 6.44
1-Jun-2006 30-Jun-2006 [NULL] 6.72

Output i want
STDT EDDT PUBDT AMT
1-May-2006 1-May-2006 8-May-2006 6.8
2-May-2006 2-May-2006 8-May-2006 6.8
3-May-2006 3-May-2006 8-May-2006 6.8
4-May-2006 4-May-2006 8-May-2006 6.8
5-May-2006 5-May-2006 8-May-2006 6.8
6-May-2006 6-May-2006 [NULL] 6.42
7-May-2006 7-May-2006 [NULL] 6.25
8-May-2006 8-May-2006 [NULL] 6.8
9-May-2006 9-May-2006 [NULL] 6.45
10-May-2006 10-May-2006 [NULL] 6.98
11-May-2006 11-May-2006 [NULL] 6.45
12-May-2006 12-May-2006 [NULL] 6.11
13-May-2006 13-May-2006 [NULL] 6.55
14-May-2006 14-May-2006 [NULL] 6.12
15-May-2006 15-May-2006 19-May-2006 6.91
16-May-2006 16-May-2006 19-May-2006 6.91
17-May-2006 17-May-2006 19-May-2006 6.91
18-May-2006 18-May-2006 19-May-2006 6.91
19-May-2006 19-May-2006 24-May-2006 6.38
20-May-2006 20-May-2006 [NULL] 6.72
21-May-2006 21-May-2006 [NULL] 6.34
22-May-2006 22-May-2006 [NULL] 6.78
23-May-2006 23-May-2006 [NULL] 6.28
24-May-2006 24-May-2006 [NULL] 6.38
25-May-2006 25-May-2006 [NULL] 6.18
26-May-2006 26-May-2006 [NULL] 6.72
27-May-2006 27-May-2006 [NULL] 6.56
28-May-2006 28-May-2006 [NULL] 6.24
29-May-2006 29-May-2006 [NULL] 6.43
30-May-2006 30-May-2006 5-Jun-2006 6.72
31-May-2006 31-May-2006 5-Jun-2006 6.72
1-Jun-2006 30-Jun-2006 [NULL] 6.72


I want the amt for pubdt to be as
if the pubdt is null amt stays same
for each pubdt get the amt of that date between stdt and eddt
starting on sort order stdt.
Please see data for dates 15 to 18 get amt from 19
and for 19 get amt from 24
Is it possible to write a sql for this.

Thanks


Functional, not flashy.

July 04, 2006 - 1:25 pm UTC

Reviewer: Tyler from Vancouver BC.

There are no shortages of assumptions being made here, but for the data you've provided, here's a solution :)

SELECT
PUBBY.STDT,
PUBBY.EDDT,
PUBBY.PUBDT,
CASE
WHEN PUBBY.AMT IS NULL
THEN
( SELECT p3.AMT
FROM (
SELECT
p2.AMT,
MAX(P2.EDDT) OVER () as max_date,
p2.EDDT
FROM PUB1 P2) P3
WHERE p3.EDDT = max_date)
ELSE
PUBBY.AMT
END AS AMT
FROM (
SELECT
P.STDT,
P.EDDT,
P.PUBDT,
CASE
WHEN P.PUBDT IS NOT NULL
THEN
( SELECT P1.AMT
FROM PUB1 P1
WHERE P1.EDDT = P.PUBDT)
ELSE
P.AMT
END AS AMT
FROM PUB1 P) PUBBY;


I think this works too...

July 04, 2006 - 2:50 pm UTC

Reviewer: Chris from Calgary, CANADA

SELECT stdt,
eddt,
pubdt,
(SELECT amt
FROM pub1 p4
WHERE p4.eddt = p3.pubdt2) amt
FROM (SELECT stdt,
eddt,
pubdt,
NVL2 (pubdt,
(SELECT MIN (p2.eddt)
FROM pub1