473,387 Members | 1,904 Online
Bytes | Software Development & Data Engineering Community
Post Job

Home Posts Topics Members FAQ

Join Bytes to post your question to a community of 473,387 software developers and data experts.

My design - where did I go wrong?

CREATE TABLE Sales1
(
varchar (10) CustID,
varchar (10) TransID,
datetime SaleDate,
money S1,
money S2,
money S3,
money S4,
numeric V1
)

CREATE NONCLUSTERED INDEX Sales1_CustID ON Sales1 (CustID)

CREATE NONCLUSTERED INDEX Sales1_SaleDate ON Sales1 (SaleDate)

"money" is just the right size for my fields. This table has 9,500,000
records.

Although I need to do this select in less than a half second, it takes 1
full minute:
SELECT MAX(S1) FROM Sales1 WHERE SaleDate > '1/1/2005'

And I need to do this select in less than a half second, but it takes 3
minutes:
SELECT AVG(S1 / S2) FROM Sales1 WHERE S3 > S4

Am I supposed to create a new field with these values pre-calculated? I hope
not, because I have several other formulas - up to 500 different types of
selects which are all similar.

I am testing with SQL 2000 Developer. XEON CPU, fast SATA hard drive and 2GB
of memory.

Thanks
Jul 29 '05 #1
7 1488
See inline

Rich wrote:

CREATE TABLE Sales1
(
varchar (10) CustID,
varchar (10) TransID,
datetime SaleDate,
money S1,
money S2,
money S3,
money S4,
numeric V1
)
This is not proper DDL. In a proper CREATE TABLE statement the column
name comes first, then its data type.

The columns S1, S2, S3, S4 and V1 have very poor names. You haven't
specified what these columns represent. I sure hope your table is
properly normalized.
CREATE NONCLUSTERED INDEX Sales1_CustID ON Sales1 (CustID)

CREATE NONCLUSTERED INDEX Sales1_SaleDate ON Sales1 (SaleDate)
Your table is missing a Primary Key constraint. What is the table's key?
Is it the combination of CustID and SaleDate? Please add a Primary Key.
It will automatically be uniquely indexed.
"money" is just the right size for my fields. This table has 9,500,000
records.

Although I need to do this select in less than a half second, it takes 1
full minute:
SELECT MAX(S1) FROM Sales1 WHERE SaleDate > '1/1/2005'
If you really use a literal (as in the example above) and the index
statistics are up to date, then the query will be as fast as possible.

However, if in reality you are using a local variable or parameter (for
example ... WHERE SaleDate > @SomeDate) then SQL-Server might not know
that the index is useful. In that case you could check out the
performance if you add an Index Hint.

Please note that the preferred dateformat is '20050101' or
'2005-01-01T00:00:00', because this is a safe notation. The
interpretation of '1/1/2005' will depend on the server language.
And I need to do this select in less than a half second, but it takes 3
minutes:
SELECT AVG(S1 / S2) FROM Sales1 WHERE S3 > S4
There is currently no index on (S3,S4). And even if there was, then it
is still not clear if it could be used (you would have to check that). I
doubt that you will get this query to 0.5 seconds. What does the query
mean anyway? It is a very strange query in the context of a Sales table
with a CustID column. It looks like a reporting query, not a query that
requires a performance of < 0.5 seconds.

Note that it is not safe to divide money data types, because the result
will also be a money data type. First of all, money divided by money
results in a ratio, not another money amount. Second, all precision
beyond the 4th decimal is lost in a money data type, so your ratio will
only have 4 decimals. Casting the S1 and S2 values to decimal should
solve that problem.
Am I supposed to create a new field with these values pre-calculated? I hope
not, because I have several other formulas - up to 500 different types of
selects which are all similar.
You could have a look indexed views. They could hurt
Insert/Update/Delete performance, but it may enable you to run this
reporting type queries pretty fast.

On the other hand, have a good look at what you need to achieve, and if
you really need the performance you are asking for. It might mean you
have to redesign your solution, because processing full 9.5 million rows
will never be lightning fast...

Gert-Jan
I am testing with SQL 2000 Developer. XEON CPU, fast SATA hard drive and 2GB
of memory.

Thanks

Jul 29 '05 #2
Rich (no@spam.invalid) writes:
CREATE TABLE Sales1
(
varchar (10) CustID,
varchar (10) TransID,
datetime SaleDate,
money S1,
money S2,
money S3,
money S4,
numeric V1
)

CREATE NONCLUSTERED INDEX Sales1_CustID ON Sales1 (CustID)

CREATE NONCLUSTERED INDEX Sales1_SaleDate ON Sales1 (SaleDate)

"money" is just the right size for my fields. This table has 9,500,000
records.

Although I need to do this select in less than a half second, it takes 1
full minute:
SELECT MAX(S1) FROM Sales1 WHERE SaleDate > '1/1/2005'
Add S1 to the non-clustered index. Or make the index on SaleDate clustered.
And I need to do this select in less than a half second, but it takes 3
minutes:
SELECT AVG(S1 / S2) FROM Sales1 WHERE S3 > S4
That's a tough one. With that requirement for response time, it seems
that you would need to add a computed column with S3-S4 and then index
that column, and add S1 and S2 to that index. And rewrite the query as
"WHERE S3_minus_S4 > 0". Alternatively define an indexed view on this
condition.

Under the current circumstances, SQL Server will have to scan the
entire table.
Am I supposed to create a new field with these values pre-calculated? I
hope not, because I have several other formulas - up to 500 different
types of selects which are all similar.


Ouch. Well, it seems that you need to do a more thorough review or
the requiremens and make a new design.

--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 29 '05 #3

"Erland Sommarskog" <es****@sommarskog.se> wrote in message
news:Xn*********************@127.0.0.1...
Rich (no@spam.invalid) writes:
CREATE TABLE Sales1
(
varchar (10) CustID,
varchar (10) TransID,
datetime SaleDate,
money S1,
money S2,
money S3,
money S4,
numeric V1
)

CREATE NONCLUSTERED INDEX Sales1_CustID ON Sales1 (CustID)

CREATE NONCLUSTERED INDEX Sales1_SaleDate ON Sales1 (SaleDate)

"money" is just the right size for my fields. This table has 9,500,000
records.

Although I need to do this select in less than a half second, it takes 1
full minute:
SELECT MAX(S1) FROM Sales1 WHERE SaleDate > '1/1/2005'
Add S1 to the non-clustered index. Or make the index on SaleDate

clustered.
And I need to do this select in less than a half second, but it takes 3
minutes:
SELECT AVG(S1 / S2) FROM Sales1 WHERE S3 > S4


That's a tough one. With that requirement for response time, it seems
that you would need to add a computed column with S3-S4 and then index
that column, and add S1 and S2 to that index. And rewrite the query as
"WHERE S3_minus_S4 > 0". Alternatively define an indexed view on this
condition.

Under the current circumstances, SQL Server will have to scan the
entire table.
Am I supposed to create a new field with these values pre-calculated? I
hope not, because I have several other formulas - up to 500 different
types of selects which are all similar.


Ouch. Well, it seems that you need to do a more thorough review or
the requiremens and make a new design.

--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp

Thanks Erland. I've also just started reading about Real-Time OLAP cubes and
Analysis Services. Would this help me in any way?

Richard
Jul 29 '05 #4
Rich (no@spam.invalid) writes:
Thanks Erland. I've also just started reading about Real-Time OLAP cubes
and Analysis Services. Would this help me in any way?


Maybe. Or to be more frank: I don't have the faintest idea. I have
never looked Analysis Services, so I can't tell.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 29 '05 #5
>> I've also just started reading about Real-Time OLAP cubes and Analysis Services. Would this help me in any way? <<

This is probably the best answer, but in the meantime you can do a VIEW
with all the summaries: Basically convert all of your WHERE clauses
into CASE expressions

SELECT MAX (CASE WHEN sale_date > '2005-01-01' THEN s1 END),
AVG (CASE WHEN S3 > S4 THEN (s1 / s2) END),
etc.
FROM Sales1 ;

Jul 30 '05 #6
--CELKO-- (jc*******@earthlink.net) writes:
I've also just started reading about Real-Time OLAP cubes and Analysis
Services. Would this help me in any way? <<
This is probably the best answer, but in the meantime you can do a VIEW
with all the summaries: Basically convert all of your WHERE clauses
into CASE expressions

SELECT MAX (CASE WHEN sale_date > '2005-01-01' THEN s1 END),
AVG (CASE WHEN S3 > S4 THEN (s1 / s2) END),
etc.
FROM Sales1 ;


That would have to be an indexed view to give the performance Rich is
required to produce. Since there are a lot of restrictions with indexed
views on what you can put into them, this may require quite some tweaks.
--
Erland Sommarskog, SQL Server MVP, es****@sommarskog.se

Books Online for SQL Server SP3 at
http://www.microsoft.com/sql/techinf...2000/books.asp
Jul 30 '05 #7
I am guessing that he has to do a table scan for some of these 500
calculations, so if we can get it down to one scan, this will be the
best we can hope for. I have not played with indexed views, so maybe
someone else can comment here.

Jul 30 '05 #8

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

Similar topics

36
by: Andrea Griffini | last post by:
I did it. I proposed python as the main language for our next CAD/CAM software because I think that it has all the potential needed for it. I'm not sure yet if the decision will get through, but...
5
by: Andrew Ward | last post by:
Hi All, Sorry if this is off topic, but I could not seem to find a suitable OO Design newsgroup. If there is one feel free to let me know. Here is a simplification of a general design problem I...
3
by: SpamProof | last post by:
I'm looking for an example of a detailed design that I can follow or get ideas from before programming in vb.net. Currently, I'm using this outline approach that describes my Project, Classes,...
4
by: gigal | last post by:
Currently, the class is defined as, Class CarClass { EngineClass e; SeatClass s; CDPlayerClass cd; .... };
4
by: emma middlebrook | last post by:
Hi Straight to the point - I don't understand why System.Array derives from IList (given the methods/properties actually on IList). When designing an interface you specify a contract. Deriving...
22
by: Krivenok Dmitry | last post by:
Hello All! I am trying to implement my own Design Patterns Library. I have read the following documentation about Observer Pattern: 1) Design Patterns by GoF Classic description of Observer....
1
by: Nogusta123 | last post by:
Hi, I have had a lot of problems getting web pages, master pages and content pages to render in VS2005 design view the same as they would in Internet Explorer. I did a lot of looking on the...
6
by: Orgun | last post by:
Hi, I sent this message to the moderated c++ group too but it is waiting for moderator approval and I wanted to send here too. I am new to Design Patterns. I want to write a simple...
0
by: YellowFin Announcements | last post by:
Introduction Usability and relevance have been identified as the major factors preventing mass adoption of Business Intelligence applications. What we have today are traditional BI tools that...
7
by: snewman18 | last post by:
In learning about design patterns, I've seen discussion about using inheritance when an object's relationship to another object is 'is-a' and composition when the relationship is 'has-a'. Since...
0
by: taylorcarr | last post by:
A Canon printer is a smart device known for being advanced, efficient, and reliable. It is designed for home, office, and hybrid workspace use and can also be used for a variety of purposes. However,...
0
by: aa123db | last post by:
Variable and constants Use var or let for variables and const fror constants. Var foo ='bar'; Let foo ='bar';const baz ='bar'; Functions function $name$ ($parameters$) { } ...
0
by: ryjfgjl | last post by:
If we have dozens or hundreds of excel to import into the database, if we use the excel import function provided by database editors such as navicat, it will be extremely tedious and time-consuming...
0
by: ryjfgjl | last post by:
In our work, we often receive Excel tables with data in the same format. If we want to analyze these data, it can be difficult to analyze them because the data is spread across multiple Excel files...
0
by: emmanuelkatto | last post by:
Hi All, I am Emmanuel katto from Uganda. I want to ask what challenges you've faced while migrating a website to cloud. Please let me know. Thanks! Emmanuel
1
by: nemocccc | last post by:
hello, everyone, I want to develop a software for my android phone for daily needs, any suggestions?
0
by: Hystou | last post by:
There are some requirements for setting up RAID: 1. The motherboard and BIOS support RAID configuration. 2. The motherboard has 2 or more available SATA protocol SSD/HDD slots (including MSATA, M.2...
0
marktang
by: marktang | last post by:
ONU (Optical Network Unit) is one of the key components for providing high-speed Internet services. Its primary function is to act as an endpoint device located at the user's premises. However,...
0
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...

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.