473,811 Members | 3,402 Online
Bytes | Software Development & Data Engineering Community
+ Post

Home Posts Topics Members FAQ

Query Help.

I have this query that I need to speed up. I don't know where to
start. Any advise would be greatly apreciated

SELECT
centerID AS [Center ID], StoreID AS [Store Code], Region, City AS
City, Owner AS [Owner Name], Brand AS Brand,
(SELECT OrderDate FROM [ORDER] WHERE StoreID = S.StoreID AND revid =
0 AND programid = 4) AS [BS Enrollment Date],
(SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID AND
P_PrintID like '%BrandSmart%' and P_PromoMonth = @Month and
P_PromoYear = @Year) AS [BS Quantity],
CASE S.Brand
WHEN 'Allegra Print & Imaging' THEN 75
WHEN 'American Speedy Printing' THEN 75
WHEN 'Insty-Prints' THEN 100
ELSE 0
END
As [BS HO Quantity],
((SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID AND
P_PrintID like '%BrandSmart%' and P_PromoMonth = @Month and
P_PromoYear = @Year) - CASE
WHEN (SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID
AND P_PrintID like '%BrandSmart%' and P_PromoMonth = @Month and
P_PromoYear = @Year) = 0 then 0
WHEN S.Brand = 'Allegra Print & Imaging' THEN 75
WHEN S.Brand = 'American Speedy Printing' THEN 75
WHEN S.Brand = 'Insty-Prints' THEN 100
ELSE 0
END)
as [Billable BS],
(SELECT count(*) FROM production WHERE P_DateResponded is not null
and P_S_RecID = S.StoreID AND P_PrintID like '%LeadSmart%' and
P_PromoMonth = @Month and P_PromoYear = @Year) AS [BS Leads],
(SELECT OrderDate FROM [ORDER] WHERE StoreID = S.StoreID AND revid =
0 AND programid = 5) AS [LS Enrollment Date],
(SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID AND
P_PrintID like '%LeadSmart%' and P_PromoMonth = @Month and P_PromoYear
= @Year) AS [LS Quantity],
CASE
WHEN S.Brand = 'Insty-Prints' THEN 300
ELSE 0
END
As [LS HO Quantity],
((SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID AND
P_PrintID like '%LeadSmart%' and P_PromoMonth = @Month and P_PromoYear
= @Year) - CASE
WHEN (SELECT count(*) FROM production WHERE P_S_RecID = S.StoreID
AND P_PrintID like '%LeadSmart%' and P_PromoMonth = @Month and
P_PromoYear = @Year) = 0 then 0
WHEN S.Brand = 'Insty-Prints' THEN 300
ELSE 0
END)
as [Billable LS],
'0' as [LS Newsletter Quantity],
'0' as [New Business Quantity],
(Select Original_Record _Count From User_Lists WHERE Type = 'Accudata'
and User_ID = S.StoreID and Order_ID is not null) as [Prospect List
Quantity],
1000 as [Allegra HO Quantity],
50 as [Enrollment Fee],
UCC.[Name] as [Name on CC],
UCC.Type as [CC Type],
UCC.Number as [CC Number],
UCC.Expiration_ Date as [CC Exp Date],
SBI.SBI_Address 1 as [Address 1],
SBI.SBI_ZipCode as [Zip Code],
(Case
When s.UserCC = 1 then 'No'
ELSE 'Yes'
END) as [Invoiced]
FROM dbo.Stores S LEFT JOIN User_Credit_Car ds UCC
ON S.StoreID = UCC.User_ID LEFT JOIN StoresBillingIn fo SBI
ON S.StoreID = SBI.SBI_S_Store ID
WHERE
(StoreID NOT LIKE '%test%') AND
(StoreID <'admin') ANd
((SELECT OrderDate FROM [ORDER] WHERE StoreID = S.StoreID AND revid =
0 AND programid = 5) is not null OR
(SELECT OrderDate FROM [ORDER] WHERE StoreID = S.StoreID AND revid =
0 AND programid = 4) is not null)

Apr 6 '07 #1
2 1422
Designing Solutions WD wrote:
I have this query that I need to speed up. I don't know where to
start. Any advise would be greatly apreciated
Indexes probably make a lot of difference. Which ones have you
defined? Which ones are more/less restrictive on the data? (e.g.
"30% of the records have StoreID = 'Southwest' but only 1% have
CenterID = 'Phoenix')

The pattern searches on production.P_Pr intID and Stores.StoreID
can't be helping matters. How many of each do you have? Assuming
there's another table Printers with P_PrintID as its primary key,
you may be able to speed things up by using the following:

create view BS_Printers as
select P_PrintID from Printers where P_PrintID like '%BrandSmart%'

create view LS_Printers as
select P_PrintID from Printers where P_PrintID like '%LeadSmart%'

Here's a first stab at refactoring. Note the comments. Less redundancy
means less opportunity to screw things up by changing one block but
forgetting to change another. Pre-loading the #quantities temp table
may make the speed better / worse / about the same; unless it makes it
significantly worse, I recommend sticking with it.

-- Column types are educated guesses. Insert "post DDL" rant here.
create table #quantities (
StoreID varchar(10),
PromoMonth int,
PromoYear int,
BS_Quantity int,
LS_Quantity
)
go

insert into #quantities (
StoreID,
PromoMonth,
PromoYear,
BS_Quantity,
LS_Quantity
)
select
P_S_RecID,
P_PromoMonth,
P_PromoYear,
sum(case when P_PrintID like '%BrandSmart%' then 1 else 0 end)
as BS_Quantity,
sum(case when P_PrintID like '%LeadSmart%' then 1 else 0 end)
as LS_Quantity,
-- Did you really mean to combine LeadSmart with BS like this?
sum(case when P_PrintID like '%LeadSmart%'
and P_DateResponded is not null then 1 else 0 end) as BS_Leads
from production
group by P_S_RecID, P_PromoMonth, P_PromoYear
go

SELECT
centerID AS [Center ID],
StoreID AS [Store Code],
Region,
City AS City,
Owner AS [Owner Name],
Brand AS Brand,
o_bs.OrderDate as [BS Enrollment Date],
q.BS_Quantity as [BS Quantity],
CASE S.Brand
WHEN 'Allegra Print & Imaging' THEN 75
WHEN 'American Speedy Printing' THEN 75
WHEN 'Insty-Prints' THEN 100
ELSE 0
END As [BS HO Quantity],
(q.BS_Quantity - case
WHEN q.BS_Quantity = 0 then 0
WHEN S.Brand = 'Allegra Print & Imaging' THEN 75
WHEN S.Brand = 'American Speedy Printing' THEN 75
WHEN S.Brand = 'Insty-Prints' THEN 100
ELSE 0
END) as [Billable BS],
q.BS_Leads AS [BS Leads],
o_ls.OrderDate as [LS Enrollment Date],
q.LS_Quantity AS [LS Quantity],
CASE
WHEN S.Brand = 'Insty-Prints' THEN 300
ELSE 0
END As [LS HO Quantity],
(q.LS_Quantity - CASE
WHEN q.LS_Quantity = 0 then 0
WHEN S.Brand = 'Insty-Prints' THEN 300
ELSE 0
END) as [Billable LS],
'0' as [LS Newsletter Quantity],
'0' as [New Business Quantity],
ul.Original_Rec ord_Count as [Prospect List Quantity],
1000 as [Allegra HO Quantity],
50 as [Enrollment Fee],
UCC.[Name] as [Name on CC],
UCC.Type as [CC Type],
UCC.Number as [CC Number],
UCC.Expiration_ Date as [CC Exp Date],
SBI.SBI_Address 1 as [Address 1],
SBI.SBI_ZipCode as [Zip Code],
(Case
When s.UserCC = 1 then 'No'
ELSE 'Yes'
END) as [Invoiced]
FROM dbo.Stores S
left join #quantities q
on S.StoreID = q.StoreID and @Month = q.PromoMonth
and @Year = q.PromoYear
LEFT JOIN User_Credit_Car ds UCC ON S.StoreID = UCC.User_ID
LEFT JOIN StoresBillingIn fo SBI ON S.StoreID = SBI.SBI_S_Store ID
join ORDER o_bs
on S.StoreID = o_bs.StoreID and o_bs.revid = 0
and o_bs.programid = 4
join ORDER o_ls
on S.StoreID = o_ls.StoreID and o_ls.revid = 0
and o_ls.programid = 5
left join User_Lists ul
on S.StoreID = ul.User_ID and ul.Type = 'Accudata'
and ul.Order_ID is not null
WHERE StoreID not like '%test%'
and StoreID <'admin'
and o_bs.OrderDate is not null
and o_ls.OrderDate is not null
go

drop table #quantities
go
Apr 6 '07 #2
Ed,

You are a my hero.

Thank you so much I will give your code a detailed look but that
worked wonders 33 seconds down to 3 second.

Michael

Apr 6 '07 #3

This thread has been closed and replies have been disabled. Please start a new discussion.

Similar topics

9
3141
by: netpurpose | last post by:
I need to extract data from this table to find the lowest prices of each product as of today. The product will be listed/grouped by the name only, discarding the product code - I use SUBSTRING(ProductName, 1, CHARINDEX('(', ProductName)-2). I can get this result, but I had to use several views (totally inefficient). I think this can be done in one efficient/fast query, but I can't think of one. In the case that one query is not...
7
5974
by: Simon Bailey | last post by:
How do you created a query in VB? I have a button on a form that signifies a certain computer in a computer suite. On clicking on this button i would like to create a query searching for all details invovling that computer, for the user to then view. Any ideas on some code? Many thanks for any help.
4
2078
by: d.p. | last post by:
Hi all, I'm using MS Access 2003. Bare with me on this description....here's the situation: Imagine insurance, and working out premiums for different insured properties. The rates for calculating premiums are dependant on the country in which the client is in. Therefore, we have a Country table, with its list of rates, a client table and then the property table. Getting this is great, works fine, easy! Problem is, now I need to work out a...
4
2863
by: Alan Lane | last post by:
Hello world: I'm including both code and examples of query output. I appologize if that makes this message longer than it should be. Anyway, I need to change the query below into a pivot table query. I'm having trouble doing it. Help! Here is my code so far: Sub OldRegionQuery()
36
3076
by: Liam.M | last post by:
hey guys, I have one last problem to fix, and then my database is essentially done...I would therefore very much appreciate any assistance anyone would be able to provide me with. Currently I have set up a Query to show only records that meet a certain criteria...therefore excluding all of the records that do not meet this criteria (just for the record the criteria is any record within my database that falls within two months of its "Due...
5
7372
by: elitecodex | last post by:
Hey everyone. I have this query select * from `TableName` where `SomeIDField` 0 I can open a mysql command prompt and execute this command with no issues. However, Im trying to issue the same command inside of mysql_real_query and I keep on getting this error back. "You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use
10
6239
by: aaronrm | last post by:
I have a real simple cross-tab query that I am trying to sum on as the action but I am getting the "data type mismatch criteria expression" error. About three queries up the food chain from this cross-tab query I am using a simple query with no grouping where I am filtering some data out in the criteria line. I have been out of access for a couple years but I remember in the past I had a solution for this but I can't remember. Any help...
11
16338
by: funky | last post by:
hello, I've got a big problem ad i'm not able to resolve it. We have a server running oracle 10g version 10.1.0. We usually use access as front end and connect database tables for data extraction. We have been using oracle client 10.1.0.2 with it's odbc for a while without problem. The problem arose when we decided to reconnect all the tables and save password. Some query became suddenly very slow. Then I've discovered that the tables...
4
2045
by: Doris | last post by:
It does not look like my message is posting....if this is a 2nd or 3rd message, please forgive me as I really don't know how this site works. I want to apologize ahead of time for being a novice with MS Access and VBA. I desperately need help with 2 queries that I am trying to put together. I want to thank anyone that can help me out with this situation. I want to put a select query(Query1) that uses one table and the criteria would...
6
4412
by: jsacrey | last post by:
Hey everybody, got a secnario for ya that I need a bit of help with. Access 97 using linked tables from an SQL Server 2000 machine. I've created a simple query using two tables joined by one field between them. The join field in both tables are indexed and I'm selecting 1 field from each table to lookup. The Access query is taking more than 60 second to retrieve 1 record and if I execute the same query within the Query Analyzer, it...
0
10647
Oralloy
by: Oralloy | last post by:
Hello folks, I am unable to find appropriate documentation on the type promotion of bit-fields when using the generalised comparison operator "<=>". The problem is that using the GNU compilers, it seems that the internal comparison operator "<=>" tries to promote arguments from unsigned to signed. This is as boiled down as I can make it. Here is my compilation command: g++-12 -std=c++20 -Wnarrowing bit_field.cpp Here is the code in...
0
10384
jinu1996
by: jinu1996 | last post by:
In today's digital age, having a compelling online presence is paramount for businesses aiming to thrive in a competitive landscape. At the heart of this digital strategy lies an intricately woven tapestry of website design and digital marketing. It's not merely about having a website; it's about crafting an immersive digital experience that captivates audiences and drives business growth. The Art of Business Website Design Your website is...
0
10130
tracyyun
by: tracyyun | last post by:
Dear forum friends, With the development of smart home technology, a variety of wireless communication protocols have appeared on the market, such as Zigbee, Z-Wave, Wi-Fi, Bluetooth, etc. Each protocol has its own unique characteristics and advantages, but as a user who is planning to build a smart home system, I am a bit confused by the choice of these technologies. I'm particularly interested in Zigbee because I've heard it does some...
1
7667
isladogs
by: isladogs | last post by:
The next Access Europe User Group meeting will be on Wednesday 1 May 2024 starting at 18:00 UK time (6PM UTC+1) and finishing by 19:30 (7.30PM). In this session, we are pleased to welcome a new presenter, Adolph Dupré who will be discussing some powerful techniques for using class modules. He will explain when you may want to use classes instead of User Defined Types (UDT). For example, to manage the data in unbound forms. Adolph will...
0
6887
by: conductexam | last post by:
I have .net C# application in which I am extracting data from word file and save it in database particularly. To store word all data as it is I am converting the whole word file firstly in HTML and then checking html paragraph one by one. At the time of converting from word file to html my equations which are in the word document file was convert into image. Globals.ThisAddIn.Application.ActiveDocument.Select();...
0
5692
by: adsilva | last post by:
A Windows Forms form does not have the event Unload, like VB6. What one acts like?
1
4338
by: 6302768590 | last post by:
Hai team i want code for transfer the data from one system to another through IP address by using C# our system has to for every 5mins then we have to update the data what the data is updated we have to send another system
2
3865
muto222
by: muto222 | last post by:
How can i add a mobile payment intergratation into php mysql website.
3
3017
bsmnconsultancy
by: bsmnconsultancy | last post by:
In today's digital era, a well-designed website is crucial for businesses looking to succeed. Whether you're a small business owner or a large corporation in Toronto, having a strong online presence can significantly impact your brand's success. BSMN Consultancy, a leader in Website Development in Toronto offers valuable insights into creating effective websites that not only look great but also perform exceptionally well. In this comprehensive...

By using Bytes.com and it's services, you agree to our Privacy Policy and Terms of Use.

To disable or enable advertisements and analytics tracking please visit the manage ads & tracking page.