Ranking performance is slow

  • Thread starter Thread starter matthewwhaley
  • Start date Start date
M

matthewwhaley

I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.

Here are the pertinent issues and goals

1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)

Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!

SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking

FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;
 
You've probably got it correct, but make sure that horizon and businessName
are indexed appropriately. Otherwise, consider using a subroutine (or update
query) to calculate the ranking first and an additional field to store the
value. It'll still take a while but should not crash anymore. HTH.


I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.

Here are the pertinent issues and goals

1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)

Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!

SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking

FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;
 
I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.

Here are the pertinent issues and goals

1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)

Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!

SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking

FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;

Wow. I'm not surprised it's slow; you're having to make 977 passes
through the subquery, querying half a million records EACH pass. This
CAN'T be done fast.

Perhaps it can be done a bit faster than it is now; do you have
indexes on businessName, horizon and [New PnL]? Might it be possible
to move the "main member" data into one table and the points into a
related table, using a Long Integer as the linking field rather than
the less efficient two-field join?

John W. Vinson [MVP]
 
Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
 
Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
----

bye
--
Giorgio Rancati
[Office Access MVP]

<[email protected]> ha scritto nel messaggio

I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.
Here are the pertinent issues and goals
1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)
Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking
FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;- Hide quoted text -

- Show quoted text -

Wow. Thanks for all of the feedback. Just got into work this morning
and am going to give these options a shot.

This is my first post and I am amazed at the quick feedback. thanks.
I'll let you know how it goes
 
Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
----
<[email protected]> ha scritto nel messaggionews:[email protected]...
I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.
Here are the pertinent issues and goals
1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)
Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking
FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;- Hide quoted text -
- Show quoted text -

Wow. Thanks for all of the feedback. Just got into work this morning
and am going to give these options a shot.

This is my first post and I am amazed at the quick feedback. thanks.
I'll let you know how it goes- Hide quoted text -

- Show quoted text -


OK. Indexing the table and the code from Giorgio runs the query like
a champ. 10 minutes at most. Now I want to put the ranking into a
table.

I first tried an Update Query, but couldn't execute due to the
Count(*) statement.

Now I am doing a Delete/Append. The delete works easily, but the
Append runs, but returns as a Select query. It never pastes.

I then created a new append query based on the original incase there
was some aggregate function keeping from appending. I did this as a
Make table to and no matter how I set it up, it only returns as a
select. Below is the append query SQL.

Any thoughts


SELECT
qryNewPnLRank.businessdate, qryNewPnLRank.horizon,
qryNewPnLRank.businessName, qryNewPnLRank.closeDate,
qryNewPnLRank.i_pnlValue, qryNewPnLRank.businessID,
qryNewPnLRank.f_pnlValue, qryNewPnLRank.NewPnL, qryNewPnLRank.Ranking

INTO tblRankedNewinventoryPnLImpact_Made_from_Query

FROM qryNewPnLRank
 
Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
----
bye
--
Giorgio Rancati
[Office Access MVP]
<[email protected]> ha scritto nel messaggio
I have successfully created a ranking subQuery, but the performance is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.
Here are the pertinent issues and goals
1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did a
subset of half the members)
Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking
FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;- Hide quoted text -
- Show quoted text -
Wow. Thanks for all of the feedback. Just got into work this morning
and am going to give these options a shot.
This is my first post and I am amazed at the quick feedback. thanks.
I'll let you know how it goes- Hide quoted text -
- Show quoted text -

OK. Indexing the table and the code from Giorgio runs the query like
a champ. 10 minutes at most. Now I want to put the ranking into a
table.

I first tried an Update Query, but couldn't execute due to the
Count(*) statement.

Now I am doing a Delete/Append. The delete works easily, but the
Append runs, but returns as a Select query. It never pastes.

I then created a new append query based on the original incase there
was some aggregate function keeping from appending. I did this as a
Make table to and no matter how I set it up, it only returns as a
select. Below is the append query SQL.

Any thoughts

SELECT
qryNewPnLRank.businessdate, qryNewPnLRank.horizon,
qryNewPnLRank.businessName, qryNewPnLRank.closeDate,
qryNewPnLRank.i_pnlValue, qryNewPnLRank.businessID,
qryNewPnLRank.f_pnlValue, qryNewPnLRank.NewPnL, qryNewPnLRank.Ranking

INTO tblRankedNewinventoryPnLImpact_Made_from_Query

FROM qryNewPnLRank- Hide quoted text -

- Show quoted text -

Anyone had this happen before??
 
Are you executing the query or simply switching to the datasheet view?

If you click the run button (Red exclamation) or select Query: Run the query
should execute and create the table.

If you switch to datasheet view, you will see what WOULD be created if you
ran (executed) the query. In other words, a select query view of the
existing data in the existing table.

--
John Spencer
Access MVP 2002-2005, 2007
Center for Health Program Development and Management
University of Maryland Baltimore County
..

Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
----
<[email protected]> ha scritto nel
messaggionews:[email protected]...
I have successfully created a ranking subQuery, but the performance
is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.
Here are the pertinent issues and goals
1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did
a
subset of half the members)
Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking
FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;- Hide quoted
text -
- Show quoted text -

Wow. Thanks for all of the feedback. Just got into work this morning
and am going to give these options a shot.

This is my first post and I am amazed at the quick feedback. thanks.
I'll let you know how it goes- Hide quoted text -

- Show quoted text -


OK. Indexing the table and the code from Giorgio runs the query like
a champ. 10 minutes at most. Now I want to put the ranking into a
table.

I first tried an Update Query, but couldn't execute due to the
Count(*) statement.

Now I am doing a Delete/Append. The delete works easily, but the
Append runs, but returns as a Select query. It never pastes.

I then created a new append query based on the original incase there
was some aggregate function keeping from appending. I did this as a
Make table to and no matter how I set it up, it only returns as a
select. Below is the append query SQL.

Any thoughts


SELECT
qryNewPnLRank.businessdate, qryNewPnLRank.horizon,
qryNewPnLRank.businessName, qryNewPnLRank.closeDate,
qryNewPnLRank.i_pnlValue, qryNewPnLRank.businessID,
qryNewPnLRank.f_pnlValue, qryNewPnLRank.NewPnL, qryNewPnLRank.Ranking

INTO tblRankedNewinventoryPnLImpact_Made_from_Query

FROM qryNewPnLRank
 
Are you executing the query or simply switching to the datasheet view?

If you click the run button (Red exclamation) or select Query: Run the query
should execute and create the table.

If you switch to datasheet view, you will see what WOULD be created if you
ran (executed) the query. In other words, a select query view of the
existing data in the existing table.

--
John Spencer
Access MVP 2002-2005, 2007
Center for Health Program Development and Management
University of Maryland Baltimore County
.




On Feb 15, 4:22 am, "giorgio rancati"
Hi,
The Access subquery performance is bad
You can change the subquery with a Inner Join
try this query
----
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
COUNT(*) AS Ranking
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p
INNER JOIN
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
ON p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] >= p1.[New PnL]
GROUP BY
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL]
ORDER BY p.horizon,p.businessName,p.[New PnL]
----
bye
--
Giorgio Rancati
[Office Access MVP]
<[email protected]> ha scritto nel
messaggio
I have successfully created a ranking subQuery, but the performance
is
atrocious. Even after completing the query, scrolling through the
results causes it to freeze.
Here are the pertinent issues and goals
1) Local Data tbl has 490454 records consisting of 502 unique data
points for a main member (977 main members)
2) I created a ranking subquery that assigns 1-502 to each main
member's unique data points
3) It takes hours to complete (honestly it only completed when I did
a
subset of half the members)
Here is the full SQL. Any help to improve the code or tips on
performance would be greatly appreciated!
SELECT
p.businessdate, p.horizon, p.businessName, p.closeDate,
p.i_pnlValue, p.businessID, p.f_pnlValue, p.[New PnL],
(SELECT COUNT(*)
FROM
tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query as p1
WHERE
p.horizon = p1.horizon AND
p.businessName = p1.businessName AND
p.[New PnL] <= p1.[New PnL]) AS Ranking
FROM tblCurrFI_PnL_LESS_Inv_PnL_Made_from_Query AS p;- Hide quoted
text -
- Show quoted text -
Wow. Thanks for all of the feedback. Just got into work this morning
and am going to give these options a shot.
This is my first post and I am amazed at the quick feedback. thanks.
I'll let you know how it goes- Hide quoted text -
- Show quoted text -
OK. Indexing the table and the code from Giorgio runs the query like
a champ. 10 minutes at most. Now I want to put the ranking into a
table.
I first tried an Update Query, but couldn't execute due to the
Count(*) statement.
Now I am doing a Delete/Append. The delete works easily, but the
Append runs, but returns as a Select query. It never pastes.
I then created a new append query based on the original incase there
was some aggregate function keeping from appending. I did this as a
Make table to and no matter how I set it up, it only returns as a
select. Below is the append query SQL.
Any thoughts
SELECT
qryNewPnLRank.businessdate, qryNewPnLRank.horizon,
qryNewPnLRank.businessName, qryNewPnLRank.closeDate,
qryNewPnLRank.i_pnlValue, qryNewPnLRank.businessID,
qryNewPnLRank.f_pnlValue, qryNewPnLRank.NewPnL, qryNewPnLRank.Ranking
INTO tblRankedNewinventoryPnLImpact_Made_from_Query
FROM qryNewPnLRank- Hide quoted text -

- Show quoted text -

I was executing. I looked up another thread and they said that the
action queries can get corrupted if they are switched often. I
deleted it and recreated it and it is working fine.

Thanks everyone for their help.
 

Ask a Question

Want to reply to this thread or ask your own question?

You'll need to choose a username for the site, which only take a couple of moments. After that, you can post your question and our members will help you out.

Ask a Question

Back
Top