Join IIUG
 for   
 

Informix News
18 Nov 13 - ZDNet - Top 20 mobile skills in demand... Read
09 Sep 13 - telecompaper - Shaspa and Tatung have shown a new smart home platform at Ifa in Berlin. Powered by the IBM Informix software... Read
06 Sep 13 - IBM data magazine - Mission Accomplished - Miami, Florida will be the backdrop for the 2014 IIUG Informix Conference... Read
01 Feb 13 - IBM Data Magazine - Are your database backups safe? Lester Knutsen (IBM Champion) writes about database back up safety using "archecker"... Read
14 Nov 12 - IBM - IBM's Big Data For Smart Grid Goes Live In Texas... Read
3 Oct 12 - The Financial - IBM and TransWorks Collaborate to Help Louisiana-Pacific Corporation Achieve Supply Chain Efficiency... Read
28 Aug 12 - techCLOUD9 - Splunk kicks up a SaaS Storm... Read
10 Aug 12 - businessCLOUD9 - Is this the other half of Cloud monitoring?... Read
3 Aug 12 - IBM data management - Supercharging the data warehouse while keeping costs down IBM Informix Warehouse Accelerator (IWA) delivers superior performance for in-memory analytics processing... Read
2 Aug 12 - channelbiz - Oninit Group launches Pay Per Pulse cloud-based service... Read
28 May 12 - Bloor - David Norfolk on the recent Informix benchmark "pretty impressive results"... Read
23 May 12 - DBTA - Informix Genero: A Way to Modernize Informix 4GL Applications... Read
9 Apr 12 - Mastering Data Management - Upping the Informix Ante: Advanced Data Tools... Read
22 Mar 12 - developerWorks - Optimizing Informix database access... Read
14 Mar 12 - BernieSpang.com - International Informix User Group set to meet in San Diego... Read
1 Mar 12 - IBM Data Management - IIUG Heads West for 2012 - Get ready for sun and sand in San Diego... Read
1 Mar 12 - IBM Data Management - Running Informix on Solid-State Drives.Speed Up Database Access... Read
26 Feb 12 - BernieSpan.com - Better results, lower cost for a broad set of new IBM clients and partners... Read
24 Feb 12 - developerWorks - Informix Warehouse Accelerator: Continuous Acceleration during Data Refresh... Read
6 Feb 12 - PRLOG - Informix port delivers unlimited database scalability for popular SaaS application ... Read
2 Feb 12 - developerWorks - Loading data with the IBM Informix TimeSeries Plug-in for Data Studio... Read
1 Feb 12 - developerWorks - 100 Tech Tips, #47: Log-in to Fix Central... Read
13 Jan 12 - MC Press online - Informix Dynamic Server Entices New Users with Free Production Edition ... Read
11 Jan 12 - Computerworld - Ecologic Analytics and Landis+Gyr -- Suitors Decide to Tie the Knot... Read
9 Jan 12 - planetIDS.com - DNS impact on Informix / Impacto do DNS no Informix... Read
8 Sep 11 - TMCnet.com - IBM Offers Database Solution to Enable Smart Meter Data Capture... Read
1 Aug 11 - IBM Data Management Magazine - IIUG user view: Happy 10th anniversary to IBM and Informix... Read
8 Jul 11 - Database Trends and Applications - Managing Time Series Data with Informix... Read
31 May 11 - Smart Grid - The meter data management pitfall utilities are overlooking... Read
27 May 11 - IBM Data Management Magazine - IIUG user view: Big data, big time ( Series data, warehouse acceleration, and 4GLs )... Read
16 May 11 - Business Wire - HiT Software Announces DBMoto for Enterprise Integration, Adds Informix. Log-based Change Data Capture... Read
21 Mar 11 - Yahoo! Finance - IBM and Cable&Wireless Worldwide Announce UK Smart Energy Cloud... Read
14 Mar 11 - MarketWatch - Fuzzy Logix and IBM Unveil In-Database Analytics for IBM Informix... Read
11 Mar 11 - InvestorPlace - It's Time to Give IBM Props: How many tech stocks are up 53% since the dot-com boom?... Read
9 Mar 11 - DBTA - Database Administration and the Goal of Diminishing Downtime... Read
2 Feb 11 - DBTAs - Informix 11.7 Flexible Grid Provides a Different Way of Looking at Database Servers... Read
27 Jan 11 - exactsolutions - Exact to Add Informix Support to Database Replay, SQL Monitoring Solutions... Read
25 Jan 11 - PR Newswire - Bank of China in the UK Works With IBM to Become a Smarter, Greener Bank... Read
12 Oct 10 - Database Trends and Applications - Informix 11.7: The Beginning of the Next Decade of IBM Informix... Read
20 Sep 10 - planetIDS.com - ITG analyst paper: Cost/Benefit case for IBM Informix as compared to Microsoft SQL Server... Read
20 Jul 10 - IBM Announcements - IBM Informix Choice Edition V11.50 helps deploy low-cost scalable and reliable solutions for Apple Macintosh and Microsoft Windows... Read
20 Jul 10 - IBM Announcements - Software withdrawal: Elite Support for Informix Ultimate-C Edition... Read
24 May 10 - eWeek Europe - IBM Supplies Database Tech For EU Smart Grid... Read
23 May 10 - SiliconIndia - IBM's smart metering system allows wise use of energy... Read
21 May 10 - CNET - IBM to help people monitor energy use... Read
20 May 10 - ebiz - IBM Teams With Hildebrand To Bring Smart Metering To Homes Across Britain... Read
19 May 10 - The New Blog Times - Misurare il consumo energetico: DEHEMS è pronto... Read
19 May 10 - ZDNet - IBM software in your home? Pact enables five-city smart meter pilot in Europe... Read
17 March 10 - ZDNet (blog) David Morgenstern - TCO: New research finds Macs in the enterprise easier, cheaper to manage than... Read
17 March 2010 - Virtualization Review - ...key components of Big Blue's platform to the commercial cloud such as its WebSphere suite of application ser vers and its DB2 and Informix databases... Read
10 February 2010 - The Wall Street Journal - International Business Machines is expanding an initiative to win over students and professors on its products. How do they lure the college crowd?... Read


End of Support Dates

IIUG on Facebook IIUG on Twitter

[ View Thread ] [ Post Response ] [ Return to Index ] [ Read Prev Msg ] [ Read Next Msg ]

IDS Forum

RE: Challenging : Aggregating several columns ....

Posted By: Andrew Ford
Date: Thursday, 14 March 2013, at 2:50 a.m.

In Response To: Re: Challenging : Aggregating several columns to s (Cesar Inacio Martins)

I think this works.

Join the table to itself 3 times to transpose the id and data fields of each
category into columns of a row and only return rows where id1 < id2 < id3.

Then left outer join this result to itself on the sum of the table n ids
being greater than the sum of the table m ids and the m row with no matching
n row must be the one with the highest sum of consecutive ids and therefore
the 3 largest ids for the category.

create temp table t(

id smallint,

cat smallint,

data char(10)
) with no log;

insert into t values (1, 1, "foo");
insert into t values (2, 1, "bar");
insert into t values (3, 1, "baz");
insert into t values (4, 2, "some");
insert into t values (5, 2, "random");
insert into t values (6, 3, "Data 1");
insert into t values (7, 2, "data");
insert into t values (8, 3, "Data 2");
insert into t values (9, 3, "Data 3");
insert into t values (10, 4, "some");
insert into t values (11, 4, "more");
insert into t values (12, 4, "random");
insert into t values (13, 4, "data");
insert into t values (14, 4, "for");
insert into t values (15, 4, "testing");

select

m.cat,

m.id1,

m.data1,

m.id2,

m.data2,

m.id3,

m.data3
from

(

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) m left outer join (

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) n on

n.cat = m.cat and

n.id1 + n.id2 + n.id3 > m.id1 + m.id2 + m.id3
where

n.cat is null;

Here are the results of a test.

cat id1 data1 id2 data2 id3 data3

1 1 foo 2 bar 3 baz

2 4 some 5 random 7 data

3 6 Data 1 8 Data 2 9 Data 3

4 13 data 14 for 15 testing

Here is the query plan, you'll probably want to create some indexes.

QUERY: (OPTIMIZATION TIMESTAMP: 03-14-2013 01:42:43)
------
select

m.cat,

m.id1,

m.data1,

m.id2,

m.data2,

m.id3,

m.data3
from

(

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) m left outer join (

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) n on

n.cat = m.cat and

n.id1 + n.id2 + n.id3 > m.id1 + m.id2 + m.id3
where

n.cat is null

Estimated Cost: 16
Estimated # of Rows Returned: 1

1) informix.t1: SEQUENTIAL SCAN

2) informix.t2: SEQUENTIAL SCAN

DYNAMIC HASH JOIN

Dynamic Hash Filters: informix.t2.cat = informix.t1.cat

Other Join Filters: informix.t2.id > informix.t1.id

3) informix.t3: SEQUENTIAL SCAN

DYNAMIC HASH JOIN

Dynamic Hash Filters: informix.t1.cat = informix.t3.cat

Other Join Filters: informix.t3.id > informix.t2.id

QUERY: (OPTIMIZATION TIMESTAMP: 03-14-2013 01:42:43)
------
select

m.cat,

m.id1,

m.data1,

m.id2,

m.data2,

m.id3,

m.data3
from

(

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) m left outer join (

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) n on

n.cat = m.cat and

n.id1 + n.id2 + n.id3 > m.id1 + m.id2 + m.id3
where

n.cat is null

Estimated Cost: 16
Estimated # of Rows Returned: 1

1) informix.t1: SEQUENTIAL SCAN

2) informix.t2: SEQUENTIAL SCAN

DYNAMIC HASH JOIN

Dynamic Hash Filters: informix.t2.cat = informix.t1.cat

Other Join Filters: informix.t2.id > informix.t1.id

3) informix.t3: SEQUENTIAL SCAN

DYNAMIC HASH JOIN

Dynamic Hash Filters: informix.t1.cat = informix.t3.cat

Other Join Filters: informix.t3.id > informix.t2.id

QUERY: (OPTIMIZATION TIMESTAMP: 03-14-2013 01:42:43)
------
select

m.cat,

m.id1,

m.data1,

m.id2,

m.data2,

m.id3,

m.data3
from

(

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) m left outer join (

select

t1.cat,

t1.id id1,

t1.data data1,

t2.id id2,

t2.data data2,

t3.id id3,

t3.data data3

from

t t1,

t t2,

t t3

where

t2.cat = t1.cat and

t3.cat = t2.cat and

t3.id > t2.id and

t2.id > t1.id

) n on

n.cat = m.cat and

n.id1 + n.id2 + n.id3 > m.id1 + m.id2 + m.id3
where

n.cat is null

Estimated Cost: 8
Estimated # of Rows Returned: 1

1) (Temp Table For Collection Subquery): SEQUENTIAL SCAN

2) (Temp Table For Collection Subquery): AUTOINDEX PATH

(1) Index Name: (Auto Index)

Index Keys: cat

Lower Index Filter: (Temp Table For Collection Subquery).cat =
(Temp Table For Collection Subquery).cat

ON-Filters:((Temp Table For Collection Subquery).cat = (Temp Table For
Collection Subquery).cat AND (Temp Table For Collection Subquery).id1 +
(Temp Table For Collection Subquery).id2 + (Temp Table For Collection
Subquery).id3 > (Temp Table For Collection Subquery).id1 + (Temp Table For
Collection Subquery).id2 + (Temp Table For Collection Subquery).id3 )

NESTED LOOP JOIN(LEFT OUTER JOIN)

PostJoin-Filters:(Temp Table For Collection Subquery).cat IS NULL

Andrew

-----Original Message-----
From: ids-bounces@iiug.org [mailto:ids-bounces@iiug.org] On Behalf Of Cesar
Inacio Martins
Sent: Wednesday, March 13, 2013 7:21 AM
To: ids@iiug.org
Subject: Re: Challenging : Aggregating several columns .... [29730]

Hi Fernando,

This is something what I try before , the problem is have all fields of same
row togheter... where difficult use the data without include a treatment to
separate each information.

expression MULTISET{'1,1,foo ','2,1,bar ','3,1,baz '} expression
MULTISET{'4,2,some ','5,2,random ','7,2,data '} expression
MULTISET{'6,3,Data 1 ','8,3,Data 2 ','9,3,Data 3 '}

2013/3/13 Fernando Nunes <domusonline@gmail.com>

> Food for thought:
>
> drop table teste;
> create temp table teste ( id smallint, cat smallint, data char(10));
> insert into teste values ( 1, 1, 'foo ' ); insert into teste values (
> 2, 1, 'bar ' ); insert into teste values ( 3, 1, 'baz ' ); insert into
> teste values ( 4, 2, 'some ' ); insert into teste values ( 5, 2,
> 'random ' ); insert into teste values ( 6, 3, 'Data 1 ' ); insert into
> teste values ( 7, 2, 'data ' ); insert into teste values ( 8, 3, 'Data
> 2 ' ); insert into teste values ( 9, 3, 'Data 3 ' ); insert into teste
> values ( 10, 3, 'Data 4 ' );
>
> select * from teste;
> select ms.*
> from
> (
> SELECT MULTISET( SELECT ITEM t.id || ',' || t.cat || ',' || t.data m1
> FROM teste t WHERE t.cat = tout.cat) FROM (SELECT unique cat from
> teste) tout
> ) ms
>
>
>
>
> On Wed, Mar 13, 2013 at 12:01 AM, Cesar Inacio Martins <
> cesar.inacio.martins@gmail.com> wrote:
>
>>
>> This is something where I always see as huge challenge when need to
>> play only with DML on Informix.
>> I play now a little with this... and get no easy/simple solution, so
>> far...
>>
>> Get this data :
>>
>> drop table teste;
>> create temp table teste ( id smallint, cat smallint, data char(10));
>> insert into teste values ( 1, 1, 'foo ' ); insert into teste values (
>> 2, 1, 'bar ' ); insert into teste values ( 3, 1, 'baz ' ); insert
>> into teste values ( 4, 2, 'some ' ); insert into teste values ( 5, 2,
>> 'random ' ); insert into teste values ( 6, 3, 'Data 1 ' ); insert
>> into teste values ( 7, 2, 'data ' ); insert into teste values ( 8, 3,
>> 'Data 2 ' ); insert into teste values ( 9, 3, 'Data 3 ' );
>>
>> and transform into this :
>>
>> cat id1 data1 id2 data2 id3 data3
>> -----------------------------------------------------
>> 1 1 foo 2 bar 3 baz
>> 2 4 some 5 random 7 data
>> 3 6 Data 1 8 Data 2 9 Data 3
>>
>> Where the logic is : aggregate into single line the 3 lines what have
>> the same "cat" .
>> This is possible on ifx 11.70 ? or 12.1?
>> Only with DML... no SPL. (consider the user/system don't have grant
>> to create procedure)
>>
>> Original question :
>>
http://stackoverflow.com/questions/15368750/aggregating-several-columns-to-s
ingle-colum
>>
>> Regards
>> Cesar
>>
>> _______________________________________________
>> Informix-list mailing list
>> Informix-list@iiug.org
>> http://www.iiug.org/mailman/listinfo/informix-list
>>
>>
>
>
> --
> Fernando Nunes
> Portugal
>
> http://informix-technology.blogspot.com
> My email works... but I don't check it frequently...
>

--001a11c240489aadd504d7cd70c2

****************************************************************************
***
Forum Note: Use "Reply" to post a response in the discussion forum.

Messages In This Thread

[ View Thread ] [ Post Response ] [ Return to Index ] [ Read Prev Msg ] [ Read Next Msg ]

IDS Forum is maintained by Administrator with WebBBS 5.12.