From jwcolby at colbyconsulting.com Thu Dec 3 10:16:54 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 03 Dec 2009 11:16:54 -0500 Subject: [dba-SQLServer] Do I need a cover index? Message-ID: <4B17E476.1020103@colbyconsulting.com> I have a table with a unique PKID (int) and a bunch more fields. I created a clustered index so that (my understanding) the data is sorted by the PK and all the fields are physically stored "together" (whatever that might mean). Now... in actual use I will join that table to other tables using that PK and then select a single field from the table to include in the view. Obviously the PKID is not useful to me other than that it is indexed and used in the join. My question is, do I need to build a "cover index" that includes the PKID and that single field that I always use? Or is the fact that the data is already "stored together" give me access to that other field, and the cover index is not useful? I suspect that I should have the cover index but this is one of many gray areas in my knowledge. TIA for your assistance. -- John W. Colby www.ColbyConsulting.com From fuller.artful at gmail.com Thu Dec 3 11:29:08 2009 From: fuller.artful at gmail.com (Arthur Fuller) Date: Thu, 3 Dec 2009 12:29:08 -0500 Subject: [dba-SQLServer] Do I need a cover index? In-Reply-To: <4B17E476.1020103@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> Message-ID: <29f585dd0912030929x7a3d808ct92f8ba0135f6fa8@mail.gmail.com> I suggest that you go with the covering index. Arthur From ab-mi at post3.tele.dk Thu Dec 3 14:22:45 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Thu, 3 Dec 2009 21:22:45 +0100 Subject: [dba-SQLServer] Do I need a cover index? In-Reply-To: <4B17E476.1020103@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> Message-ID: If you want a covering index then don't redesign the clustered index to include that other field and don't build a composite non clustered index on that other field plus the PK field. All you have to do is to build a non clustered index on that other field. This single-field index will in fact cover both that field and the PK field. Reason: In SQL Server the leaf level of a non clustered index always includes the key values of the clustered index. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 3. december 2009 17:17 Til: Dba-Sqlserver Emne: [dba-SQLServer] Do I need a cover index? I have a table with a unique PKID (int) and a bunch more fields. I created a clustered index so that (my understanding) the data is sorted by the PK and all the fields are physically stored "together" (whatever that might mean). Now... in actual use I will join that table to other tables using that PK and then select a single field from the table to include in the view. Obviously the PKID is not useful to me other than that it is indexed and used in the join. My question is, do I need to build a "cover index" that includes the PKID and that single field that I always use? Or is the fact that the data is already "stored together" give me access to that other field, and the cover index is not useful? I suspect that I should have the cover index but this is one of many gray areas in my knowledge. TIA for your assistance. -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From marklbreen at gmail.com Thu Dec 3 15:53:08 2009 From: marklbreen at gmail.com (Mark Breen) Date: Thu, 3 Dec 2009 21:53:08 +0000 Subject: [dba-SQLServer] Do I need a cover index? In-Reply-To: <4B17E476.1020103@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> Message-ID: Hello John, I would have thought the the most important thing to consider is what columns you will join on and what columns you will filter on. So, if you are only retrieving based on the PKID then I see no need to have any additional index. However, if you are joining on the PKID, but are filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an index on Field 47 also. Regarding Clustered vs non Clustered, I believed those to be highly in a highly trafficed database where records are coming and going all the time. In those cases, the indexes can become fragmented in a similar way that hard disks get fragmented. More importantly, in a high volume, data entry system, I understand that it can dramatically increase performance if you do NOT cluster on the PK. (the following may be ten years out of date). The reason to Cluster on the Non-PK fields as that multiple records for Invoices 99, 100, 101, 102 would all be written to the same page within the db, and if that page is locked for invoice 103, then another operator cannot raise invoice 104 until 103 is completed. This was the logic I was thought in 1997 in clustering on another column such as CustomerId instead of InvoiceId. I really do not know if that is still relevant nowadays. Anyway, in your case, it seems all irrelevant, as you do a mass import and the immediately create your indexes. IOW, your indexes are in perfect condition. You probably only use them two or three times before you abandon that db for the next one. One last question, having just re-read your email, I see that you are talking about / hoping that a clustered index may keep the *fields *together. I would have assumed 99% confidently that the fields must always be kept together (as you say, what ever that might mean), but the clustering of indexes only relates to keeping *records *together, not columns together. So, if that is the case, you do not require a clustered index to keep columns together, ie, the must always travel together. I have no idea how to measure that. Am I totally off beam here, is the problem that I do not know what a cover index is? BTW, one last question, when you create new databases, do you create the db as 1 mb and allow it to grow, or do you initially create it as 47 gb, and then just populate it with what ever arrives each month. Is is faster to do your imports to a db that is already expanded up. If so, do you keep a handy, ready to go, empty 47 GB db lying around? thanks Mark 2009/12/3 jwcolby > I have a table with a unique PKID (int) and a bunch more fields. I created > a clustered index so > that (my understanding) the data is sorted by the PK and all the fields are > physically stored > "together" (whatever that might mean). > > Now... in actual use I will join that table to other tables using that PK > and then select a single > field from the table to include in the view. > > Obviously the PKID is not useful to me other than that it is indexed and > used in the join. > > My question is, do I need to build a "cover index" that includes the PKID > and that single field that > I always use? Or is the fact that the data is already "stored together" > give me access to that > other field, and the cover index is not useful? I suspect that I should > have the cover index but > this is one of many gray areas in my knowledge. > > TIA for your assistance. > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Thu Dec 3 17:24:14 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 03 Dec 2009 18:24:14 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? In-Reply-To: References: <4B17E476.1020103@colbyconsulting.com> Message-ID: <4B18489E.6080105@colbyconsulting.com> >However, if you are joining on the PKID, but are filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an index on Field 47 also. As it happens I do perform a where on the data field so a cover is required. > Anyway, in your case, it seems all irrelevant, as you do a mass import and the immediately create your indexes. Correct, after which no records are ever deleted or added. I do (or may) modify fields but not the PK of course. > One last question, having just re-read your email, I see that you are talking about / hoping that a clustered index may keep the *fields *together. Well, I am reading that by creating a clustered index, every single data element (field) in that row is stored together, AND the rows are physically sorted on the index key - the PKID in this case. OTOH if you do not create a clustered index, then the data elements just go "in the heap" with pointers to the data in the heap maintained in the index. Again though, what does that mean? I know what a heap means in memory for a program, but it is a little difficult for me to equate that to a db file. I have no concept of what the structure of a db file looks like, where this "heap" might be etc. But it is always spoken of negatively so it must be bad. > BTW, one last question, when you create new databases, do you create the db as 1 mb and allow it to grow... I do. Yes it would be faster to create it initially as something bigger but it is difficult to know how big is big enough and in the end this is not enough of a problem to worry about. In the end I do the month to month processing in the same file, over and over again. I am actually considering (eventually) creating a temp database to use to get the data exported / imported etc. The nice thing about SQL Server is that you can simply specify the db name that you want to create a table in, append data in etc. So I could do a temp database, temp tables for the export and then just delete the db when the export is finished. Likewise for the import. Temp db, temp table(s) then append into the "real" table, or update records in the "real" table. But that is down the road. >If so, do you keep a handy, ready to go, empty 47 GB db lying around? Well, empty or not, 47 gigs is 47 gigs and copying that is slooooowwwww. You would lose some or all of the hoped for efficiency in the copy. John W. Colby www.ColbyConsulting.com Mark Breen wrote: > Hello John, > > I would have thought the the most important thing to consider is what > columns you will join on and what columns you will filter on. > > So, if you are only retrieving based on the PKID then I see no need to have > any additional index. However, if you are joining on the PKID, but are > filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an > index on Field 47 also. > > Regarding Clustered vs non Clustered, I believed those to be highly in a > highly trafficed database where records are coming and going all the time. > In those cases, the indexes can become fragmented in a similar way that > hard disks get fragmented. More importantly, in a high volume, data entry > system, I understand that it can dramatically increase performance if you do > NOT cluster on the PK. (the following may be ten years out of date). The > reason to Cluster on the Non-PK fields as that multiple records for Invoices > 99, 100, 101, 102 would all be written to the same page within the db, and > if that page is locked for invoice 103, then another operator cannot raise > invoice 104 until 103 is completed. This was the logic I was thought in > 1997 in clustering on another column such as CustomerId instead of > InvoiceId. I really do not know if that is still relevant nowadays. > > Anyway, in your case, it seems all irrelevant, as you do a mass import and > the immediately create your indexes. IOW, your indexes are in perfect > condition. You probably only use them two or three times before you abandon > that db for the next one. > > One last question, having just re-read your email, I see that you are > talking about / hoping that a clustered index may keep the *fields *together. > I would have assumed 99% confidently that the fields must always be kept > together (as you say, what ever that might mean), but the clustering of > indexes only relates to keeping *records *together, not columns together. > So, if that is the case, you do not require a clustered index to keep > columns together, ie, the must always travel together. I have no idea how > to measure that. > > Am I totally off beam here, is the problem that I do not know what a cover > index is? > > BTW, one last question, when you create new databases, do you create the db > as 1 mb and allow it to grow, or do you initially create it as 47 gb, and > then just populate it with what ever arrives each month. Is is faster to do > your imports to a db that is already expanded up. If so, do you keep a > handy, ready to go, empty 47 GB db lying around? > > thanks > > Mark From marklbreen at gmail.com Thu Dec 3 18:29:13 2009 From: marklbreen at gmail.com (Mark Breen) Date: Fri, 4 Dec 2009 00:29:13 +0000 Subject: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B18489E.6080105@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com> Message-ID: Hello John, thanks for the responses. [Well, I am reading that by creating a clustered index, every single data element (field) in that row is stored together, AND the rows are physically sorted on the index key - the PKID in this case.] I would not have assumed this. Even without a clustered, I would expect that SQL Server would store the columns of one row as close to each other as physically possible, given the limitations of the data sizes. Somewhere in the back of my mind I am even wondering is that what the 8000 char limit is for, ie, that 8k blocks are reserved for a row of data. Again, that may be ten years out of date now with SQL 2008. Just one final point to comment on. I also do not know what the heap is, but I would guess that your heap is neat and tidy as the data is effectively created sequentially, so, it probably looks the same with or without the clustered PK. No idea how to check this though. Thanks Mark 2009/12/3 jwcolby > >However, if you are joining on the PKID, but are filtering "Where Field47 > = 'Ice Cream and Jelly', > then you should have an index on Field 47 also. > > As it happens I do perform a where on the data field so a cover is > required. > > > Anyway, in your case, it seems all irrelevant, as you do a mass import > and the immediately create > your indexes. > > Correct, after which no records are ever deleted or added. I do (or may) > modify fields but not the > PK of course. > > > One last question, having just re-read your email, I see that you are > talking about / hoping that > a clustered index may keep the *fields *together. > > Well, I am reading that by creating a clustered index, every single data > element (field) in that row > is stored together, AND the rows are physically sorted on the index key - > the PKID in this case. > > OTOH if you do not create a clustered index, then the data elements just go > "in the heap" with > pointers to the data in the heap maintained in the index. Again though, > what does that mean? I > know what a heap means in memory for a program, but it is a little > difficult for me to equate that > to a db file. I have no concept of what the structure of a db file looks > like, where this "heap" > might be etc. But it is always spoken of negatively so it must be bad. > > > BTW, one last question, when you create new databases, do you create the > db as 1 mb and allow it > to grow... > > I do. Yes it would be faster to create it initially as something bigger > but it is difficult to know > how big is big enough and in the end this is not enough of a problem to > worry about. In the end I > do the month to month processing in the same file, over and over again. I > am actually considering > (eventually) creating a temp database to use to get the data exported / > imported etc. The nice > thing about SQL Server is that you can simply specify the db name that you > want to create a table > in, append data in etc. So I could do a temp database, temp tables for the > export and then just > delete the db when the export is finished. Likewise for the import. Temp > db, temp table(s) then > append into the "real" table, or update records in the "real" table. > > But that is down the road. > > >If so, do you keep a handy, ready to go, empty 47 GB db lying around? > > Well, empty or not, 47 gigs is 47 gigs and copying that is slooooowwwww. > You would lose some or all > of the hoped for efficiency in the copy. > > John W. Colby > www.ColbyConsulting.com > > > Mark Breen wrote: > > Hello John, > > > > I would have thought the the most important thing to consider is what > > columns you will join on and what columns you will filter on. > > > > So, if you are only retrieving based on the PKID then I see no need to > have > > any additional index. However, if you are joining on the PKID, but are > > filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an > > index on Field 47 also. > > > > Regarding Clustered vs non Clustered, I believed those to be highly in a > > highly trafficed database where records are coming and going all the > time. > > In those cases, the indexes can become fragmented in a similar way that > > hard disks get fragmented. More importantly, in a high volume, data > entry > > system, I understand that it can dramatically increase performance if you > do > > NOT cluster on the PK. (the following may be ten years out of date). > The > > reason to Cluster on the Non-PK fields as that multiple records for > Invoices > > 99, 100, 101, 102 would all be written to the same page within the db, > and > > if that page is locked for invoice 103, then another operator cannot > raise > > invoice 104 until 103 is completed. This was the logic I was thought in > > 1997 in clustering on another column such as CustomerId instead of > > InvoiceId. I really do not know if that is still relevant nowadays. > > > > Anyway, in your case, it seems all irrelevant, as you do a mass import > and > > the immediately create your indexes. IOW, your indexes are in perfect > > condition. You probably only use them two or three times before you > abandon > > that db for the next one. > > > > One last question, having just re-read your email, I see that you are > > talking about / hoping that a clustered index may keep the *fields > *together. > > I would have assumed 99% confidently that the fields must always be kept > > together (as you say, what ever that might mean), but the clustering of > > indexes only relates to keeping *records *together, not columns together. > > So, if that is the case, you do not require a clustered index to keep > > columns together, ie, the must always travel together. I have no idea > how > > to measure that. > > > > Am I totally off beam here, is the problem that I do not know what a > cover > > index is? > > > > BTW, one last question, when you create new databases, do you create the > db > > as 1 mb and allow it to grow, or do you initially create it as 47 gb, and > > then just populate it with what ever arrives each month. Is is faster to > do > > your imports to a db that is already expanded up. If so, do you keep a > > handy, ready to go, empty 47 GB db lying around? > > > > thanks > > > > Mark > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Thu Dec 3 19:13:00 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Fri, 4 Dec 2009 02:13:00 +0100 Subject: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B18489E.6080105@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com> Message-ID: <8CFE2736E3794F1C81685C26E81B4605@AB> Some points to consider: 1. A clustered index on the PK will be useful for the join operation. 2. A non clustered index on the filtering field will be useful for the search operation. 3. In your scenario the best choice IMO is a clustered index on the PK and a non clustered index on the filtering field. As mentioned in my previous posting this index will automatically include the values of the PK in the bottom of its index tree (the "leaf level"). Perhaps your searches don't specify the PK value (I guess not, since you use surrogate keys, which of cause are not candidates for searches). But nice to know anyhow - it certainly should prevent you from creating a composite index on the PK plus your filtering field: this kind of index would be an enormously waste of space and performance. 4. If you don't have a clustered index, then your table is a "heap". This means that the records can go anywhere in the physical file. A heap can be very efficient for inserts, because SQL Server then don't have to bother where to drop the records, it just scatters the records wherever room is available. But it is very-very inefficient for searches and joins, because then SQL Server has to consult a special internal table named IAM to find where it happened to drop your damned records. That's why it's normally bad. But you could imagine situations where this would be very well, for example an auditing table populated by a trigger. 5. If you want to make your inserts create huge amounts of disk fragmentation then just go ahead using a small-sizes db relying on auto grow of your db. If you don't want that then follow Mark's advice and size your db initially to the anticipated size. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 4. december 2009 00:24 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >However, if you are joining on the PKID, but are filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an index on Field 47 also. As it happens I do perform a where on the data field so a cover is required. > Anyway, in your case, it seems all irrelevant, as you do a mass import and the immediately create your indexes. Correct, after which no records are ever deleted or added. I do (or may) modify fields but not the PK of course. > One last question, having just re-read your email, I see that you are talking about / hoping that a clustered index may keep the *fields *together. Well, I am reading that by creating a clustered index, every single data element (field) in that row is stored together, AND the rows are physically sorted on the index key - the PKID in this case. OTOH if you do not create a clustered index, then the data elements just go "in the heap" with pointers to the data in the heap maintained in the index. Again though, what does that mean? I know what a heap means in memory for a program, but it is a little difficult for me to equate that to a db file. I have no concept of what the structure of a db file looks like, where this "heap" might be etc. But it is always spoken of negatively so it must be bad. > BTW, one last question, when you create new databases, do you create the db as 1 mb and allow it to grow... I do. Yes it would be faster to create it initially as something bigger but it is difficult to know how big is big enough and in the end this is not enough of a problem to worry about. In the end I do the month to month processing in the same file, over and over again. I am actually considering (eventually) creating a temp database to use to get the data exported / imported etc. The nice thing about SQL Server is that you can simply specify the db name that you want to create a table in, append data in etc. So I could do a temp database, temp tables for the export and then just delete the db when the export is finished. Likewise for the import. Temp db, temp table(s) then append into the "real" table, or update records in the "real" table. But that is down the road. >If so, do you keep a handy, ready to go, empty 47 GB db lying around? Well, empty or not, 47 gigs is 47 gigs and copying that is slooooowwwww. You would lose some or all of the hoped for efficiency in the copy. John W. Colby www.ColbyConsulting.com Mark Breen wrote: > Hello John, > > I would have thought the the most important thing to consider is what > columns you will join on and what columns you will filter on. > > So, if you are only retrieving based on the PKID then I see no need to have > any additional index. However, if you are joining on the PKID, but are > filtering "Where Field47 = 'Ice Cream and Jelly', then you should have an > index on Field 47 also. > > Regarding Clustered vs non Clustered, I believed those to be highly in a > highly trafficed database where records are coming and going all the time. > In those cases, the indexes can become fragmented in a similar way that > hard disks get fragmented. More importantly, in a high volume, data entry > system, I understand that it can dramatically increase performance if you do > NOT cluster on the PK. (the following may be ten years out of date). The > reason to Cluster on the Non-PK fields as that multiple records for Invoices > 99, 100, 101, 102 would all be written to the same page within the db, and > if that page is locked for invoice 103, then another operator cannot raise > invoice 104 until 103 is completed. This was the logic I was thought in > 1997 in clustering on another column such as CustomerId instead of > InvoiceId. I really do not know if that is still relevant nowadays. > > Anyway, in your case, it seems all irrelevant, as you do a mass import and > the immediately create your indexes. IOW, your indexes are in perfect > condition. You probably only use them two or three times before you abandon > that db for the next one. > > One last question, having just re-read your email, I see that you are > talking about / hoping that a clustered index may keep the *fields *together. > I would have assumed 99% confidently that the fields must always be kept > together (as you say, what ever that might mean), but the clustering of > indexes only relates to keeping *records *together, not columns together. > So, if that is the case, you do not require a clustered index to keep > columns together, ie, the must always travel together. I have no idea how > to measure that. > > Am I totally off beam here, is the problem that I do not know what a cover > index is? > > BTW, one last question, when you create new databases, do you create the db > as 1 mb and allow it to grow, or do you initially create it as 47 gb, and > then just populate it with what ever arrives each month. Is is faster to do > your imports to a db that is already expanded up. If so, do you keep a > handy, ready to go, empty 47 GB db lying around? > > thanks > > Mark _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Thu Dec 3 19:57:12 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 03 Dec 2009 20:57:12 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <8CFE2736E3794F1C81685C26E81B4605@AB> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com> <8CFE2736E3794F1C81685C26E81B4605@AB> Message-ID: <4B186C78.9030100@colbyconsulting.com> Thanks Asger. I will take #5 to heart though I will have to figure out how to figure out what is a "good size". ;) As I mentioned, at the moment I don't really have a lot of "new databases". I do occasionally get new lists, but it is just occasionally. Where I do much more is in monthly maintenance. Every month I update the database, which creates new temp (currently) tables inside of the existing database. As an example I create a sorted output table (on zip5/zip4) and copy every record into that table. I then take 2 million records at a whack and place them in a temp table, created on the fly. BCP out that "chunk". Drop the table, create it all over again, copy the next 2 million records in. BCP out. Rinse repeat until all 50 million records are BCPd out. As you might imagine that process causes enormous file growth, particularly in my log file but also in my main database file. These database are largish, at least coming from Access where the db file is never more than a few hundred million bytes. I might start with a 30 gig file and end up with a 100 gig file after processing. The more I think about it the more I think I want to go with a temp db to perform this export, as well as a matching import. Again though, how big is big enough. I do an 11 million record file, then a 21 million record file, then a 50 million record file etc. Just building an empty 50 gig file takes a long time for SQL Server. I don't have any answers on how to figure this out. As I get my C# control program happening I will be logging the start / stop time for each step (stored procedure) of this process. I could also log start and stop file sizes for the database files. Thus I could intentionally select different strategies and view my log files to see the times required for the strategy. As of now I don't have that in place, though I am actively working on it. The other thing I want to do is get my C# controller able to detach and attach these databases. If I can detach them programmatically then I can have defrag running at night. I own Perfectdisk server defrag which does a very good job at consolidating free space but the database files have to be detached. BTW I moved my log files out to a separate "spindle", that being a raid array based on its own set of disks. I am looking at the log files which I have been using a lot lately and while they are large, the actual number of fragments seems (to me) to be pretty reasonable. 50 gig - 4 Fragments 25 gig - 2 Fragments 30 gig - 6 Fragments Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is "small" at 1.5 gig. That is log file data. And understand that I often shrink the log files which usually shrinks them back down to 1 meg, and the disk was defragged awhile back to get all of the free space together. But these log files were all created (expanded) since that defrag. I think it is useful to remember that my databases are not transactional databases, and activity is concentrated in a single database as I perform this maintenance, then I move on to the next database. Thus it is not like there are 20 highly varied databases all mixing it up on a minute by minute basis. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Some points to consider: > 1. A clustered index on the PK will be useful for the join operation. > 2. A non clustered index on the filtering field will be useful for the > search operation. > 3. In your scenario the best choice IMO is a clustered index on the PK and a > non clustered index on the filtering field. As mentioned in my previous > posting this index will automatically include the values of the PK in the > bottom of its index tree (the "leaf level"). Perhaps your searches don't > specify the PK value (I guess not, since you use surrogate keys, which of > cause are not candidates for searches). But nice to know anyhow - it > certainly should prevent you from creating a composite index on the PK plus > your filtering field: this kind of index would be an enormously waste of > space and performance. > 4. If you don't have a clustered index, then your table is a "heap". This > means that the records can go anywhere in the physical file. A heap can be > very efficient for inserts, because SQL Server then don't have to bother > where to drop the records, it just scatters the records wherever room is > available. But it is very-very inefficient for searches and joins, because > then SQL Server has to consult a special internal table named IAM to find > where it happened to drop your damned records. That's why it's normally bad. > But you could imagine situations where this would be very well, for example > an auditing table populated by a trigger. > 5. If you want to make your inserts create huge amounts of disk > fragmentation then just go ahead using a small-sizes db relying on auto grow > of your db. If you don't want that then follow Mark's advice and size your > db initially to the anticipated size. > Asger From ab-mi at post3.tele.dk Thu Dec 3 20:43:50 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Fri, 4 Dec 2009 03:43:50 +0100 Subject: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B186C78.9030100@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB> <4B186C78.9030100@colbyconsulting.com> Message-ID: For once you asked a simple question. The answer is: big enough. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 4. december 2009 02:57 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? Thanks Asger. I will take #5 to heart though I will have to figure out how to figure out what is a "good size". ;) As I mentioned, at the moment I don't really have a lot of "new databases". I do occasionally get new lists, but it is just occasionally. Where I do much more is in monthly maintenance. Every month I update the database, which creates new temp (currently) tables inside of the existing database. As an example I create a sorted output table (on zip5/zip4) and copy every record into that table. I then take 2 million records at a whack and place them in a temp table, created on the fly. BCP out that "chunk". Drop the table, create it all over again, copy the next 2 million records in. BCP out. Rinse repeat until all 50 million records are BCPd out. As you might imagine that process causes enormous file growth, particularly in my log file but also in my main database file. These database are largish, at least coming from Access where the db file is never more than a few hundred million bytes. I might start with a 30 gig file and end up with a 100 gig file after processing. The more I think about it the more I think I want to go with a temp db to perform this export, as well as a matching import. Again though, how big is big enough. I do an 11 million record file, then a 21 million record file, then a 50 million record file etc. Just building an empty 50 gig file takes a long time for SQL Server. I don't have any answers on how to figure this out. As I get my C# control program happening I will be logging the start / stop time for each step (stored procedure) of this process. I could also log start and stop file sizes for the database files. Thus I could intentionally select different strategies and view my log files to see the times required for the strategy. As of now I don't have that in place, though I am actively working on it. The other thing I want to do is get my C# controller able to detach and attach these databases. If I can detach them programmatically then I can have defrag running at night. I own Perfectdisk server defrag which does a very good job at consolidating free space but the database files have to be detached. BTW I moved my log files out to a separate "spindle", that being a raid array based on its own set of disks. I am looking at the log files which I have been using a lot lately and while they are large, the actual number of fragments seems (to me) to be pretty reasonable. 50 gig - 4 Fragments 25 gig - 2 Fragments 30 gig - 6 Fragments Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is "small" at 1.5 gig. That is log file data. And understand that I often shrink the log files which usually shrinks them back down to 1 meg, and the disk was defragged awhile back to get all of the free space together. But these log files were all created (expanded) since that defrag. I think it is useful to remember that my databases are not transactional databases, and activity is concentrated in a single database as I perform this maintenance, then I move on to the next database. Thus it is not like there are 20 highly varied databases all mixing it up on a minute by minute basis. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Some points to consider: > 1. A clustered index on the PK will be useful for the join operation. > 2. A non clustered index on the filtering field will be useful for the > search operation. > 3. In your scenario the best choice IMO is a clustered index on the PK and a > non clustered index on the filtering field. As mentioned in my previous > posting this index will automatically include the values of the PK in the > bottom of its index tree (the "leaf level"). Perhaps your searches don't > specify the PK value (I guess not, since you use surrogate keys, which of > cause are not candidates for searches). But nice to know anyhow - it > certainly should prevent you from creating a composite index on the PK plus > your filtering field: this kind of index would be an enormously waste of > space and performance. > 4. If you don't have a clustered index, then your table is a "heap". This > means that the records can go anywhere in the physical file. A heap can be > very efficient for inserts, because SQL Server then don't have to bother > where to drop the records, it just scatters the records wherever room is > available. But it is very-very inefficient for searches and joins, because > then SQL Server has to consult a special internal table named IAM to find > where it happened to drop your damned records. That's why it's normally bad. > But you could imagine situations where this would be very well, for example > an auditing table populated by a trigger. > 5. If you want to make your inserts create huge amounts of disk > fragmentation then just go ahead using a small-sizes db relying on auto grow > of your db. If you don't want that then follow Mark's advice and size your > db initially to the anticipated size. > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Fri Dec 4 13:42:59 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 04 Dec 2009 14:42:59 -0500 Subject: [dba-SQLServer] I need a crosstab (kinda) Message-ID: <4B196643.8090001@colbyconsulting.com> I have a table that I create for my DBFH client orders. This table has a set of fields which are the where clause fields. Every single "where clause" field (for data placed in the table) gets created in the table, then the actual codes that match the where are placed in those fields. For example, the source table has a a field called MOB and these fields contain a code of '1' or '2' or they contain the empty string ''. So when I create tblOrderData, IF I am using the MOB field in the where clause to select data to place in tblOrderData, I create a MOB field in tblOrderData and whatever that field contains gets placed in this field. I do this because the client might say "MOB" AND ("Kids_1_3" OR "Kids_4_7" or...) etc. I need to be able to visually prove that my data matches the where clause. Thus the where clause fields in tblOrderData. Additionally however the client wants to see counts of each where clause field, and counts of the intersection of where clause fields. "count of MOB AND Kids_1_3", Count of MOB and Kids_4_7" etc. If I have 4 where clause fields I would have a 4x4 matrix with counts of the intersections. 5 where clause fields would give me a 5x5 matrix of counts of intersections. He thinks of it as a table where the column headers are the where clause field names and the row headers are the where clause field names. I am pretty sure I do not know how to do this in SQL. Is this possible in SQL? It is kind of a crosstab but not really. -- John W. Colby www.ColbyConsulting.com From ab-mi at post3.tele.dk Sat Dec 5 19:02:50 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 02:02:50 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> Message-ID: Sorry John, I only read the first two lines of your posting right through to ;) - thinking the rest was from another response not related to my comment. Now I happen to notice that your reply was far longer... As I see you create temporary tables in a normal user db populating and then dropping them, which causes the normal user db and its log to grow. Did you consider creating these tables in the special tempdb database instead? You create a table in the tempdb database using a # in front of the tablename, e.g. #MyTable. This kind of table will automatically be deleted when the connection creating it is closed and it will not cause any growth of our normal user db. Since the tempdb database is using the "simple recovery model" it will also automatically truncate its own log file whenever an operation is finished. To make efficient use of the tempdb database you might want to place its data file and log file on separate fast drives and enlarge the files (by default both files are stored in the Data-directory of your SQL Server installation and have a size of 8MB and 1MB respectively). You change the default placement and size of the tempdb this way: ALTER DATABASE tempdb MODIFY FILE (name='tempdev', filename='X:\TempDBData\tempdb.mdf') GO ALTER DATABASE tempdb MODIFY FILE (name='templog', filename='Y:\TempDBLog\templog.ldf') GO ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) GO ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) GO After this you have to restart SQL Server to make the changes effective. HTH Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond Sendt: 4. december 2009 03:44 Til: 'Discussion concerning MS SQL Server' Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? For once you asked a simple question. The answer is: big enough. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 4. december 2009 02:57 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? Thanks Asger. I will take #5 to heart though I will have to figure out how to figure out what is a "good size". ;) As I mentioned, at the moment I don't really have a lot of "new databases". I do occasionally get new lists, but it is just occasionally. Where I do much more is in monthly maintenance. Every month I update the database, which creates new temp (currently) tables inside of the existing database. As an example I create a sorted output table (on zip5/zip4) and copy every record into that table. I then take 2 million records at a whack and place them in a temp table, created on the fly. BCP out that "chunk". Drop the table, create it all over again, copy the next 2 million records in. BCP out. Rinse repeat until all 50 million records are BCPd out. As you might imagine that process causes enormous file growth, particularly in my log file but also in my main database file. These database are largish, at least coming from Access where the db file is never more than a few hundred million bytes. I might start with a 30 gig file and end up with a 100 gig file after processing. The more I think about it the more I think I want to go with a temp db to perform this export, as well as a matching import. Again though, how big is big enough. I do an 11 million record file, then a 21 million record file, then a 50 million record file etc. Just building an empty 50 gig file takes a long time for SQL Server. I don't have any answers on how to figure this out. As I get my C# control program happening I will be logging the start / stop time for each step (stored procedure) of this process. I could also log start and stop file sizes for the database files. Thus I could intentionally select different strategies and view my log files to see the times required for the strategy. As of now I don't have that in place, though I am actively working on it. The other thing I want to do is get my C# controller able to detach and attach these databases. If I can detach them programmatically then I can have defrag running at night. I own Perfectdisk server defrag which does a very good job at consolidating free space but the database files have to be detached. BTW I moved my log files out to a separate "spindle", that being a raid array based on its own set of disks. I am looking at the log files which I have been using a lot lately and while they are large, the actual number of fragments seems (to me) to be pretty reasonable. 50 gig - 4 Fragments 25 gig - 2 Fragments 30 gig - 6 Fragments Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is "small" at 1.5 gig. That is log file data. And understand that I often shrink the log files which usually shrinks them back down to 1 meg, and the disk was defragged awhile back to get all of the free space together. But these log files were all created (expanded) since that defrag. I think it is useful to remember that my databases are not transactional databases, and activity is concentrated in a single database as I perform this maintenance, then I move on to the next database. Thus it is not like there are 20 highly varied databases all mixing it up on a minute by minute basis. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Some points to consider: > 1. A clustered index on the PK will be useful for the join operation. > 2. A non clustered index on the filtering field will be useful for the > search operation. > 3. In your scenario the best choice IMO is a clustered index on the PK and a > non clustered index on the filtering field. As mentioned in my previous > posting this index will automatically include the values of the PK in the > bottom of its index tree (the "leaf level"). Perhaps your searches don't > specify the PK value (I guess not, since you use surrogate keys, which of > cause are not candidates for searches). But nice to know anyhow - it > certainly should prevent you from creating a composite index on the PK plus > your filtering field: this kind of index would be an enormously waste of > space and performance. > 4. If you don't have a clustered index, then your table is a "heap". This > means that the records can go anywhere in the physical file. A heap can be > very efficient for inserts, because SQL Server then don't have to bother > where to drop the records, it just scatters the records wherever room is > available. But it is very-very inefficient for searches and joins, because > then SQL Server has to consult a special internal table named IAM to find > where it happened to drop your damned records. That's why it's normally bad. > But you could imagine situations where this would be very well, for example > an auditing table populated by a trigger. > 5. If you want to make your inserts create huge amounts of disk > fragmentation then just go ahead using a small-sizes db relying on auto grow > of your db. If you don't want that then follow Mark's advice and size your > db initially to the anticipated size. > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Sat Dec 5 19:46:14 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 05 Dec 2009 20:46:14 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> Message-ID: <4B1B0CE6.5070706@colbyconsulting.com> Asger, A month or so back I did move the TempDB off to it's own "spindle", a two drive raid 0 array, 600 gigs, nothing on it except the temp db. Do you think it would be worthwhile to make this large, like 50 gigs or 100 gigs or even more? Again I have plenty of room, the array is dedicated to the temp drive. If "expanding" is a high cost operation then perhaps just making it huge would be a good thing? The operations I am discussing import and export tens of gigs of data. Thanks for telling me about this. I have been thinking about doing something like this, but was considering creating databases on-the-fly to do this stuff. Using the tempdb sure looks much easier! John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Sat Dec 5 19:52:14 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 05 Dec 2009 20:52:14 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> Message-ID: <4B1B0E4E.3040002@colbyconsulting.com> One question about the "automatic deletion", what is the "connection" you mention? ATM I have an entire set of stored procedures which I run run directly from SSMS, or from my Access or C# control program. I assume that if run from inside of SSMS it will pretty much never be deleted, i.e. I would have to delete it myself? From my Access or C# control program I would have to make sure I used the same connection throughout the entire process? John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Sat Dec 5 19:57:43 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 05 Dec 2009 20:57:43 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> Message-ID: <4B1B0F97.5090500@colbyconsulting.com> Asger, This is an example of my current code. begin try SELECT @SQL = 'DROP TABLE [' + @DBName + '].dbo.AZExportToOrdered' EXEC (@SQL) end try begin catch print 'There was an error dropping ' + @DBName + '.dbo.AZExportToOrdered' print ERROR_MESSAGE() end catch begin try SELECT @SQL = 'CREATE TABLE [' + @DBName + '].[dbo].[AZExportToOrdered]( [OrderByInt] [int] IDENTITY(1,1) NOT NULL, [PK] [int] NULL, [FName] [varchar](250) NULL, [LName] [varchar](250) NULL, [Addr] [varchar](250) NULL, [City] [varchar](250) NULL, [St] [varchar](250) NULL, [Zip5] [varchar](250) NULL, [Zip4] [varchar](250) NULL ) ON [PRIMARY]' exec (@SQL) Basically I would drop the DBName part and then place a # in front of my table name. What would happen if I were to run a couple of these "simultaneously". One of my intentions is to get this stuff threaded in C# and be able to (though I may not actually do so) run several of these at the same time. Would I get table name collisions inside of the temp db? Or does SQL Server somehow magically handle that issue? John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Sat Dec 5 20:10:08 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 03:10:08 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B1B0CE6.5070706@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0CE6.5070706@colbyconsulting.com> Message-ID: <5D7545B1D77D41659259165556254982@AB> John, Yes, moving the tempdb off (as you did) is very good, and enlarging the size of its data and log files is certainly a point too: relying on auto growth for the tempdb is as bad as it is for a normal user db. BTW: SQL Server 2005 makes much more use of the tempdb database for its own operations than previous versions did - and SQL Server 2008 does so even more. So that's another good reason to replace and resize this database. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 6. december 2009 02:46 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? Asger, A month or so back I did move the TempDB off to it's own "spindle", a two drive raid 0 array, 600 gigs, nothing on it except the temp db. Do you think it would be worthwhile to make this large, like 50 gigs or 100 gigs or even more? Again I have plenty of room, the array is dedicated to the temp drive. If "expanding" is a high cost operation then perhaps just making it huge would be a good thing? The operations I am discussing import and export tens of gigs of data. Thanks for telling me about this. I have been thinking about doing something like this, but was considering creating databases on-the-fly to do this stuff. Using the tempdb sure looks much easier! John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Sat Dec 5 20:23:59 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 05 Dec 2009 21:23:59 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <5D7545B1D77D41659259165556254982@AB> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0CE6.5070706@colbyconsulting.com> <5D7545B1D77D41659259165556254982@AB> Message-ID: <4B1B15BF.8020104@colbyconsulting.com> Asger, Working with the tempdb is a little unsettling. With a normal table I was able to see what fields I had created, if my index create worked, how many records were in the table, even view the data in the table. With the tempdb I can see that the table exists, but can't "do anything" with it. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John, > Yes, moving the tempdb off (as you did) is very good, and enlarging the size > of its data and log files is certainly a point too: relying on auto growth > for the tempdb is as bad as it is for a normal user db. > BTW: SQL Server 2005 makes much more use of the tempdb database for its own > operations than previous versions did - and SQL Server 2008 does so even > more. So that's another good reason to replace and resize this database. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 6. december 2009 02:46 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? > > Asger, > > A month or so back I did move the TempDB off to it's own "spindle", a two > drive raid 0 array, 600 > gigs, nothing on it except the temp db. > > Do you think it would be worthwhile to make this large, like 50 gigs or 100 > gigs or even more? > Again I have plenty of room, the array is dedicated to the temp drive. If > "expanding" is a high > cost operation then perhaps just making it huge would be a good thing? > > The operations I am discussing import and export tens of gigs of data. > > Thanks for telling me about this. I have been thinking about doing > something like this, but was > considering creating databases on-the-fly to do this stuff. Using the > tempdb sure looks much easier! > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Sorry John, I only read the first two lines of your posting right through > to >> ;) - thinking the rest was from another response not related to my > comment. >> Now I happen to notice that your reply was far longer... >> As I see you create temporary tables in a normal user db populating and > then >> dropping them, which causes the normal user db and its log to grow. >> Did you consider creating these tables in the special tempdb database >> instead? You create a table in the tempdb database using a # in front of > the >> tablename, e.g. #MyTable. This kind of table will automatically be deleted >> when the connection creating it is closed and it will not cause any growth >> of our normal user db. Since the tempdb database is using the "simple >> recovery model" it will also automatically truncate its own log file >> whenever an operation is finished. >> To make efficient use of the tempdb database you might want to place its >> data file and log file on separate fast drives and enlarge the files (by >> default both files are stored in the Data-directory of your SQL Server >> installation and have a size of 8MB and 1MB respectively). You change the >> default placement and size of the tempdb this way: >> >> ALTER DATABASE tempdb MODIFY FILE >> (name='tempdev', filename='X:\TempDBData\tempdb.mdf') >> GO >> ALTER DATABASE tempdb MODIFY FILE >> (name='templog', filename='Y:\TempDBLog\templog.ldf') >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) >> GO >> After this you have to restart SQL Server to make the changes effective. >> >> HTH >> Asger >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger > Blond >> Sendt: 4. december 2009 03:44 >> Til: 'Discussion concerning MS SQL Server' >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> For once you asked a simple question. The answer is: big enough. >> Asger >> >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby >> Sendt: 4. december 2009 02:57 >> Til: Discussion concerning MS SQL Server >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> Thanks Asger. I will take #5 to heart though I will have to figure out > how >> to figure out what is a >> "good size". >> >> ;) >> >> >> As I mentioned, at the moment I don't really have a lot of "new > databases". >> I do occasionally get >> new lists, but it is just occasionally. Where I do much more is in > monthly >> maintenance. Every >> month I update the database, which creates new temp (currently) tables >> inside of the existing >> database. As an example I create a sorted output table (on zip5/zip4) and >> copy every record into >> that table. I then take 2 million records at a whack and place them in a >> temp table, created on the >> fly. BCP out that "chunk". Drop the table, create it all over again, > copy >> the next 2 million >> records in. BCP out. Rinse repeat until all 50 million records are BCPd >> out. >> >> As you might imagine that process causes enormous file growth, > particularly >> in my log file but also >> in my main database file. >> >> These database are largish, at least coming from Access where the db file > is >> never more than a few >> hundred million bytes. I might start with a 30 gig file and end up with a >> 100 gig file after >> processing. The more I think about it the more I think I want to go with > a >> temp db to perform this >> export, as well as a matching import. Again though, how big is big > enough. >> I do an 11 million >> record file, then a 21 million record file, then a 50 million record file >> etc. Just building an >> empty 50 gig file takes a long time for SQL Server. >> >> I don't have any answers on how to figure this out. As I get my C# > control >> program happening I will >> be logging the start / stop time for each step (stored procedure) of this >> process. I could also log >> start and stop file sizes for the database files. >> >> Thus I could intentionally select different strategies and view my log > files >> to see the times >> required for the strategy. >> >> As of now I don't have that in place, though I am actively working on it. >> >> The other thing I want to do is get my C# controller able to detach and >> attach these databases. If >> I can detach them programmatically then I can have defrag running at > night. >> I own Perfectdisk >> server defrag which does a very good job at consolidating free space but > the >> database files have to >> be detached. >> >> BTW I moved my log files out to a separate "spindle", that being a raid >> array based on its own set >> of disks. I am looking at the log files which I have been using a lot >> lately and while they are >> large, the actual number of fragments seems (to me) to be pretty > reasonable. >> 50 gig - 4 Fragments >> 25 gig - 2 Fragments >> 30 gig - 6 Fragments >> >> Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is >> "small" at 1.5 gig. >> >> That is log file data. And understand that I often shrink the log files >> which usually shrinks them >> back down to 1 meg, and the disk was defragged awhile back to get all of > the >> free space together. >> But these log files were all created (expanded) since that defrag. >> >> I think it is useful to remember that my databases are not transactional >> databases, and activity is >> concentrated in a single database as I perform this maintenance, then I > move >> on to the next >> database. Thus it is not like there are 20 highly varied databases all >> mixing it up on a minute by >> minute basis. >> >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Asger Blond wrote: >>> Some points to consider: >>> 1. A clustered index on the PK will be useful for the join operation. >>> 2. A non clustered index on the filtering field will be useful for the >>> search operation. >>> 3. In your scenario the best choice IMO is a clustered index on the PK > and >> a >>> non clustered index on the filtering field. As mentioned in my previous >>> posting this index will automatically include the values of the PK in the >>> bottom of its index tree (the "leaf level"). Perhaps your searches don't >>> specify the PK value (I guess not, since you use surrogate keys, which of >>> cause are not candidates for searches). But nice to know anyhow - it >>> certainly should prevent you from creating a composite index on the PK >> plus >>> your filtering field: this kind of index would be an enormously waste of >>> space and performance. >>> 4. If you don't have a clustered index, then your table is a "heap". This >>> means that the records can go anywhere in the physical file. A heap can > be >>> very efficient for inserts, because SQL Server then don't have to bother >>> where to drop the records, it just scatters the records wherever room is >>> available. But it is very-very inefficient for searches and joins, > because >>> then SQL Server has to consult a special internal table named IAM to find >>> where it happened to drop your damned records. That's why it's normally >> bad. >>> But you could imagine situations where this would be very well, for >> example >>> an auditing table populated by a trigger. >>> 5. If you want to make your inserts create huge amounts of disk >>> fragmentation then just go ahead using a small-sizes db relying on auto >> grow >>> of your db. If you don't want that then follow Mark's advice and size > your >>> db initially to the anticipated size. >>> Asger >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Sat Dec 5 20:32:47 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 03:32:47 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B1B0F97.5090500@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0F97.5090500@colbyconsulting.com> Message-ID: <9342B1A805E24B4B9A7FABCCBE8F7440@AB> No collision problem if the procedure is run simultaneously from to different connection: SQL server will internally separate the same-named tables in tempdb with connection markers. But of cause if you want to recreate the table within the same connection you have to first drop the table. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 6. december 2009 02:58 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? Asger, This is an example of my current code. begin try SELECT @SQL = 'DROP TABLE [' + @DBName + '].dbo.AZExportToOrdered' EXEC (@SQL) end try begin catch print 'There was an error dropping ' + @DBName + '.dbo.AZExportToOrdered' print ERROR_MESSAGE() end catch begin try SELECT @SQL = 'CREATE TABLE [' + @DBName + '].[dbo].[AZExportToOrdered]( [OrderByInt] [int] IDENTITY(1,1) NOT NULL, [PK] [int] NULL, [FName] [varchar](250) NULL, [LName] [varchar](250) NULL, [Addr] [varchar](250) NULL, [City] [varchar](250) NULL, [St] [varchar](250) NULL, [Zip5] [varchar](250) NULL, [Zip4] [varchar](250) NULL ) ON [PRIMARY]' exec (@SQL) Basically I would drop the DBName part and then place a # in front of my table name. What would happen if I were to run a couple of these "simultaneously". One of my intentions is to get this stuff threaded in C# and be able to (though I may not actually do so) run several of these at the same time. Would I get table name collisions inside of the temp db? Or does SQL Server somehow magically handle that issue? John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From ab-mi at post3.tele.dk Sat Dec 5 20:46:58 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 03:46:58 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B1B15BF.8020104@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0CE6.5070706@colbyconsulting.com><5D7545B1D77D41659259165556254982@AB> <4B1B15BF.8020104@colbyconsulting.com> Message-ID: <6CF1C41E459F4F2894524A2156D2148C@AB> Sure you can: USE tempdb SELECT * FROM #MyTable EXEC sp_help #MyTable EXEC sp_helpindex #MyTable -- and even: ALTER TABLE #MyTable ADD MyNewColumn char(10) Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 6. december 2009 03:24 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? Asger, Working with the tempdb is a little unsettling. With a normal table I was able to see what fields I had created, if my index create worked, how many records were in the table, even view the data in the table. With the tempdb I can see that the table exists, but can't "do anything" with it. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John, > Yes, moving the tempdb off (as you did) is very good, and enlarging the size > of its data and log files is certainly a point too: relying on auto growth > for the tempdb is as bad as it is for a normal user db. > BTW: SQL Server 2005 makes much more use of the tempdb database for its own > operations than previous versions did - and SQL Server 2008 does so even > more. So that's another good reason to replace and resize this database. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 6. december 2009 02:46 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? > > Asger, > > A month or so back I did move the TempDB off to it's own "spindle", a two > drive raid 0 array, 600 > gigs, nothing on it except the temp db. > > Do you think it would be worthwhile to make this large, like 50 gigs or 100 > gigs or even more? > Again I have plenty of room, the array is dedicated to the temp drive. If > "expanding" is a high > cost operation then perhaps just making it huge would be a good thing? > > The operations I am discussing import and export tens of gigs of data. > > Thanks for telling me about this. I have been thinking about doing > something like this, but was > considering creating databases on-the-fly to do this stuff. Using the > tempdb sure looks much easier! > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Sorry John, I only read the first two lines of your posting right through > to >> ;) - thinking the rest was from another response not related to my > comment. >> Now I happen to notice that your reply was far longer... >> As I see you create temporary tables in a normal user db populating and > then >> dropping them, which causes the normal user db and its log to grow. >> Did you consider creating these tables in the special tempdb database >> instead? You create a table in the tempdb database using a # in front of > the >> tablename, e.g. #MyTable. This kind of table will automatically be deleted >> when the connection creating it is closed and it will not cause any growth >> of our normal user db. Since the tempdb database is using the "simple >> recovery model" it will also automatically truncate its own log file >> whenever an operation is finished. >> To make efficient use of the tempdb database you might want to place its >> data file and log file on separate fast drives and enlarge the files (by >> default both files are stored in the Data-directory of your SQL Server >> installation and have a size of 8MB and 1MB respectively). You change the >> default placement and size of the tempdb this way: >> >> ALTER DATABASE tempdb MODIFY FILE >> (name='tempdev', filename='X:\TempDBData\tempdb.mdf') >> GO >> ALTER DATABASE tempdb MODIFY FILE >> (name='templog', filename='Y:\TempDBLog\templog.ldf') >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) >> GO >> After this you have to restart SQL Server to make the changes effective. >> >> HTH >> Asger >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger > Blond >> Sendt: 4. december 2009 03:44 >> Til: 'Discussion concerning MS SQL Server' >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> For once you asked a simple question. The answer is: big enough. >> Asger >> >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby >> Sendt: 4. december 2009 02:57 >> Til: Discussion concerning MS SQL Server >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> Thanks Asger. I will take #5 to heart though I will have to figure out > how >> to figure out what is a >> "good size". >> >> ;) >> >> >> As I mentioned, at the moment I don't really have a lot of "new > databases". >> I do occasionally get >> new lists, but it is just occasionally. Where I do much more is in > monthly >> maintenance. Every >> month I update the database, which creates new temp (currently) tables >> inside of the existing >> database. As an example I create a sorted output table (on zip5/zip4) and >> copy every record into >> that table. I then take 2 million records at a whack and place them in a >> temp table, created on the >> fly. BCP out that "chunk". Drop the table, create it all over again, > copy >> the next 2 million >> records in. BCP out. Rinse repeat until all 50 million records are BCPd >> out. >> >> As you might imagine that process causes enormous file growth, > particularly >> in my log file but also >> in my main database file. >> >> These database are largish, at least coming from Access where the db file > is >> never more than a few >> hundred million bytes. I might start with a 30 gig file and end up with a >> 100 gig file after >> processing. The more I think about it the more I think I want to go with > a >> temp db to perform this >> export, as well as a matching import. Again though, how big is big > enough. >> I do an 11 million >> record file, then a 21 million record file, then a 50 million record file >> etc. Just building an >> empty 50 gig file takes a long time for SQL Server. >> >> I don't have any answers on how to figure this out. As I get my C# > control >> program happening I will >> be logging the start / stop time for each step (stored procedure) of this >> process. I could also log >> start and stop file sizes for the database files. >> >> Thus I could intentionally select different strategies and view my log > files >> to see the times >> required for the strategy. >> >> As of now I don't have that in place, though I am actively working on it. >> >> The other thing I want to do is get my C# controller able to detach and >> attach these databases. If >> I can detach them programmatically then I can have defrag running at > night. >> I own Perfectdisk >> server defrag which does a very good job at consolidating free space but > the >> database files have to >> be detached. >> >> BTW I moved my log files out to a separate "spindle", that being a raid >> array based on its own set >> of disks. I am looking at the log files which I have been using a lot >> lately and while they are >> large, the actual number of fragments seems (to me) to be pretty > reasonable. >> 50 gig - 4 Fragments >> 25 gig - 2 Fragments >> 30 gig - 6 Fragments >> >> Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is >> "small" at 1.5 gig. >> >> That is log file data. And understand that I often shrink the log files >> which usually shrinks them >> back down to 1 meg, and the disk was defragged awhile back to get all of > the >> free space together. >> But these log files were all created (expanded) since that defrag. >> >> I think it is useful to remember that my databases are not transactional >> databases, and activity is >> concentrated in a single database as I perform this maintenance, then I > move >> on to the next >> database. Thus it is not like there are 20 highly varied databases all >> mixing it up on a minute by >> minute basis. >> >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Asger Blond wrote: >>> Some points to consider: >>> 1. A clustered index on the PK will be useful for the join operation. >>> 2. A non clustered index on the filtering field will be useful for the >>> search operation. >>> 3. In your scenario the best choice IMO is a clustered index on the PK > and >> a >>> non clustered index on the filtering field. As mentioned in my previous >>> posting this index will automatically include the values of the PK in the >>> bottom of its index tree (the "leaf level"). Perhaps your searches don't >>> specify the PK value (I guess not, since you use surrogate keys, which of >>> cause are not candidates for searches). But nice to know anyhow - it >>> certainly should prevent you from creating a composite index on the PK >> plus >>> your filtering field: this kind of index would be an enormously waste of >>> space and performance. >>> 4. If you don't have a clustered index, then your table is a "heap". This >>> means that the records can go anywhere in the physical file. A heap can > be >>> very efficient for inserts, because SQL Server then don't have to bother >>> where to drop the records, it just scatters the records wherever room is >>> available. But it is very-very inefficient for searches and joins, > because >>> then SQL Server has to consult a special internal table named IAM to find >>> where it happened to drop your damned records. That's why it's normally >> bad. >>> But you could imagine situations where this would be very well, for >> example >>> an auditing table populated by a trigger. >>> 5. If you want to make your inserts create huge amounts of disk >>> fragmentation then just go ahead using a small-sizes db relying on auto >> grow >>> of your db. If you don't want that then follow Mark's advice and size > your >>> db initially to the anticipated size. >>> Asger >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From ab-mi at post3.tele.dk Sat Dec 5 21:23:22 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 04:23:22 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B1B0E4E.3040002@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0E4E.3040002@colbyconsulting.com> Message-ID: <40035F96AC7846A2AB8DB278869BFDA0@AB> In SSMS: When you close the query window the connection is closed and the table in tempdb is automatically dropped. If you don't close the query window and you open a new query window and create the same-named table in tempdb then SQL Server will see this as a different table. The same goes for an Access or C# control program: if you want to make sure that you are using the same table in tempdb then stick to the same connection, if you want to create a new table with the same name in tempdb then either first drop this table or close the connection and reconnect. BTW: I you actually wants a table in tempdb to be visible and operationally across several connections then you can prefix it with ##, e.g. ##MyTable. This kind of table will be dropped only when the last connection referencing its closed. This is like a global variable, and I suppose not you case... Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 6. december 2009 02:52 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? One question about the "automatic deletion", what is the "connection" you mention? ATM I have an entire set of stored procedures which I run run directly from SSMS, or from my Access or C# control program. I assume that if run from inside of SSMS it will pretty much never be deleted, i.e. I would have to delete it myself? From my Access or C# control program I would have to make sure I used the same connection throughout the entire process? John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sorry John, I only read the first two lines of your posting right through to > ;) - thinking the rest was from another response not related to my comment. > Now I happen to notice that your reply was far longer... > As I see you create temporary tables in a normal user db populating and then > dropping them, which causes the normal user db and its log to grow. > Did you consider creating these tables in the special tempdb database > instead? You create a table in the tempdb database using a # in front of the > tablename, e.g. #MyTable. This kind of table will automatically be deleted > when the connection creating it is closed and it will not cause any growth > of our normal user db. Since the tempdb database is using the "simple > recovery model" it will also automatically truncate its own log file > whenever an operation is finished. > To make efficient use of the tempdb database you might want to place its > data file and log file on separate fast drives and enlarge the files (by > default both files are stored in the Data-directory of your SQL Server > installation and have a size of 8MB and 1MB respectively). You change the > default placement and size of the tempdb this way: > > ALTER DATABASE tempdb MODIFY FILE > (name='tempdev', filename='X:\TempDBData\tempdb.mdf') > GO > ALTER DATABASE tempdb MODIFY FILE > (name='templog', filename='Y:\TempDBLog\templog.ldf') > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) > GO > ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) > GO > After this you have to restart SQL Server to make the changes effective. > > HTH > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond > Sendt: 4. december 2009 03:44 > Til: 'Discussion concerning MS SQL Server' > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > For once you asked a simple question. The answer is: big enough. > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 4. december 2009 02:57 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? > > Thanks Asger. I will take #5 to heart though I will have to figure out how > to figure out what is a > "good size". > > ;) > > > As I mentioned, at the moment I don't really have a lot of "new databases". > I do occasionally get > new lists, but it is just occasionally. Where I do much more is in monthly > maintenance. Every > month I update the database, which creates new temp (currently) tables > inside of the existing > database. As an example I create a sorted output table (on zip5/zip4) and > copy every record into > that table. I then take 2 million records at a whack and place them in a > temp table, created on the > fly. BCP out that "chunk". Drop the table, create it all over again, copy > the next 2 million > records in. BCP out. Rinse repeat until all 50 million records are BCPd > out. > > As you might imagine that process causes enormous file growth, particularly > in my log file but also > in my main database file. > > These database are largish, at least coming from Access where the db file is > never more than a few > hundred million bytes. I might start with a 30 gig file and end up with a > 100 gig file after > processing. The more I think about it the more I think I want to go with a > temp db to perform this > export, as well as a matching import. Again though, how big is big enough. > I do an 11 million > record file, then a 21 million record file, then a 50 million record file > etc. Just building an > empty 50 gig file takes a long time for SQL Server. > > I don't have any answers on how to figure this out. As I get my C# control > program happening I will > be logging the start / stop time for each step (stored procedure) of this > process. I could also log > start and stop file sizes for the database files. > > Thus I could intentionally select different strategies and view my log files > to see the times > required for the strategy. > > As of now I don't have that in place, though I am actively working on it. > > The other thing I want to do is get my C# controller able to detach and > attach these databases. If > I can detach them programmatically then I can have defrag running at night. > I own Perfectdisk > server defrag which does a very good job at consolidating free space but the > database files have to > be detached. > > BTW I moved my log files out to a separate "spindle", that being a raid > array based on its own set > of disks. I am looking at the log files which I have been using a lot > lately and while they are > large, the actual number of fragments seems (to me) to be pretty reasonable. > > 50 gig - 4 Fragments > 25 gig - 2 Fragments > 30 gig - 6 Fragments > > Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is > "small" at 1.5 gig. > > That is log file data. And understand that I often shrink the log files > which usually shrinks them > back down to 1 meg, and the disk was defragged awhile back to get all of the > free space together. > But these log files were all created (expanded) since that defrag. > > I think it is useful to remember that my databases are not transactional > databases, and activity is > concentrated in a single database as I perform this maintenance, then I move > on to the next > database. Thus it is not like there are 20 highly varied databases all > mixing it up on a minute by > minute basis. > > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Some points to consider: >> 1. A clustered index on the PK will be useful for the join operation. >> 2. A non clustered index on the filtering field will be useful for the >> search operation. >> 3. In your scenario the best choice IMO is a clustered index on the PK and > a >> non clustered index on the filtering field. As mentioned in my previous >> posting this index will automatically include the values of the PK in the >> bottom of its index tree (the "leaf level"). Perhaps your searches don't >> specify the PK value (I guess not, since you use surrogate keys, which of >> cause are not candidates for searches). But nice to know anyhow - it >> certainly should prevent you from creating a composite index on the PK > plus >> your filtering field: this kind of index would be an enormously waste of >> space and performance. >> 4. If you don't have a clustered index, then your table is a "heap". This >> means that the records can go anywhere in the physical file. A heap can be >> very efficient for inserts, because SQL Server then don't have to bother >> where to drop the records, it just scatters the records wherever room is >> available. But it is very-very inefficient for searches and joins, because >> then SQL Server has to consult a special internal table named IAM to find >> where it happened to drop your damned records. That's why it's normally > bad. >> But you could imagine situations where this would be very well, for > example >> an auditing table populated by a trigger. >> 5. If you want to make your inserts create huge amounts of disk >> fragmentation then just go ahead using a small-sizes db relying on auto > grow >> of your db. If you don't want that then follow Mark's advice and size your >> db initially to the anticipated size. >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Sat Dec 5 21:29:47 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 05 Dec 2009 22:29:47 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <40035F96AC7846A2AB8DB278869BFDA0@AB> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0E4E.3040002@colbyconsulting.com> <40035F96AC7846A2AB8DB278869BFDA0@AB> Message-ID: <4B1B252B.8030200@colbyconsulting.com> I am in fact testing this stuff now and am using the ##table method. I was reading that the #table was closed when the SP that creates it closes. Given that I broke my process up into many SPs it seemed prudent to use the ##table method. By the way, 50 million records into the tempdb takes 0:6:44, to the original db takes 0:12:18. So about 45% faster. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > In SSMS: When you close the query window the connection is closed and the > table in tempdb is automatically dropped. If you don't close the query > window and you open a new query window and create the same-named table in > tempdb then SQL Server will see this as a different table. > The same goes for an Access or C# control program: if you want to make sure > that you are using the same table in tempdb then stick to the same > connection, if you want to create a new table with the same name in tempdb > then either first drop this table or close the connection and reconnect. > BTW: I you actually wants a table in tempdb to be visible and operationally > across several connections then you can prefix it with ##, e.g. ##MyTable. > This kind of table will be dropped only when the last connection referencing > its closed. This is like a global variable, and I suppose not you case... > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 6. december 2009 02:52 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? > > One question about the "automatic deletion", what is the "connection" you > mention? ATM I have an > entire set of stored procedures which I run run directly from SSMS, or from > my Access or C# control > program. I assume that if run from inside of SSMS it will pretty much never > be deleted, i.e. I > would have to delete it myself? From my Access or C# control program I > would have to make sure I > used the same connection throughout the entire process? > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Sorry John, I only read the first two lines of your posting right through > to >> ;) - thinking the rest was from another response not related to my > comment. >> Now I happen to notice that your reply was far longer... >> As I see you create temporary tables in a normal user db populating and > then >> dropping them, which causes the normal user db and its log to grow. >> Did you consider creating these tables in the special tempdb database >> instead? You create a table in the tempdb database using a # in front of > the >> tablename, e.g. #MyTable. This kind of table will automatically be deleted >> when the connection creating it is closed and it will not cause any growth >> of our normal user db. Since the tempdb database is using the "simple >> recovery model" it will also automatically truncate its own log file >> whenever an operation is finished. >> To make efficient use of the tempdb database you might want to place its >> data file and log file on separate fast drives and enlarge the files (by >> default both files are stored in the Data-directory of your SQL Server >> installation and have a size of 8MB and 1MB respectively). You change the >> default placement and size of the tempdb this way: >> >> ALTER DATABASE tempdb MODIFY FILE >> (name='tempdev', filename='X:\TempDBData\tempdb.mdf') >> GO >> ALTER DATABASE tempdb MODIFY FILE >> (name='templog', filename='Y:\TempDBLog\templog.ldf') >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) >> GO >> After this you have to restart SQL Server to make the changes effective. >> >> HTH >> Asger >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger > Blond >> Sendt: 4. december 2009 03:44 >> Til: 'Discussion concerning MS SQL Server' >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> For once you asked a simple question. The answer is: big enough. >> Asger >> >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby >> Sendt: 4. december 2009 02:57 >> Til: Discussion concerning MS SQL Server >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> Thanks Asger. I will take #5 to heart though I will have to figure out > how >> to figure out what is a >> "good size". >> >> ;) >> >> >> As I mentioned, at the moment I don't really have a lot of "new > databases". >> I do occasionally get >> new lists, but it is just occasionally. Where I do much more is in > monthly >> maintenance. Every >> month I update the database, which creates new temp (currently) tables >> inside of the existing >> database. As an example I create a sorted output table (on zip5/zip4) and >> copy every record into >> that table. I then take 2 million records at a whack and place them in a >> temp table, created on the >> fly. BCP out that "chunk". Drop the table, create it all over again, > copy >> the next 2 million >> records in. BCP out. Rinse repeat until all 50 million records are BCPd >> out. >> >> As you might imagine that process causes enormous file growth, > particularly >> in my log file but also >> in my main database file. >> >> These database are largish, at least coming from Access where the db file > is >> never more than a few >> hundred million bytes. I might start with a 30 gig file and end up with a >> 100 gig file after >> processing. The more I think about it the more I think I want to go with > a >> temp db to perform this >> export, as well as a matching import. Again though, how big is big > enough. >> I do an 11 million >> record file, then a 21 million record file, then a 50 million record file >> etc. Just building an >> empty 50 gig file takes a long time for SQL Server. >> >> I don't have any answers on how to figure this out. As I get my C# > control >> program happening I will >> be logging the start / stop time for each step (stored procedure) of this >> process. I could also log >> start and stop file sizes for the database files. >> >> Thus I could intentionally select different strategies and view my log > files >> to see the times >> required for the strategy. >> >> As of now I don't have that in place, though I am actively working on it. >> >> The other thing I want to do is get my C# controller able to detach and >> attach these databases. If >> I can detach them programmatically then I can have defrag running at > night. >> I own Perfectdisk >> server defrag which does a very good job at consolidating free space but > the >> database files have to >> be detached. >> >> BTW I moved my log files out to a separate "spindle", that being a raid >> array based on its own set >> of disks. I am looking at the log files which I have been using a lot >> lately and while they are >> large, the actual number of fragments seems (to me) to be pretty > reasonable. >> 50 gig - 4 Fragments >> 25 gig - 2 Fragments >> 30 gig - 6 Fragments >> >> Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is >> "small" at 1.5 gig. >> >> That is log file data. And understand that I often shrink the log files >> which usually shrinks them >> back down to 1 meg, and the disk was defragged awhile back to get all of > the >> free space together. >> But these log files were all created (expanded) since that defrag. >> >> I think it is useful to remember that my databases are not transactional >> databases, and activity is >> concentrated in a single database as I perform this maintenance, then I > move >> on to the next >> database. Thus it is not like there are 20 highly varied databases all >> mixing it up on a minute by >> minute basis. >> >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Asger Blond wrote: >>> Some points to consider: >>> 1. A clustered index on the PK will be useful for the join operation. >>> 2. A non clustered index on the filtering field will be useful for the >>> search operation. >>> 3. In your scenario the best choice IMO is a clustered index on the PK > and >> a >>> non clustered index on the filtering field. As mentioned in my previous >>> posting this index will automatically include the values of the PK in the >>> bottom of its index tree (the "leaf level"). Perhaps your searches don't >>> specify the PK value (I guess not, since you use surrogate keys, which of >>> cause are not candidates for searches). But nice to know anyhow - it >>> certainly should prevent you from creating a composite index on the PK >> plus >>> your filtering field: this kind of index would be an enormously waste of >>> space and performance. >>> 4. If you don't have a clustered index, then your table is a "heap". This >>> means that the records can go anywhere in the physical file. A heap can > be >>> very efficient for inserts, because SQL Server then don't have to bother >>> where to drop the records, it just scatters the records wherever room is >>> available. But it is very-very inefficient for searches and joins, > because >>> then SQL Server has to consult a special internal table named IAM to find >>> where it happened to drop your damned records. That's why it's normally >> bad. >>> But you could imagine situations where this would be very well, for >> example >>> an auditing table populated by a trigger. >>> 5. If you want to make your inserts create huge amounts of disk >>> fragmentation then just go ahead using a small-sizes db relying on auto >> grow >>> of your db. If you don't want that then follow Mark's advice and size > your >>> db initially to the anticipated size. >>> Asger >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Sat Dec 5 23:35:41 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sun, 06 Dec 2009 00:35:41 -0500 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <6CF1C41E459F4F2894524A2156D2148C@AB> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0CE6.5070706@colbyconsulting.com><5D7545B1D77D41659259165556254982@AB> <4B1B15BF.8020104@colbyconsulting.com> <6CF1C41E459F4F2894524A2156D2148C@AB> Message-ID: <4B1B42AD.7020402@colbyconsulting.com> LOL. OK. Of course I was referring to simply LOOKING at the table using SSMS. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > Sure you can: > USE tempdb > SELECT * FROM #MyTable > EXEC sp_help #MyTable > EXEC sp_helpindex #MyTable > -- and even: > ALTER TABLE #MyTable ADD MyNewColumn char(10) > > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 6. december 2009 03:24 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? > > Asger, > > Working with the tempdb is a little unsettling. With a normal table I was > able to see what fields I > had created, if my index create worked, how many records were in the table, > even view the data in > the table. With the tempdb I can see that the table exists, but can't "do > anything" with it. > > John W. Colby > www.ColbyConsulting.com From ab-mi at post3.tele.dk Sun Dec 6 09:25:35 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sun, 6 Dec 2009 16:25:35 +0100 Subject: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? In-Reply-To: <4B1B252B.8030200@colbyconsulting.com> References: <4B17E476.1020103@colbyconsulting.com> <4B18489E.6080105@colbyconsulting.com><8CFE2736E3794F1C81685C26E81B4605@AB><4B186C78.9030100@colbyconsulting.com> <4B1B0E4E.3040002@colbyconsulting.com><40035F96AC7846A2AB8DB278869BFDA0@AB> <4B1B252B.8030200@colbyconsulting.com> Message-ID: You are right about the local #table being dropped when the sp creating it ends. In this case a global ##table might be the way. You could however use a local #table if you make a call from the sp creating it to the other sp's - then the called sp's will be able to see the local #table. You can also let the called sp hand the #table over to a new sp, and so on. The #table will then be dropped when the last sp in the chain ends. Nice to know that the tempdb method is faster. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 6. december 2009 04:30 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? I am in fact testing this stuff now and am using the ##table method. I was reading that the #table was closed when the SP that creates it closes. Given that I broke my process up into many SPs it seemed prudent to use the ##table method. By the way, 50 million records into the tempdb takes 0:6:44, to the original db takes 0:12:18. So about 45% faster. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > In SSMS: When you close the query window the connection is closed and the > table in tempdb is automatically dropped. If you don't close the query > window and you open a new query window and create the same-named table in > tempdb then SQL Server will see this as a different table. > The same goes for an Access or C# control program: if you want to make sure > that you are using the same table in tempdb then stick to the same > connection, if you want to create a new table with the same name in tempdb > then either first drop this table or close the connection and reconnect. > BTW: I you actually wants a table in tempdb to be visible and operationally > across several connections then you can prefix it with ##, e.g. ##MyTable. > This kind of table will be dropped only when the last connection referencing > its closed. This is like a global variable, and I suppose not you case... > Asger > > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 6. december 2009 02:52 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] R: SPAM-LOW: Re: Do I need a cover index? > > One question about the "automatic deletion", what is the "connection" you > mention? ATM I have an > entire set of stored procedures which I run run directly from SSMS, or from > my Access or C# control > program. I assume that if run from inside of SSMS it will pretty much never > be deleted, i.e. I > would have to delete it myself? From my Access or C# control program I > would have to make sure I > used the same connection throughout the entire process? > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> Sorry John, I only read the first two lines of your posting right through > to >> ;) - thinking the rest was from another response not related to my > comment. >> Now I happen to notice that your reply was far longer... >> As I see you create temporary tables in a normal user db populating and > then >> dropping them, which causes the normal user db and its log to grow. >> Did you consider creating these tables in the special tempdb database >> instead? You create a table in the tempdb database using a # in front of > the >> tablename, e.g. #MyTable. This kind of table will automatically be deleted >> when the connection creating it is closed and it will not cause any growth >> of our normal user db. Since the tempdb database is using the "simple >> recovery model" it will also automatically truncate its own log file >> whenever an operation is finished. >> To make efficient use of the tempdb database you might want to place its >> data file and log file on separate fast drives and enlarge the files (by >> default both files are stored in the Data-directory of your SQL Server >> installation and have a size of 8MB and 1MB respectively). You change the >> default placement and size of the tempdb this way: >> >> ALTER DATABASE tempdb MODIFY FILE >> (name='tempdev', filename='X:\TempDBData\tempdb.mdf') >> GO >> ALTER DATABASE tempdb MODIFY FILE >> (name='templog', filename='Y:\TempDBLog\templog.ldf') >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'tempdev', size = 2000 MB ) >> GO >> ALTER DATABASE tempdb MODIFY FILE(name = 'templog', size = 500 MB ) >> GO >> After this you have to restart SQL Server to make the changes effective. >> >> HTH >> Asger >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger > Blond >> Sendt: 4. december 2009 03:44 >> Til: 'Discussion concerning MS SQL Server' >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> For once you asked a simple question. The answer is: big enough. >> Asger >> >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby >> Sendt: 4. december 2009 02:57 >> Til: Discussion concerning MS SQL Server >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: Do I need a cover index? >> >> Thanks Asger. I will take #5 to heart though I will have to figure out > how >> to figure out what is a >> "good size". >> >> ;) >> >> >> As I mentioned, at the moment I don't really have a lot of "new > databases". >> I do occasionally get >> new lists, but it is just occasionally. Where I do much more is in > monthly >> maintenance. Every >> month I update the database, which creates new temp (currently) tables >> inside of the existing >> database. As an example I create a sorted output table (on zip5/zip4) and >> copy every record into >> that table. I then take 2 million records at a whack and place them in a >> temp table, created on the >> fly. BCP out that "chunk". Drop the table, create it all over again, > copy >> the next 2 million >> records in. BCP out. Rinse repeat until all 50 million records are BCPd >> out. >> >> As you might imagine that process causes enormous file growth, > particularly >> in my log file but also >> in my main database file. >> >> These database are largish, at least coming from Access where the db file > is >> never more than a few >> hundred million bytes. I might start with a 30 gig file and end up with a >> 100 gig file after >> processing. The more I think about it the more I think I want to go with > a >> temp db to perform this >> export, as well as a matching import. Again though, how big is big > enough. >> I do an 11 million >> record file, then a 21 million record file, then a 50 million record file >> etc. Just building an >> empty 50 gig file takes a long time for SQL Server. >> >> I don't have any answers on how to figure this out. As I get my C# > control >> program happening I will >> be logging the start / stop time for each step (stored procedure) of this >> process. I could also log >> start and stop file sizes for the database files. >> >> Thus I could intentionally select different strategies and view my log > files >> to see the times >> required for the strategy. >> >> As of now I don't have that in place, though I am actively working on it. >> >> The other thing I want to do is get my C# controller able to detach and >> attach these databases. If >> I can detach them programmatically then I can have defrag running at > night. >> I own Perfectdisk >> server defrag which does a very good job at consolidating free space but > the >> database files have to >> be detached. >> >> BTW I moved my log files out to a separate "spindle", that being a raid >> array based on its own set >> of disks. I am looking at the log files which I have been using a lot >> lately and while they are >> large, the actual number of fragments seems (to me) to be pretty > reasonable. >> 50 gig - 4 Fragments >> 25 gig - 2 Fragments >> 30 gig - 6 Fragments >> >> Most of them are in the 2-6 fragment range. ONE is 16 fragments and it is >> "small" at 1.5 gig. >> >> That is log file data. And understand that I often shrink the log files >> which usually shrinks them >> back down to 1 meg, and the disk was defragged awhile back to get all of > the >> free space together. >> But these log files were all created (expanded) since that defrag. >> >> I think it is useful to remember that my databases are not transactional >> databases, and activity is >> concentrated in a single database as I perform this maintenance, then I > move >> on to the next >> database. Thus it is not like there are 20 highly varied databases all >> mixing it up on a minute by >> minute basis. >> >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Asger Blond wrote: >>> Some points to consider: >>> 1. A clustered index on the PK will be useful for the join operation. >>> 2. A non clustered index on the filtering field will be useful for the >>> search operation. >>> 3. In your scenario the best choice IMO is a clustered index on the PK > and >> a >>> non clustered index on the filtering field. As mentioned in my previous >>> posting this index will automatically include the values of the PK in the >>> bottom of its index tree (the "leaf level"). Perhaps your searches don't >>> specify the PK value (I guess not, since you use surrogate keys, which of >>> cause are not candidates for searches). But nice to know anyhow - it >>> certainly should prevent you from creating a composite index on the PK >> plus >>> your filtering field: this kind of index would be an enormously waste of >>> space and performance. >>> 4. If you don't have a clustered index, then your table is a "heap". This >>> means that the records can go anywhere in the physical file. A heap can > be >>> very efficient for inserts, because SQL Server then don't have to bother >>> where to drop the records, it just scatters the records wherever room is >>> available. But it is very-very inefficient for searches and joins, > because >>> then SQL Server has to consult a special internal table named IAM to find >>> where it happened to drop your damned records. That's why it's normally >> bad. >>> But you could imagine situations where this would be very well, for >> example >>> an auditing table populated by a trigger. >>> 5. If you want to make your inserts create huge amounts of disk >>> fragmentation then just go ahead using a small-sizes db relying on auto >> grow >>> of your db. If you don't want that then follow Mark's advice and size > your >>> db initially to the anticipated size. >>> Asger >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Tue Dec 8 07:09:12 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 08 Dec 2009 08:09:12 -0500 Subject: [dba-SQLServer] Common Table Expressions - The solution to one of my problems Message-ID: <4B1E4FF8.9040602@colbyconsulting.com> http://www.sqlservercentral.com/articles/T-SQL/68651/ It looks way easy! -- John W. Colby www.ColbyConsulting.com From erbachs at gmail.com Tue Dec 8 12:58:28 2009 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 8 Dec 2009 12:58:28 -0600 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 on a workstation, not the server Message-ID: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> Dear Group, I'm trying to help my wife who is the de facto network administrator for the small company she works for. The main order processing application uses SQL Server 2005 on the domain server. That SQL Server is having problems. What we've tried is to copy the MDF and log file to a workstation that has SQL Server 2005 installed on it. The application is an Access MDB connected via ODBC to the SQL Server database. We can connect to the SQL Server database just fine if we run the Access application on that workstation. The problem comes in when we try to connect to the database from another workstation on the LAN. We keep getting "SQL Server not found". I can't get the System ODBC connection to "see" the SQL Server on the workstation...nor can I get Access 2003 to create an ADP project to connect directly to SQL Server 2005 on that other workstation. We've got a call into Microsoft support to do the surgery necessary to get the main domain server's installation of SQL Server up and running...it's just that we thought we could point the Access application to the database on the workstation copy of SQL Server 2005 and at least get a couple workstations going with entering orders, etc. The server is Windows Small Business Server 2008 which includes SQL Server 2005 Standard edition. The installation of SQL Server 2005 on the workstation is also Standard edition. Any clue as to how we can connect to a workstation copy of SQL Server? I'm pulling my hair out trying to figure out why other workstations cannot "see" the SQL Server on the workstation. Regards, Steve Erbach Neenah, WI From jeff.developer at gmail.com Tue Dec 8 14:05:41 2009 From: jeff.developer at gmail.com (Jeff B) Date: Tue, 8 Dec 2009 14:05:41 -0600 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 on a workstation, not the server In-Reply-To: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> References: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> Message-ID: <4b1eb13a.5644f10a.6430.3911@mx.google.com> I believe that you need a NAMED copy of SQL Server in order to connect from a different workstation. Jeff Barrows MCP, MCAD, MCSD ? Outbak Technologies, LLC Racine, WI jeff.developer at gmail.com -----Original Message----- From: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of Steve Erbach Sent: Tuesday, December 08, 2009 12:58 PM To: Discussion concerning MS SQL Server Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 on a workstation, not the server Dear Group, I'm trying to help my wife who is the de facto network administrator for the small company she works for. The main order processing application uses SQL Server 2005 on the domain server. That SQL Server is having problems. What we've tried is to copy the MDF and log file to a workstation that has SQL Server 2005 installed on it. The application is an Access MDB connected via ODBC to the SQL Server database. We can connect to the SQL Server database just fine if we run the Access application on that workstation. The problem comes in when we try to connect to the database from another workstation on the LAN. We keep getting "SQL Server not found". I can't get the System ODBC connection to "see" the SQL Server on the workstation...nor can I get Access 2003 to create an ADP project to connect directly to SQL Server 2005 on that other workstation. We've got a call into Microsoft support to do the surgery necessary to get the main domain server's installation of SQL Server up and running...it's just that we thought we could point the Access application to the database on the workstation copy of SQL Server 2005 and at least get a couple workstations going with entering orders, etc. The server is Windows Small Business Server 2008 which includes SQL Server 2005 Standard edition. The installation of SQL Server 2005 on the workstation is also Standard edition. Any clue as to how we can connect to a workstation copy of SQL Server? I'm pulling my hair out trying to figure out why other workstations cannot "see" the SQL Server on the workstation. Regards, Steve Erbach Neenah, WI _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com No virus found in this incoming message. Checked by AVG - www.avg.com Version: 9.0.709 / Virus Database: 270.14.98/2552 - Release Date: 12/08/09 01:34:00 From erbachs at gmail.com Tue Dec 8 14:47:25 2009 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 8 Dec 2009 14:47:25 -0600 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 on a workstation, not the server In-Reply-To: <4b1eb13a.5644f10a.6430.3911@mx.google.com> References: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> <4b1eb13a.5644f10a.6430.3911@mx.google.com> Message-ID: <39cb22f30912081247t2fd5eac4pdbcad68f99945380@mail.gmail.com> Jeff, When I left my wife's place of employment about 45 minutes ago, she was on the phone with the people that installed SBS 2008. It MAY be the centralized firewall settings for all the workstations. The guy seemed to think that if the firewall on the workstation that has SQL Server installed is opened up, then it may work. My wife hasn't called yet. She may be on the phone now with the Microsoft support guy who was slated to help her get the SBS Server's copy of SQL Server back in operation. Thanks for the reply...I'll relay that to my wife. Steve Erbach On Tue, Dec 8, 2009 at 2:05 PM, Jeff B wrote: > I believe that you need a NAMED copy of SQL Server in order to connect from > a different workstation. > > Jeff Barrows > MCP, MCAD, MCSD > > Outbak Technologies, LLC > Racine, WI > jeff.developer at gmail.com > > -----Original Message----- > From: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of Steve > Erbach > Sent: Tuesday, December 08, 2009 12:58 PM > To: Discussion concerning MS SQL Server > Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 > on > a workstation, not the server > > Dear Group, > > I'm trying to help my wife who is the de facto network administrator for > the > small company she works for. The main order processing application uses > SQL > Server 2005 on the domain server. That SQL Server is having problems. > > What we've tried is to copy the MDF and log file to a workstation that has > SQL Server 2005 installed on it. The application is an Access MDB > connected > via ODBC to the SQL Server database. We can connect to the SQL Server > database just fine if we run the Access application on that workstation. > > The problem comes in when we try to connect to the database from another > workstation on the LAN. We keep getting "SQL Server not found". I can't > get the System ODBC connection to "see" the SQL Server on the > workstation...nor can I get Access 2003 to create an ADP project to connect > directly to SQL Server 2005 on that other workstation. > > We've got a call into Microsoft support to do the surgery necessary to get > the main domain server's installation of SQL Server up and running...it's > just that we thought we could point the Access application to the database > on the workstation copy of SQL Server 2005 and at least get a couple > workstations going with entering orders, etc. > > The server is Windows Small Business Server 2008 which includes SQL Server > 2005 Standard edition. The installation of SQL Server 2005 on the > workstation is also Standard edition. > > Any clue as to how we can connect to a workstation copy of SQL Server? I'm > pulling my hair out trying to figure out why other workstations cannot > "see" > the SQL Server on the workstation. > > Regards, > > Steve Erbach > From erbachs at gmail.com Tue Dec 8 15:25:40 2009 From: erbachs at gmail.com (Steve Erbach) Date: Tue, 8 Dec 2009 15:25:40 -0600 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 on a workstation, not the server In-Reply-To: <4b1eb13a.5644f10a.6430.3911@mx.google.com> References: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> <4b1eb13a.5644f10a.6430.3911@mx.google.com> Message-ID: <39cb22f30912081325s318f1d6bi5ec3bd862ac20c6a@mail.gmail.com> Jeff, I just tried setting up an Access 2003 ADP project on my wife's PC at home connecting to SQL Server 2005 on my workstation. We don't have anything other than the Windows peer-to-peer network running. I was able to connect to the SQL Server on my system which is NOT a named copy. The SQL Server has the same name as my PC. It's gotta be something related to access rights/sharing on that workstation at my wife's office. They have only the one server which does everything: Exchange, SBS, SQL Server. It also hosted the Access back end for the application they run that they just recently upgraded to the SQL Server version with ODBC connections to the Access front end. Steve Erbach Neenah, WI On Tue, Dec 8, 2009 at 2:05 PM, Jeff B wrote: > I believe that you need a NAMED copy of SQL Server in order to connect from > a different workstation. > > Jeff Barrows > MCP, MCAD, MCSD > > Outbak Technologies, LLC > Racine, WI > jeff.developer at gmail.com > > -----Original Message----- > From: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of Steve > Erbach > Sent: Tuesday, December 08, 2009 12:58 PM > To: Discussion concerning MS SQL Server > Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 > on > a workstation, not the server > > Dear Group, > > I'm trying to help my wife who is the de facto network administrator for > the > small company she works for. The main order processing application uses > SQL > Server 2005 on the domain server. That SQL Server is having problems. > > What we've tried is to copy the MDF and log file to a workstation that has > SQL Server 2005 installed on it. The application is an Access MDB > connected > via ODBC to the SQL Server database. We can connect to the SQL Server > database just fine if we run the Access application on that workstation. > > The problem comes in when we try to connect to the database from another > workstation on the LAN. We keep getting "SQL Server not found". I can't > get the System ODBC connection to "see" the SQL Server on the > workstation...nor can I get Access 2003 to create an ADP project to connect > directly to SQL Server 2005 on that other workstation. > > We've got a call into Microsoft support to do the surgery necessary to get > the main domain server's installation of SQL Server up and running...it's > just that we thought we could point the Access application to the database > on the workstation copy of SQL Server 2005 and at least get a couple > workstations going with entering orders, etc. > > The server is Windows Small Business Server 2008 which includes SQL Server > 2005 Standard edition. The installation of SQL Server 2005 on the > workstation is also Standard edition. > > Any clue as to how we can connect to a workstation copy of SQL Server? I'm > pulling my hair out trying to figure out why other workstations cannot > "see" > the SQL Server on the workstation. > > Regards, > > Steve Erbach > From jwcolby at colbyconsulting.com Tue Dec 8 16:26:19 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 08 Dec 2009 17:26:19 -0500 Subject: [dba-SQLServer] Stored Proc RETURN Message-ID: <4B1ED28B.4010009@colbyconsulting.com> Does the RETURN statement cause an immediate exit from the SP, returning a value in the process? Or does it simply set the return variable? -- John W. Colby www.ColbyConsulting.com From michael at ddisolutions.com.au Tue Dec 8 16:44:07 2009 From: michael at ddisolutions.com.au (Michael Maddison) Date: Wed, 9 Dec 2009 09:44:07 +1100 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 ona workstation, not the server References: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> Message-ID: <59A61174B1F5B54B97FD4ADDE71E7D0158280B@ddi-01.DDI.local> Steve, Try this... Open SQL Server Configuration Manager on the workstation. Expand Native Client Config. Make sure TCP/IP is enabled. Check the Default Port in the properties. Check your firewall that the port is set as an exemption. Cheers Michael M Dear Group, I'm trying to help my wife who is the de facto network administrator for the small company she works for. The main order processing application uses SQL Server 2005 on the domain server. That SQL Server is having problems. What we've tried is to copy the MDF and log file to a workstation that has SQL Server 2005 installed on it. The application is an Access MDB connected via ODBC to the SQL Server database. We can connect to the SQL Server database just fine if we run the Access application on that workstation. The problem comes in when we try to connect to the database from another workstation on the LAN. We keep getting "SQL Server not found". I can't get the System ODBC connection to "see" the SQL Server on the workstation...nor can I get Access 2003 to create an ADP project to connect directly to SQL Server 2005 on that other workstation. We've got a call into Microsoft support to do the surgery necessary to get the main domain server's installation of SQL Server up and running...it's just that we thought we could point the Access application to the database on the workstation copy of SQL Server 2005 and at least get a couple workstations going with entering orders, etc. The server is Windows Small Business Server 2008 which includes SQL Server 2005 Standard edition. The installation of SQL Server 2005 on the workstation is also Standard edition. Any clue as to how we can connect to a workstation copy of SQL Server? I'm pulling my hair out trying to figure out why other workstations cannot "see" the SQL Server on the workstation. Regards, Steve Erbach Neenah, WI _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com No virus found in this incoming message. Checked by AVG - www.avg.com Version: 9.0.709 / Virus Database: 270.14.91/2541 - Release Date: 12/08/09 06:34:00 From erbachs at gmail.com Wed Dec 9 09:43:14 2009 From: erbachs at gmail.com (Steve Erbach) Date: Wed, 9 Dec 2009 09:43:14 -0600 Subject: [dba-SQLServer] PRETTY URGENT: How to connect to SQL Server 2005 ona workstation, not the server In-Reply-To: <59A61174B1F5B54B97FD4ADDE71E7D0158280B@ddi-01.DDI.local> References: <39cb22f30912081058o1f19ad0fmd7e9090450a0d2e4@mail.gmail.com> <59A61174B1F5B54B97FD4ADDE71E7D0158280B@ddi-01.DDI.local> Message-ID: <39cb22f30912090743h7a5fe7c3v715691cb36ac4ef8@mail.gmail.com> Michael, After about six hours on the phone with Microsoft, my wife got things working again. The server's registry had to be re-built and SQL Server re-installed. So the use of a workstation copy of SQL Server is now moot. However, it would be VERY interesting to see about getting that capability working in case the server ever puked again. I will keep your suggestion handy and forward it to my wife. Thank you. Steve Erbach Neenah, WI On Tue, Dec 8, 2009 at 4:44 PM, Michael Maddison < michael at ddisolutions.com.au> wrote: > Steve, > > Try this... > > Open SQL Server Configuration Manager on the workstation. > Expand Native Client Config. > Make sure TCP/IP is enabled. > Check the Default Port in the properties. > Check your firewall that the port is set as an exemption. > > Cheers > > Michael M > > > > Dear Group, > > I'm trying to help my wife who is the de facto network administrator for > the > small company she works for. The main order processing application uses > SQL > Server 2005 on the domain server. That SQL Server is having problems. > > What we've tried is to copy the MDF and log file to a workstation that > has > SQL Server 2005 installed on it. The application is an Access MDB > connected > via ODBC to the SQL Server database. We can connect to the SQL Server > database just fine if we run the Access application on that workstation. > > The problem comes in when we try to connect to the database from another > workstation on the LAN. We keep getting "SQL Server not found". I > can't > get the System ODBC connection to "see" the SQL Server on the > workstation...nor can I get Access 2003 to create an ADP project to > connect > directly to SQL Server 2005 on that other workstation. > > From ab-mi at post3.tele.dk Wed Dec 9 09:52:45 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Wed, 9 Dec 2009 16:52:45 +0100 Subject: [dba-SQLServer] Stored Proc RETURN In-Reply-To: <4B1ED28B.4010009@colbyconsulting.com> References: <4B1ED28B.4010009@colbyconsulting.com> Message-ID: <15BC5EF3427249C4B265ADADB1FADCC2@AB> It causes an immediate exit from the SP. It might also return an integer value if you state for instance RETURN 2. To get the integer value from the RETURN however you have to execute the SP like this: DECLARE @retval int @retval = EXEC MySP SELECT @retval Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 8. december 2009 23:26 Til: Dba-Sqlserver Emne: [dba-SQLServer] Stored Proc RETURN Does the RETURN statement cause an immediate exit from the SP, returning a value in the process? Or does it simply set the return variable? -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From ab-mi at post3.tele.dk Wed Dec 9 10:08:08 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Wed, 9 Dec 2009 17:08:08 +0100 Subject: [dba-SQLServer] Stored Proc RETURN In-Reply-To: <15BC5EF3427249C4B265ADADB1FADCC2@AB> References: <4B1ED28B.4010009@colbyconsulting.com> <15BC5EF3427249C4B265ADADB1FADCC2@AB> Message-ID: <4AA3F07A518D4E73A1A0375D10D704D8@AB> Typo, the execution should be like this: DECLARE @retval int EXEC @retval = MySP SELECT @retval Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond Sendt: 9. december 2009 16:53 Til: 'Discussion concerning MS SQL Server' Emne: Re: [dba-SQLServer] Stored Proc RETURN It causes an immediate exit from the SP. It might also return an integer value if you state for instance RETURN 2. To get the integer value from the RETURN however you have to execute the SP like this: DECLARE @retval int @retval = EXEC MySP SELECT @retval Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 8. december 2009 23:26 Til: Dba-Sqlserver Emne: [dba-SQLServer] Stored Proc RETURN Does the RETURN statement cause an immediate exit from the SP, returning a value in the process? Or does it simply set the return variable? -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Fri Dec 11 10:08:46 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 11:08:46 -0500 Subject: [dba-SQLServer] Add records to large file Message-ID: <4B226E8E.2080109@colbyconsulting.com> I don't have a clustered index on my database from hell main table, the 50 million record 600 field table. I am going to do that. What I thought I would do is simply make a new database, create a new table, and append the existing data into the new table. There is a unique integer PK which will be the key of the index. My question is whether it is faster to create the clustered index and then insert the records, already sorted in PKID, or create the table and then create the index. Logically it seems that it would be faster to do the insert sorted with the index already in place, but I have heard opinions that it is "often faster" to drop the index and recreate", i.e. do the index after the records are in place. -- John W. Colby www.ColbyConsulting.com From jwcolby at colbyconsulting.com Fri Dec 11 10:18:25 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 11:18:25 -0500 Subject: [dba-SQLServer] Turn off an index Message-ID: <4B2270D1.8080709@colbyconsulting.com> My DBFH large table never changes, it is read-only. I create cover indexes for sets of related fields used in where clauses. Why would I turn on / off an index? Is there any advantage to leaving an index "turned off" for a read-only file or is this one of those "while you are updating" kind of things that I don't need to be concerned about? -- John W. Colby www.ColbyConsulting.com From jwcolby at colbyconsulting.com Fri Dec 11 12:28:41 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 13:28:41 -0500 Subject: [dba-SQLServer] How to construct queries Message-ID: <4B228F59.9080502@colbyconsulting.com> I often have to do things like "supply counts of records where..." and the list will be something like: FieldA = "Y" or FieldB = "Y" or FieldC = "Y" ... Often times the counts must be for sets of fields, for example FieldA through FieldG or FieldX through FieldZ These fields are usually a small minority of the total 50 million records, sometimes a million, sometimes 5 million etc. So I have routinely created cover indexes for the groups, one index for FieldA..FieldG, another index for FieldX .. FieldZ. If a query requests data from fields in both groups, will the query use both cover indexes to grab the data for the records? Is there a more efficient way to do these kinds of counts? -- John W. Colby www.ColbyConsulting.com From fhtapia at gmail.com Fri Dec 11 13:03:27 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Fri, 11 Dec 2009 11:03:27 -0800 Subject: [dba-SQLServer] Turn off an index In-Reply-To: <4B2270D1.8080709@colbyconsulting.com> References: <4B2270D1.8080709@colbyconsulting.com> Message-ID: <1D23256A-E172-474B-9BAD-2D03F45994BB@gmail.com> You'd normally want this to be off when you are updating hundreds of records so the db doesn't need to update the row and the index. Sent from my mobile On Dec 11, 2009, at 8:18 AM, jwcolby wrote: > My DBFH large table never changes, it is read-only. I create cover > indexes for sets of related > fields used in where clauses. Why would I turn on / off an index? > Is there any advantage to > leaving an index "turned off" for a read-only file or is this one of > those "while you are updating" > kind of things that I don't need to be concerned about? > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From fhtapia at gmail.com Fri Dec 11 13:07:10 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Fri, 11 Dec 2009 11:07:10 -0800 Subject: [dba-SQLServer] Add records to large file In-Reply-To: <4B226E8E.2080109@colbyconsulting.com> References: <4B226E8E.2080109@colbyconsulting.com> Message-ID: <5594FBD7-834B-4C65-81E6-A31E36F64F7C@gmail.com> Ime I've had better performance with the latter solution when the records are already in place. That's because when you sort a table if it's too big to go in memory then the sort occurs in the tempdb. If you have the tempdb on flash drives then maybe the sort would be faster. Ymmv Sent from my mobile On Dec 11, 2009, at 8:08 AM, jwcolby wrote: > I don't have a clustered index on my database from hell main table, > the 50 million record 600 field > table. > > I am going to do that. What I thought I would do is simply make a > new database, create a new table, > and append the existing data into the new table. There is a unique > integer PK which will be the key > of the index. > > My question is whether it is faster to create the clustered index > and then insert the records, > already sorted in PKID, or create the table and then create the index. > > Logically it seems that it would be faster to do the insert sorted > with the index already in place, > but I have heard opinions that it is "often faster" to drop the > index and recreate", i.e. do the > index after the records are in place. > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From jwcolby at colbyconsulting.com Fri Dec 11 13:24:56 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 14:24:56 -0500 Subject: [dba-SQLServer] Turn off an index In-Reply-To: <1D23256A-E172-474B-9BAD-2D03F45994BB@gmail.com> References: <4B2270D1.8080709@colbyconsulting.com> <1D23256A-E172-474B-9BAD-2D03F45994BB@gmail.com> Message-ID: <4B229C88.8010605@colbyconsulting.com> Thanks Francisco, that's what I thought. Not applicable to me. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > You'd normally want this to be off when you are updating hundreds of > records so the db doesn't need to update the row and the index. > > Sent from my mobile > > On Dec 11, 2009, at 8:18 AM, jwcolby > wrote: > >> My DBFH large table never changes, it is read-only. I create cover >> indexes for sets of related >> fields used in where clauses. Why would I turn on / off an index? >> Is there any advantage to >> leaving an index "turned off" for a read-only file or is this one of >> those "while you are updating" >> kind of things that I don't need to be concerned about? >> >> -- >> John W. Colby >> www.ColbyConsulting.com >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Fri Dec 11 13:29:32 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 14:29:32 -0500 Subject: [dba-SQLServer] Add records to large file In-Reply-To: <5594FBD7-834B-4C65-81E6-A31E36F64F7C@gmail.com> References: <4B226E8E.2080109@colbyconsulting.com> <5594FBD7-834B-4C65-81E6-A31E36F64F7C@gmail.com> Message-ID: <4B229D9C.1080505@colbyconsulting.com> Thanks Francisco. I went ahead and did it with the index in place and it finished reasonably fast. I am guessing around 1/2 hour though I didn't time it. I kinda figured it would be many hours. All these years I have been working with this huge table on the heap. With luck this will have a positive impact on future operations. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > Ime I've had better performance with the latter solution when the > records are already in place. That's because when you sort a table if > it's too big to go in memory then the sort occurs in the tempdb. If > you have the tempdb on flash drives then maybe the sort would be > faster. Ymmv > > Sent from my mobile > > On Dec 11, 2009, at 8:08 AM, jwcolby > wrote: > >> I don't have a clustered index on my database from hell main table, >> the 50 million record 600 field >> table. >> >> I am going to do that. What I thought I would do is simply make a >> new database, create a new table, >> and append the existing data into the new table. There is a unique >> integer PK which will be the key >> of the index. >> >> My question is whether it is faster to create the clustered index >> and then insert the records, >> already sorted in PKID, or create the table and then create the index. >> >> Logically it seems that it would be faster to do the insert sorted >> with the index already in place, >> but I have heard opinions that it is "often faster" to drop the >> index and recreate", i.e. do the >> index after the records are in place. >> >> -- >> John W. Colby >> www.ColbyConsulting.com >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Fri Dec 11 18:44:11 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sat, 12 Dec 2009 01:44:11 +0100 Subject: [dba-SQLServer] How to construct queries In-Reply-To: <4B228F59.9080502@colbyconsulting.com> References: <4B228F59.9080502@colbyconsulting.com> Message-ID: <79D4EB99552C4ADD899D148B4A8EFE93@AB> John, It will be useful for you to explore the execution plans for your queries. You do so by highlighting the query in SSMS and pressing CTRL+L. The Execution Plan window may be overwhelming but you just have to focus on the rightmost ikon which is indicating either "Table scan" or "Index Scan" or "Index seek". Now for your question: To understand what's going on you have to distinguish *fetch operation* and *search operation*. You also have to distinguish a *composite index* and an *index with included columns*. A covering index means that SQL Server can *fetch* the records you are selecting in your query from the leaf level (=bottom level) of your index-tree, not having to make a lookup to the data pages. But a covering index doesn't mean that SQL Server can use your index for its *search* operations. SQL Server can only use the index for a *search* operation if your where-condition references a field which is the *first* field defined in the index. And to make things more complicated: A covering index can be accomplished in to ways: as a *composite index* or as an *index with included columns*. A composite index is created this way: CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) An index with included columns is created this way: CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, FieldD) A *composite index* records all specified columns in every level of the index-tree, and it is very useful for multi-field *sorting* operations. But it is not useful for multi-field *search" operations, because SQL Server will only consider using this index for a query referencing the *first* field (here FieldA) in the where-condition. It is however very useful for *fetch* operations, since SQL Server then can do with an "index scan" on the leaf level of the index not having to make a lookup the actual data-pages. This is only true however if you are selecting fields which are present in the index: if your query selects fields not defined in an index then SQL Server has to use a *table scan* which is not efficient. And now you may ask: What about a SELECT COUNT(*) - isn't this referencing all fields and shouldn't this per definition prevent SQL Server from using the index? Don't worry: COUNT(*) is a special case where SQL Server will use the index if it can make the execution more efficient. An *index with included columns* only records the included columns in the leaf level of the index. For this reason it is neither useful for multi-field *sorting* operations nor for *search* operations on the included columns. But as for *composite indexes* it is very useful for *fetch* operations. Bottom line: A *composite index* is good for multi-columns sorting and covering queries, but it doesn't help *search* operations and it imposes an overhead forcing SQL Server to record all fields in every level of the index-tree. An *index with included column* it good for covering queries too, but it doesn't help multi-columns sorting and it doesn't help *search* operations either - however it imposes fare less overhead cause the included fields are only recorded in the leaf-level of the index. I suggest you play whith the different options using CTRL+L - pretty soon you will notice this: Composite index on FieldA, FieldB, FieldC Composite index on FieldD, FieldE, FieldF SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" --> Index Scan SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps two index seeks merged SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably a table scan Index on FieldA including FieldB and FieldC Index on FieldA including FieldD and FieldF --> exactly same results Another option is to use a separate index on each field. Then you will notice: SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps two index seeks merged SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" --> Probably a table scan Mind that the results will depend on the actual values present in your table. SQL Server maintains statistics of the indexed columns and if there is a low selectivity for you query (= a high rate of matching values in the indexed search-field) then chance is that SQL Server don't want to use the index and will prefer using a table scan instead. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 11. december 2009 19:29 Til: Dba-Sqlserver Emne: [dba-SQLServer] How to construct queries I often have to do things like "supply counts of records where..." and the list will be something like: FieldA = "Y" or FieldB = "Y" or FieldC = "Y" ... Often times the counts must be for sets of fields, for example FieldA through FieldG or FieldX through FieldZ These fields are usually a small minority of the total 50 million records, sometimes a million, sometimes 5 million etc. So I have routinely created cover indexes for the groups, one index for FieldA..FieldG, another index for FieldX .. FieldZ. If a query requests data from fields in both groups, will the query use both cover indexes to grab the data for the records? Is there a more efficient way to do these kinds of counts? -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Fri Dec 11 20:25:54 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Fri, 11 Dec 2009 21:25:54 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: <79D4EB99552C4ADD899D148B4A8EFE93@AB> References: <4B228F59.9080502@colbyconsulting.com> <79D4EB99552C4ADD899D148B4A8EFE93@AB> Message-ID: <4B22FF32.5030201@colbyconsulting.com> Wow Asger. That is a lot of information and ... All of my indexes were created with the index wizard and as far as I can tell they are composite indexes. In fact I "script index as create" and they are in fact composite indexes. Having seen your code and my scripts I can see how I would create "included columns" indexes but UI don't see how that would be done with the wizard. What I think I am hearing is that none of these indexes are useful for where clauses with multiple fields in the where (virtually all of my queries), but it is useful for returning the data (which I do in the ORDERS, though I do not need to in the COUNTS. In fact, rereading this a bit... >SQL Server can only use the index for a *search* operation if your where-condition references a field which is the *first* field defined in the index. Are you saying that the where clause simply has to include the first field in the index somewhere in the where? Because in fact I custom create these indexes. and that is the case. Except, in this last count I had more than 16 fields in the where (a bunch of ORs) and so I had to break the index into two parts, but again the where clause does in fact reference (use) the first field in both indexes (it uses every field in both indexes). Does this mean that these indexes are then useful for the search? BTW I looked at the execution plan and it shows two parallel index scans each accounting for about 5% of the cost, followed by (in each stream) logical operation repartition stream (11% in each stream, and immediately after that an "inner join" accounting for 64% of the cost. Thus it appears that it is in fact using the cover indexes maybe? Pretty complex stuff though (for me). Thanks again though for that explanation, it is useful. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John, > It will be useful for you to explore the execution plans for your queries. > You do so by highlighting the query in SSMS and pressing CTRL+L. > The Execution Plan window may be overwhelming but you just have to focus on > the rightmost ikon which is indicating either "Table scan" or "Index Scan" > or "Index seek". > Now for your question: > To understand what's going on you have to distinguish *fetch operation* and > *search operation*. You also have to distinguish a *composite index* and an > *index with included columns*. > A covering index means that SQL Server can *fetch* the records you are > selecting in your query from the leaf level (=bottom level) of your > index-tree, not having to make a lookup to the data pages. > But a covering index doesn't mean that SQL Server can use your index for its > *search* operations. SQL Server can only use the index for a *search* > operation if your where-condition references a field which is the *first* > field defined in the index. > And to make things more complicated: A covering index can be accomplished in > to ways: as a *composite index* or as an *index with included columns*. > A composite index is created this way: > CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) > An index with included columns is created this way: > CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, > FieldD) > A *composite index* records all specified columns in every level of the > index-tree, and it is very useful for multi-field *sorting* operations. But > it is not useful for multi-field *search" operations, because SQL Server > will only consider using this index for a query referencing the *first* > field (here FieldA) in the where-condition. It is however very useful for > *fetch* operations, since SQL Server then can do with an "index scan" on the > leaf level of the index not having to make a lookup the actual data-pages. > This is only true however if you are selecting fields which are present in > the index: if your query selects fields not defined in an index then SQL > Server has to use a *table scan* which is not efficient. And now you may > ask: What about a SELECT COUNT(*) - isn't this referencing all fields and > shouldn't this per definition prevent SQL Server from using the index? Don't > worry: COUNT(*) is a special case where SQL Server will use the index if it > can make the execution more efficient. > An *index with included columns* only records the included columns in the > leaf level of the index. For this reason it is neither useful for > multi-field *sorting* operations nor for *search* operations on the included > columns. But as for *composite indexes* it is very useful for *fetch* > operations. > Bottom line: > A *composite index* is good for multi-columns sorting and covering queries, > but it doesn't help *search* operations and it imposes an overhead forcing > SQL Server to record all fields in every level of the index-tree. An *index > with included column* it good for covering queries too, but it doesn't help > multi-columns sorting and it doesn't help *search* operations either - > however it imposes fare less overhead cause the included fields are only > recorded in the leaf-level of the index. > > I suggest you play whith the different options using CTRL+L - pretty soon > you will notice this: > > Composite index on FieldA, FieldB, FieldC > Composite index on FieldD, FieldE, FieldF > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" > --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps two > index seeks merged > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably a > table scan > > Index on FieldA including FieldB and FieldC > Index on FieldA including FieldD and FieldF > --> exactly same results > > Another option is to use a separate index on each field. Then you will > notice: > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps two > index seeks merged > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" > --> Probably a table scan > > Mind that the results will depend on the actual values present in your > table. SQL Server maintains statistics of the indexed columns and if there > is a low selectivity for you query (= a high rate of matching values in the > indexed search-field) then chance is that SQL Server don't want to use the > index and will prefer using a table scan instead. > > Asger From ab-mi at post3.tele.dk Sat Dec 12 09:34:21 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sat, 12 Dec 2009 16:34:21 +0100 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: <4B22FF32.5030201@colbyconsulting.com> References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com> Message-ID: <9E433E5767FA43878B1D48C688587825@AB> > ..the where clause does in fact reference (use) the first field in both > indexes (it uses every field in both indexes). > Does this mean that these indexes are then useful for the search? Yes in principle. But as said SQL Server will evaluate if using the index for its search (traversing the index-tree) or using the index for a scan (running through the leaf level of the index) is the most efficient. If your where-condition has a low selectivity (high amount of matching values in the field) then an index scan is more efficient than an index seek. That's the beauty of SQL as opposed to procedural languages: in SQL you don't tell how to do the job - you just tell what you want and then the query optimizer will figure out the best way. Your execution plan shows two parallel index scan and a join. This means that the query optimizer is in fact using your indexes as covering indexes (if it was not then you would see either table scans or lookup operations in the plan). But it also tell that the optimizer do not use the indexes for its search operations (in that case you would see index seeks). If you constantly notice that the execution plan is using index scans rather than index seeks then you might consider using indexes with included columns instead of composite indexes. But if your table gets repopulated with new records having less amount of matching values for the search field then you might notice that the optimizer now will find your composite index useful for its searches. In that case I would stick to the composite index. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 12. december 2009 03:26 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries Wow Asger. That is a lot of information and ... All of my indexes were created with the index wizard and as far as I can tell they are composite indexes. In fact I "script index as create" and they are in fact composite indexes. Having seen your code and my scripts I can see how I would create "included columns" indexes but UI don't see how that would be done with the wizard. What I think I am hearing is that none of these indexes are useful for where clauses with multiple fields in the where (virtually all of my queries), but it is useful for returning the data (which I do in the ORDERS, though I do not need to in the COUNTS. In fact, rereading this a bit... >SQL Server can only use the index for a *search* operation if your where-condition references a field which is the *first* field defined in the index. Are you saying that the where clause simply has to include the first field in the index somewhere in the where? Because in fact I custom create these indexes. and that is the case. Except, in this last count I had more than 16 fields in the where (a bunch of ORs) and so I had to break the index into two parts, but again the where clause does in fact reference (use) the first field in both indexes (it uses every field in both indexes). Does this mean that these indexes are then useful for the search? BTW I looked at the execution plan and it shows two parallel index scans each accounting for about 5% of the cost, followed by (in each stream) logical operation repartition stream (11% in each stream, and immediately after that an "inner join" accounting for 64% of the cost. Thus it appears that it is in fact using the cover indexes maybe? Pretty complex stuff though (for me). Thanks again though for that explanation, it is useful. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John, > It will be useful for you to explore the execution plans for your queries. > You do so by highlighting the query in SSMS and pressing CTRL+L. > The Execution Plan window may be overwhelming but you just have to focus on > the rightmost ikon which is indicating either "Table scan" or "Index Scan" > or "Index seek". > Now for your question: > To understand what's going on you have to distinguish *fetch operation* and > *search operation*. You also have to distinguish a *composite index* and an > *index with included columns*. > A covering index means that SQL Server can *fetch* the records you are > selecting in your query from the leaf level (=bottom level) of your > index-tree, not having to make a lookup to the data pages. > But a covering index doesn't mean that SQL Server can use your index for its > *search* operations. SQL Server can only use the index for a *search* > operation if your where-condition references a field which is the *first* > field defined in the index. > And to make things more complicated: A covering index can be accomplished in > to ways: as a *composite index* or as an *index with included columns*. > A composite index is created this way: > CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) > An index with included columns is created this way: > CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, > FieldD) > A *composite index* records all specified columns in every level of the > index-tree, and it is very useful for multi-field *sorting* operations. But > it is not useful for multi-field *search" operations, because SQL Server > will only consider using this index for a query referencing the *first* > field (here FieldA) in the where-condition. It is however very useful for > *fetch* operations, since SQL Server then can do with an "index scan" on the > leaf level of the index not having to make a lookup the actual data-pages. > This is only true however if you are selecting fields which are present in > the index: if your query selects fields not defined in an index then SQL > Server has to use a *table scan* which is not efficient. And now you may > ask: What about a SELECT COUNT(*) - isn't this referencing all fields and > shouldn't this per definition prevent SQL Server from using the index? Don't > worry: COUNT(*) is a special case where SQL Server will use the index if it > can make the execution more efficient. > An *index with included columns* only records the included columns in the > leaf level of the index. For this reason it is neither useful for > multi-field *sorting* operations nor for *search* operations on the included > columns. But as for *composite indexes* it is very useful for *fetch* > operations. > Bottom line: > A *composite index* is good for multi-columns sorting and covering queries, > but it doesn't help *search* operations and it imposes an overhead forcing > SQL Server to record all fields in every level of the index-tree. An *index > with included column* it good for covering queries too, but it doesn't help > multi-columns sorting and it doesn't help *search* operations either - > however it imposes fare less overhead cause the included fields are only > recorded in the leaf-level of the index. > > I suggest you play whith the different options using CTRL+L - pretty soon > you will notice this: > > Composite index on FieldA, FieldB, FieldC > Composite index on FieldD, FieldE, FieldF > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" > --> Index Scan > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps two > index seeks merged > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably a > table scan > > Index on FieldA including FieldB and FieldC > Index on FieldA including FieldD and FieldF > --> exactly same results > > Another option is to use a separate index on each field. Then you will > notice: > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps two > index seeks merged > SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" > --> Probably a table scan > > Mind that the results will depend on the actual values present in your > table. SQL Server maintains statistics of the indexed columns and if there > is a low selectivity for you query (= a high rate of matching values in the > indexed search-field) then chance is that SQL Server don't want to use the > index and will prefer using a table scan instead. > > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Sat Dec 12 11:36:47 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sat, 12 Dec 2009 12:36:47 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: <9E433E5767FA43878B1D48C688587825@AB> References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com> <9E433E5767FA43878B1D48C688587825@AB> Message-ID: <4B23D4AF.4040404@colbyconsulting.com> Asger, >But if your table gets repopulated with new records At least in this case the table is entirely static, never updated in any way. John W. Colby www.ColbyConsulting.com Asger Blond wrote: >> ..the where clause does in fact reference (use) the first field in both >> indexes (it uses every field in both indexes). >> Does this mean that these indexes are then useful for the search? > > Yes in principle. But as said SQL Server will evaluate if using the index > for its search (traversing the index-tree) or using the index for a scan > (running through the leaf level of the index) is the most efficient. If your > where-condition has a low selectivity (high amount of matching values in the > field) then an index scan is more efficient than an index seek. That's the > beauty of SQL as opposed to procedural languages: in SQL you don't tell how > to do the job - you just tell what you want and then the query optimizer > will figure out the best way. > > Your execution plan shows two parallel index scan and a join. This means > that the query optimizer is in fact using your indexes as covering indexes > (if it was not then you would see either table scans or lookup operations in > the plan). But it also tell that the optimizer do not use the indexes for > its search operations (in that case you would see index seeks). > If you constantly notice that the execution plan is using index scans rather > than index seeks then you might consider using indexes with included columns > instead of composite indexes. But if your table gets repopulated with new > records having less amount of matching values for the search field then you > might notice that the optimizer now will find your composite index useful > for its searches. In that case I would stick to the composite index. > > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 12. december 2009 03:26 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries > > Wow Asger. That is a lot of information and ... > > All of my indexes were created with the index wizard and as far as I can > tell they are composite > indexes. In fact I "script index as create" and they are in fact composite > indexes. Having seen > your code and my scripts I can see how I would create "included columns" > indexes but UI don't see > how that would be done with the wizard. > > What I think I am hearing is that none of these indexes are useful for where > clauses with multiple > fields in the where (virtually all of my queries), but it is useful for > returning the data (which I > do in the ORDERS, though I do not need to in the COUNTS. > > In fact, rereading this a bit... > > >SQL Server can only use the index for a *search* operation if your > where-condition references a > field which is the *first* field defined in the index. > > Are you saying that the where clause simply has to include the first field > in the index somewhere in > the where? Because in fact I custom create these indexes. and that is the > case. > > Except, in this last count I had more than 16 fields in the where (a bunch > of ORs) and so I had to > break the index into two parts, but again the where clause does in fact > reference (use) the first > field in both indexes (it uses every field in both indexes). > > Does this mean that these indexes are then useful for the search? > > BTW I looked at the execution plan and it shows two parallel index scans > each accounting for about > 5% of the cost, followed by (in each stream) logical operation repartition > stream (11% in each > stream, and immediately after that an "inner join" accounting for 64% of the > cost. > > Thus it appears that it is in fact using the cover indexes maybe? > > Pretty complex stuff though (for me). > > Thanks again though for that explanation, it is useful. > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> John, >> It will be useful for you to explore the execution plans for your queries. >> You do so by highlighting the query in SSMS and pressing CTRL+L. >> The Execution Plan window may be overwhelming but you just have to focus > on >> the rightmost ikon which is indicating either "Table scan" or "Index Scan" >> or "Index seek". >> Now for your question: >> To understand what's going on you have to distinguish *fetch operation* > and >> *search operation*. You also have to distinguish a *composite index* and > an >> *index with included columns*. >> A covering index means that SQL Server can *fetch* the records you are >> selecting in your query from the leaf level (=bottom level) of your >> index-tree, not having to make a lookup to the data pages. >> But a covering index doesn't mean that SQL Server can use your index for > its >> *search* operations. SQL Server can only use the index for a *search* >> operation if your where-condition references a field which is the *first* >> field defined in the index. >> And to make things more complicated: A covering index can be accomplished > in >> to ways: as a *composite index* or as an *index with included columns*. >> A composite index is created this way: >> CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) >> An index with included columns is created this way: >> CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, >> FieldD) >> A *composite index* records all specified columns in every level of the >> index-tree, and it is very useful for multi-field *sorting* operations. > But >> it is not useful for multi-field *search" operations, because SQL Server >> will only consider using this index for a query referencing the *first* >> field (here FieldA) in the where-condition. It is however very useful for >> *fetch* operations, since SQL Server then can do with an "index scan" on > the >> leaf level of the index not having to make a lookup the actual data-pages. >> This is only true however if you are selecting fields which are present in >> the index: if your query selects fields not defined in an index then SQL >> Server has to use a *table scan* which is not efficient. And now you may >> ask: What about a SELECT COUNT(*) - isn't this referencing all fields and >> shouldn't this per definition prevent SQL Server from using the index? > Don't >> worry: COUNT(*) is a special case where SQL Server will use the index if > it >> can make the execution more efficient. >> An *index with included columns* only records the included columns in the >> leaf level of the index. For this reason it is neither useful for >> multi-field *sorting* operations nor for *search* operations on the > included >> columns. But as for *composite indexes* it is very useful for *fetch* >> operations. >> Bottom line: >> A *composite index* is good for multi-columns sorting and covering > queries, >> but it doesn't help *search* operations and it imposes an overhead forcing >> SQL Server to record all fields in every level of the index-tree. An > *index >> with included column* it good for covering queries too, but it doesn't > help >> multi-columns sorting and it doesn't help *search* operations either - >> however it imposes fare less overhead cause the included fields are only >> recorded in the leaf-level of the index. >> >> I suggest you play whith the different options using CTRL+L - pretty soon >> you will notice this: >> >> Composite index on FieldA, FieldB, FieldC >> Composite index on FieldD, FieldE, FieldF >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" >> --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps > two >> index seeks merged >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably > a >> table scan >> >> Index on FieldA including FieldB and FieldC >> Index on FieldA including FieldD and FieldF >> --> exactly same results >> >> Another option is to use a separate index on each field. Then you will >> notice: >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps > two >> index seeks merged >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" >> --> Probably a table scan >> >> Mind that the results will depend on the actual values present in your >> table. SQL Server maintains statistics of the indexed columns and if there >> is a low selectivity for you query (= a high rate of matching values in > the >> indexed search-field) then chance is that SQL Server don't want to use the >> index and will prefer using a table scan instead. >> >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Sat Dec 12 13:36:25 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Sat, 12 Dec 2009 20:36:25 +0100 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: <4B23D4AF.4040404@colbyconsulting.com> References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com><9E433E5767FA43878B1D48C688587825@AB> <4B23D4AF.4040404@colbyconsulting.com> Message-ID: John I just reread my previous posting and - stupid me - I totally forgot that you have OR operators in your queries... When you have OR operators the query optimizer will never use a composite index for searches no matter how selective the where condition is - it will only use the composite index for fetches in an index scan. Why? The query optimizer could use the condition referencing the first field defined in the index for a search operation, but then it has to do an index scan anyhow for the rest of the condition referencing the other fields - and of cause it decides to just make an index scan. In this situation you could as well use an index with includes columns. If you really want the optimizer to use index *searches* then you have to build *a separate index for each field*. The optimizer can use these indexes for searches and then join the results. This kind of execution is also "covering" since SQL Server can find all values needed in the indexes and don't have to go to the actual data pages. But in this case it certainly matters how selective your condition is. I just made a test on a table with 4 fields and 1 million records having lots of duplicate values which gives a poor selectivity. If the where clause only contained two conditions with an OR then the optimizer used a join of two seeks. But if it contained tree or more conditions the optimizer reverted to a table scan. I then changed the values to have much less duplicates (giving better selectivity) and now the optimizer would use several index seeks and join the results. Finally I tested performance for this set of records (having less duplicates) on 1) separate indexes on each field and 2) a composite index of all fields. There was a substantial difference: 1) had a much faster execution time than 2): 35 ms versus 1193 ms... If you want to test this on your own tables you can use a SSMS-query window and use Query | Include client statistics. This will give a result tab with statistical information after running a query - look especially for the value of "Total execution time". Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 12. december 2009 18:37 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries Asger, >But if your table gets repopulated with new records At least in this case the table is entirely static, never updated in any way. John W. Colby www.ColbyConsulting.com Asger Blond wrote: >> ..the where clause does in fact reference (use) the first field in both >> indexes (it uses every field in both indexes). >> Does this mean that these indexes are then useful for the search? > > Yes in principle. But as said SQL Server will evaluate if using the index > for its search (traversing the index-tree) or using the index for a scan > (running through the leaf level of the index) is the most efficient. If your > where-condition has a low selectivity (high amount of matching values in the > field) then an index scan is more efficient than an index seek. That's the > beauty of SQL as opposed to procedural languages: in SQL you don't tell how > to do the job - you just tell what you want and then the query optimizer > will figure out the best way. > > Your execution plan shows two parallel index scan and a join. This means > that the query optimizer is in fact using your indexes as covering indexes > (if it was not then you would see either table scans or lookup operations in > the plan). But it also tell that the optimizer do not use the indexes for > its search operations (in that case you would see index seeks). > If you constantly notice that the execution plan is using index scans rather > than index seeks then you might consider using indexes with included columns > instead of composite indexes. But if your table gets repopulated with new > records having less amount of matching values for the search field then you > might notice that the optimizer now will find your composite index useful > for its searches. In that case I would stick to the composite index. > > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 12. december 2009 03:26 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries > > Wow Asger. That is a lot of information and ... > > All of my indexes were created with the index wizard and as far as I can > tell they are composite > indexes. In fact I "script index as create" and they are in fact composite > indexes. Having seen > your code and my scripts I can see how I would create "included columns" > indexes but UI don't see > how that would be done with the wizard. > > What I think I am hearing is that none of these indexes are useful for where > clauses with multiple > fields in the where (virtually all of my queries), but it is useful for > returning the data (which I > do in the ORDERS, though I do not need to in the COUNTS. > > In fact, rereading this a bit... > > >SQL Server can only use the index for a *search* operation if your > where-condition references a > field which is the *first* field defined in the index. > > Are you saying that the where clause simply has to include the first field > in the index somewhere in > the where? Because in fact I custom create these indexes. and that is the > case. > > Except, in this last count I had more than 16 fields in the where (a bunch > of ORs) and so I had to > break the index into two parts, but again the where clause does in fact > reference (use) the first > field in both indexes (it uses every field in both indexes). > > Does this mean that these indexes are then useful for the search? > > BTW I looked at the execution plan and it shows two parallel index scans > each accounting for about > 5% of the cost, followed by (in each stream) logical operation repartition > stream (11% in each > stream, and immediately after that an "inner join" accounting for 64% of the > cost. > > Thus it appears that it is in fact using the cover indexes maybe? > > Pretty complex stuff though (for me). > > Thanks again though for that explanation, it is useful. > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >> John, >> It will be useful for you to explore the execution plans for your queries. >> You do so by highlighting the query in SSMS and pressing CTRL+L. >> The Execution Plan window may be overwhelming but you just have to focus > on >> the rightmost ikon which is indicating either "Table scan" or "Index Scan" >> or "Index seek". >> Now for your question: >> To understand what's going on you have to distinguish *fetch operation* > and >> *search operation*. You also have to distinguish a *composite index* and > an >> *index with included columns*. >> A covering index means that SQL Server can *fetch* the records you are >> selecting in your query from the leaf level (=bottom level) of your >> index-tree, not having to make a lookup to the data pages. >> But a covering index doesn't mean that SQL Server can use your index for > its >> *search* operations. SQL Server can only use the index for a *search* >> operation if your where-condition references a field which is the *first* >> field defined in the index. >> And to make things more complicated: A covering index can be accomplished > in >> to ways: as a *composite index* or as an *index with included columns*. >> A composite index is created this way: >> CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) >> An index with included columns is created this way: >> CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, >> FieldD) >> A *composite index* records all specified columns in every level of the >> index-tree, and it is very useful for multi-field *sorting* operations. > But >> it is not useful for multi-field *search" operations, because SQL Server >> will only consider using this index for a query referencing the *first* >> field (here FieldA) in the where-condition. It is however very useful for >> *fetch* operations, since SQL Server then can do with an "index scan" on > the >> leaf level of the index not having to make a lookup the actual data-pages. >> This is only true however if you are selecting fields which are present in >> the index: if your query selects fields not defined in an index then SQL >> Server has to use a *table scan* which is not efficient. And now you may >> ask: What about a SELECT COUNT(*) - isn't this referencing all fields and >> shouldn't this per definition prevent SQL Server from using the index? > Don't >> worry: COUNT(*) is a special case where SQL Server will use the index if > it >> can make the execution more efficient. >> An *index with included columns* only records the included columns in the >> leaf level of the index. For this reason it is neither useful for >> multi-field *sorting* operations nor for *search* operations on the > included >> columns. But as for *composite indexes* it is very useful for *fetch* >> operations. >> Bottom line: >> A *composite index* is good for multi-columns sorting and covering > queries, >> but it doesn't help *search* operations and it imposes an overhead forcing >> SQL Server to record all fields in every level of the index-tree. An > *index >> with included column* it good for covering queries too, but it doesn't > help >> multi-columns sorting and it doesn't help *search* operations either - >> however it imposes fare less overhead cause the included fields are only >> recorded in the leaf-level of the index. >> >> I suggest you play whith the different options using CTRL+L - pretty soon >> you will notice this: >> >> Composite index on FieldA, FieldB, FieldC >> Composite index on FieldD, FieldE, FieldF >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" >> --> Index Scan >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps > two >> index seeks merged >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably > a >> table scan >> >> Index on FieldA including FieldB and FieldC >> Index on FieldA including FieldD and FieldF >> --> exactly same results >> >> Another option is to use a separate index on each field. Then you will >> notice: >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps > two >> index seeks merged >> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR FieldC="Y" >> --> Probably a table scan >> >> Mind that the results will depend on the actual values present in your >> table. SQL Server maintains statistics of the indexed columns and if there >> is a low selectivity for you query (= a high rate of matching values in > the >> indexed search-field) then chance is that SQL Server don't want to use the >> index and will prefer using a table scan instead. >> >> Asger > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Sun Dec 13 03:08:06 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Sun, 13 Dec 2009 04:08:06 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com><9E433E5767FA43878B1D48C688587825@AB> <4B23D4AF.4040404@colbyconsulting.com> Message-ID: <4B24AEF6.9000909@colbyconsulting.com> I think I will give this a try (soon). I could set up code to programmatically build an index on every field, then set it running. Come back in a week and I would be done indexing forever. If it made that much time difference it would definitely be worth doing! I had always worried about whether SQL Server could have enough indexes on a single table to do this (I have ~550 fields) but I read just yesterday that it can have that many indexes so I am good there.. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John > I just reread my previous posting and - stupid me - I totally forgot that > you have OR operators in your queries... > When you have OR operators the query optimizer will never use a composite > index for searches no matter how selective the where condition is - it will > only use the composite index for fetches in an index scan. Why? The query > optimizer could use the condition referencing the first field defined in the > index for a search operation, but then it has to do an index scan anyhow for > the rest of the condition referencing the other fields - and of cause it > decides to just make an index scan. > In this situation you could as well use an index with includes columns. > > If you really want the optimizer to use index *searches* then you have to > build *a separate index for each field*. The optimizer can use these indexes > for searches and then join the results. This kind of execution is also > "covering" since SQL Server can find all values needed in the indexes and > don't have to go to the actual data pages. But in this case it certainly > matters how selective your condition is. > I just made a test on a table with 4 fields and 1 million records having > lots of duplicate values which gives a poor selectivity. If the where clause > only contained two conditions with an OR then the optimizer used a join of > two seeks. But if it contained tree or more conditions the optimizer > reverted to a table scan. > I then changed the values to have much less duplicates (giving better > selectivity) and now the optimizer would use several index seeks and join > the results. > Finally I tested performance for this set of records (having less > duplicates) on 1) separate indexes on each field and 2) a composite index of > all fields. There was a substantial difference: 1) had a much faster > execution time than 2): 35 ms versus 1193 ms... > If you want to test this on your own tables you can use a SSMS-query window > and use Query | Include client statistics. This will give a result tab with > statistical information after running a query - look especially for the > value of "Total execution time". > > Asger > -----Oprindelig meddelelse----- > Fra: dba-sqlserver-bounces at databaseadvisors.com > [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby > Sendt: 12. december 2009 18:37 > Til: Discussion concerning MS SQL Server > Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries > > Asger, > > >But if your table gets repopulated with new records > > At least in this case the table is entirely static, never updated in any > way. > > John W. Colby > www.ColbyConsulting.com > > > Asger Blond wrote: >>> ..the where clause does in fact reference (use) the first field in both >>> indexes (it uses every field in both indexes). >>> Does this mean that these indexes are then useful for the search? >> Yes in principle. But as said SQL Server will evaluate if using the index >> for its search (traversing the index-tree) or using the index for a scan >> (running through the leaf level of the index) is the most efficient. If > your >> where-condition has a low selectivity (high amount of matching values in > the >> field) then an index scan is more efficient than an index seek. That's the >> beauty of SQL as opposed to procedural languages: in SQL you don't tell > how >> to do the job - you just tell what you want and then the query optimizer >> will figure out the best way. >> >> Your execution plan shows two parallel index scan and a join. This means >> that the query optimizer is in fact using your indexes as covering indexes >> (if it was not then you would see either table scans or lookup operations > in >> the plan). But it also tell that the optimizer do not use the indexes for >> its search operations (in that case you would see index seeks). >> If you constantly notice that the execution plan is using index scans > rather >> than index seeks then you might consider using indexes with included > columns >> instead of composite indexes. But if your table gets repopulated with new >> records having less amount of matching values for the search field then > you >> might notice that the optimizer now will find your composite index useful >> for its searches. In that case I would stick to the composite index. >> >> Asger >> -----Oprindelig meddelelse----- >> Fra: dba-sqlserver-bounces at databaseadvisors.com >> [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby >> Sendt: 12. december 2009 03:26 >> Til: Discussion concerning MS SQL Server >> Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries >> >> Wow Asger. That is a lot of information and ... >> >> All of my indexes were created with the index wizard and as far as I can >> tell they are composite >> indexes. In fact I "script index as create" and they are in fact > composite >> indexes. Having seen >> your code and my scripts I can see how I would create "included columns" >> indexes but UI don't see >> how that would be done with the wizard. >> >> What I think I am hearing is that none of these indexes are useful for > where >> clauses with multiple >> fields in the where (virtually all of my queries), but it is useful for >> returning the data (which I >> do in the ORDERS, though I do not need to in the COUNTS. >> >> In fact, rereading this a bit... >> >> >SQL Server can only use the index for a *search* operation if your >> where-condition references a >> field which is the *first* field defined in the index. >> >> Are you saying that the where clause simply has to include the first field >> in the index somewhere in >> the where? Because in fact I custom create these indexes. and that is the >> case. >> >> Except, in this last count I had more than 16 fields in the where (a bunch >> of ORs) and so I had to >> break the index into two parts, but again the where clause does in fact >> reference (use) the first >> field in both indexes (it uses every field in both indexes). >> >> Does this mean that these indexes are then useful for the search? >> >> BTW I looked at the execution plan and it shows two parallel index scans >> each accounting for about >> 5% of the cost, followed by (in each stream) logical operation repartition >> stream (11% in each >> stream, and immediately after that an "inner join" accounting for 64% of > the >> cost. >> >> Thus it appears that it is in fact using the cover indexes maybe? >> >> Pretty complex stuff though (for me). >> >> Thanks again though for that explanation, it is useful. >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Asger Blond wrote: >>> John, >>> It will be useful for you to explore the execution plans for your > queries. >>> You do so by highlighting the query in SSMS and pressing CTRL+L. >>> The Execution Plan window may be overwhelming but you just have to focus >> on >>> the rightmost ikon which is indicating either "Table scan" or "Index > Scan" >>> or "Index seek". >>> Now for your question: >>> To understand what's going on you have to distinguish *fetch operation* >> and >>> *search operation*. You also have to distinguish a *composite index* and >> an >>> *index with included columns*. >>> A covering index means that SQL Server can *fetch* the records you are >>> selecting in your query from the leaf level (=bottom level) of your >>> index-tree, not having to make a lookup to the data pages. >>> But a covering index doesn't mean that SQL Server can use your index for >> its >>> *search* operations. SQL Server can only use the index for a *search* >>> operation if your where-condition references a field which is the *first* >>> field defined in the index. >>> And to make things more complicated: A covering index can be accomplished >> in >>> to ways: as a *composite index* or as an *index with included columns*. >>> A composite index is created this way: >>> CREATE INDEX MyCompositeIndex ON MyTable (FieldA, FieldB, FieldC, FieldD) >>> An index with included columns is created this way: >>> CREATE INDEX MyIncludedIndex ON MyTable (FieldA) INCLUDE (FieldB, FieldC, >>> FieldD) >>> A *composite index* records all specified columns in every level of the >>> index-tree, and it is very useful for multi-field *sorting* operations. >> But >>> it is not useful for multi-field *search" operations, because SQL Server >>> will only consider using this index for a query referencing the *first* >>> field (here FieldA) in the where-condition. It is however very useful for >>> *fetch* operations, since SQL Server then can do with an "index scan" on >> the >>> leaf level of the index not having to make a lookup the actual > data-pages. >>> This is only true however if you are selecting fields which are present > in >>> the index: if your query selects fields not defined in an index then SQL >>> Server has to use a *table scan* which is not efficient. And now you may >>> ask: What about a SELECT COUNT(*) - isn't this referencing all fields and >>> shouldn't this per definition prevent SQL Server from using the index? >> Don't >>> worry: COUNT(*) is a special case where SQL Server will use the index if >> it >>> can make the execution more efficient. >>> An *index with included columns* only records the included columns in the >>> leaf level of the index. For this reason it is neither useful for >>> multi-field *sorting* operations nor for *search* operations on the >> included >>> columns. But as for *composite indexes* it is very useful for *fetch* >>> operations. >>> Bottom line: >>> A *composite index* is good for multi-columns sorting and covering >> queries, >>> but it doesn't help *search* operations and it imposes an overhead > forcing >>> SQL Server to record all fields in every level of the index-tree. An >> *index >>> with included column* it good for covering queries too, but it doesn't >> help >>> multi-columns sorting and it doesn't help *search* operations either - >>> however it imposes fare less overhead cause the included fields are only >>> recorded in the leaf-level of the index. >>> >>> I suggest you play whith the different options using CTRL+L - pretty soon >>> you will notice this: >>> >>> Composite index on FieldA, FieldB, FieldC >>> Composite index on FieldD, FieldE, FieldF >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >>> SELECT COUNT (*) FROM MyTable WHERE FieldB="Y" --> Index Scan >>> SELECT COUNT (*) FROM MyTable WHERE FieldD="Y" --> Index Seek >>> SELECT COUNT (*) FROM MyTable WHERE FieldE="Y" --> Index Scan >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR > FieldC="Y" >>> --> Index Scan >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldD="Y" --> Perhaps >> two >>> index seeks merged >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldE="Y" --> Probably >> a >>> table scan >>> >>> Index on FieldA including FieldB and FieldC >>> Index on FieldA including FieldD and FieldF >>> --> exactly same results >>> >>> Another option is to use a separate index on each field. Then you will >>> notice: >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" --> Index Seek >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" --> Perhaps >> two >>> index seeks merged >>> SELECT COUNT (*) FROM MyTable WHERE FieldA="Y" OR FieldB="Y" OR > FieldC="Y" >>> --> Probably a table scan >>> >>> Mind that the results will depend on the actual values present in your >>> table. SQL Server maintains statistics of the indexed columns and if > there >>> is a low selectivity for you query (= a high rate of matching values in >> the >>> indexed search-field) then chance is that SQL Server don't want to use > the >>> index and will prefer using a table scan instead. >>> >>> Asger >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Mon Dec 14 07:34:59 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Mon, 14 Dec 2009 08:34:59 -0500 Subject: [dba-SQLServer] List of fields in a table Message-ID: <4B263F03.2000204@colbyconsulting.com> I need to get a list of fields in a table in any database I want, in a stored procedure. I have found this: select COLUMN_NAME from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = 'tblOrderData' but that only appears to work if you execute that from a query in the target database, whereas my stored procedure needs to take the database and table name as parameters and go get the list. How can I get a list of fields in any table in any database, from a stored procedure saved in a "library" database? -- John W. Colby www.ColbyConsulting.com From mwp.reid at qub.ac.uk Mon Dec 14 08:18:18 2009 From: mwp.reid at qub.ac.uk (Martin Reid) Date: Mon, 14 Dec 2009 14:18:18 +0000 Subject: [dba-SQLServer] List of fields in a table In-Reply-To: <4B263F03.2000204@colbyconsulting.com> References: <4B263F03.2000204@colbyconsulting.com> Message-ID: <631CF83223105545BF43EFB52CB0829502B0D3863E@EX2K7-VIRT-2.ads.qub.ac.uk> John This any use http://msdn.microsoft.com/en-us/magazine/cc164065.aspx martin Martin WP Reid Information Services The Library at Queen's Tel : 02890976174 Email : mwp.reid at qub.ac.uk Sharepoint Training Portal ________________________________________ From: dba-sqlserver-bounces at databaseadvisors.com [dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby [jwcolby at colbyconsulting.com] Sent: 14 December 2009 13:34 To: Dba-Sqlserver Subject: [dba-SQLServer] List of fields in a table I need to get a list of fields in a table in any database I want, in a stored procedure. I have found this: select COLUMN_NAME from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME = 'tblOrderData' but that only appears to work if you execute that from a query in the target database, whereas my stored procedure needs to take the database and table name as parameters and go get the list. How can I get a list of fields in any table in any database, from a stored procedure saved in a "library" database? -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From robert at webedb.com Mon Dec 14 12:40:37 2009 From: robert at webedb.com (Robert Stewart) Date: Mon, 14 Dec 2009 12:40:37 -0600 Subject: [dba-SQLServer] List of fields in a table In-Reply-To: References: Message-ID: <200912141841.nBEIevCC006690@databaseadvisors.com> CREATE PROCEDURE GetColumnName(@DB_Name varchar(100), @TableName varchar(100)) DECLARE @Sql as nvarchar(2000) SET @Sql = 'SELECT column_name FROM ' + @DB_Name + '.' + 'INFORMATION_SCHEMA.COLUMNS WHERE table_name = ' + char(39) + @TableName + CHAR(39) EXEC @Sql END Not tested, but should work. At 12:00 PM 12/14/2009, you wrote: >Message: 1 >Date: Mon, 14 Dec 2009 08:34:59 -0500 >From: jwcolby >Subject: [dba-SQLServer] List of fields in a table >To: Dba-Sqlserver >Message-ID: <4B263F03.2000204 at colbyconsulting.com> >Content-Type: text/plain; charset=ISO-8859-1; format=flowed > >I need to get a list of fields in a table in any database I want, in >a stored procedure. I have >found this: > >select COLUMN_NAME from INFORMATION_SCHEMA.COLUMNS where TABLE_NAME >= 'tblOrderData' > >but that only appears to work if you execute that from a query in >the target database, whereas my >stored procedure needs to take the database and table name as >parameters and go get the list. > >How can I get a list of fields in any table in any database, from a >stored procedure saved in a >"library" database? > >-- >John W. Colby From jwcolby at colbyconsulting.com Tue Dec 15 10:00:56 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 15 Dec 2009 11:00:56 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com><9E433E5767FA43878B1D48C688587825@AB> <4B23D4AF.4040404@colbyconsulting.com> Message-ID: <4B27B2B8.4040706@colbyconsulting.com> Asger, YOU DA MAN!!! > If you really want the optimizer to use index *searches* then you have to > build *a separate index for each field*. The optimizer can use these indexes > for searches and then join the results. This kind of execution is also > "covering" since SQL Server can find all values needed in the indexes and > don't have to go to the actual data pages. But in this case it certainly > matters how selective your condition is. I built a stored procedure to go build individual indexes on each field of the table from hell (~550 fields). On a query which returns a count of 13 million+ records using an or on 20 different fields, the execution plan shows that the query is in fact using index seeks now instead of index scans, and the time dropped from 1:58 to 0:29, from almost two minutes to under 1/2 minute!!! Awesome. Of course I have a total data space of about 40 gbytes and an index space of about 114 gigs, and that is for about 200 indexes, I still have about 300+ indexes to go. So this puppy is going to be large!!! However the upside is that I will have every single field indexed when I am done and not have to worry about "do I need to build an index for this order". The process of building the indexes is averaging somewhere around 7-8 minutes / index, which obviously changes depending on how many data elements are in the indexed field. Thanks again for your very detailed explanations of what the indexes actually do, which allowed me to figure out that this might actually help. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John > I just reread my previous posting and - stupid me - I totally forgot that > you have OR operators in your queries... > When you have OR operators the query optimizer will never use a composite > index for searches no matter how selective the where condition is - it will > only use the composite index for fetches in an index scan. Why? The query > optimizer could use the condition referencing the first field defined in the > index for a search operation, but then it has to do an index scan anyhow for > the rest of the condition referencing the other fields - and of cause it > decides to just make an index scan. > In this situation you could as well use an index with includes columns. > > If you really want the optimizer to use index *searches* then you have to > build *a separate index for each field*. The optimizer can use these indexes > for searches and then join the results. This kind of execution is also > "covering" since SQL Server can find all values needed in the indexes and > don't have to go to the actual data pages. But in this case it certainly > matters how selective your condition is. > I just made a test on a table with 4 fields and 1 million records having > lots of duplicate values which gives a poor selectivity. If the where clause > only contained two conditions with an OR then the optimizer used a join of > two seeks. But if it contained tree or more conditions the optimizer > reverted to a table scan. > I then changed the values to have much less duplicates (giving better > selectivity) and now the optimizer would use several index seeks and join > the results. > Finally I tested performance for this set of records (having less > duplicates) on 1) separate indexes on each field and 2) a composite index of > all fields. There was a substantial difference: 1) had a much faster > execution time than 2): 35 ms versus 1193 ms... > If you want to test this on your own tables you can use a SSMS-query window > and use Query | Include client statistics. This will give a result tab with > statistical information after running a query - look especially for the > value of "Total execution time". > > Asger From jwcolby at colbyconsulting.com Tue Dec 15 10:08:58 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 15 Dec 2009 11:08:58 -0500 Subject: [dba-SQLServer] Index information Message-ID: <4B27B49A.8000905@colbyconsulting.com> In viewing an execution plan, as I hover over the index seek icon I see a bunch of information including estimated number of rows. This leads me to wonder whether SQL Server has statistics somewhere about the total number of actual data elements in each index. IOW how many data elements are in this field, as observed in the index for that field? When I am done with my indexing, I will have a single column index on every field, and if the information is available I could get a gross count for each field which would be useful for the client. -- John W. Colby www.ColbyConsulting.com From mwp.reid at qub.ac.uk Tue Dec 15 10:15:51 2009 From: mwp.reid at qub.ac.uk (Martin Reid) Date: Tue, 15 Dec 2009 16:15:51 +0000 Subject: [dba-SQLServer] Index information In-Reply-To: <4B27B49A.8000905@colbyconsulting.com> References: <4B27B49A.8000905@colbyconsulting.com> Message-ID: <631CF83223105545BF43EFB52CB0829502B23881CC@EX2K7-VIRT-2.ads.qub.ac.uk> This any use http://www.mssqltips.com/tip.asp?tip=1038 martin Martin WP Reid Information Services The Library at Queen's Tel : 02890976174 Email : mwp.reid at qub.ac.uk Sharepoint Training Portal ________________________________________ From: dba-sqlserver-bounces at databaseadvisors.com [dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby [jwcolby at colbyconsulting.com] Sent: 15 December 2009 16:08 To: Dba-Sqlserver Subject: [dba-SQLServer] Index information In viewing an execution plan, as I hover over the index seek icon I see a bunch of information including estimated number of rows. This leads me to wonder whether SQL Server has statistics somewhere about the total number of actual data elements in each index. IOW how many data elements are in this field, as observed in the index for that field? When I am done with my indexing, I will have a single column index on every field, and if the information is available I could get a gross count for each field which would be useful for the client. -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From ab-mi at post3.tele.dk Tue Dec 15 13:34:00 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Tue, 15 Dec 2009 20:34:00 +0100 Subject: [dba-SQLServer] SPAM-LOW: Re: How to construct queries In-Reply-To: <4B27B2B8.4040706@colbyconsulting.com> References: <4B228F59.9080502@colbyconsulting.com><79D4EB99552C4ADD899D148B4A8EFE93@AB> <4B22FF32.5030201@colbyconsulting.com><9E433E5767FA43878B1D48C688587825@AB> <4B23D4AF.4040404@colbyconsulting.com> <4B27B2B8.4040706@colbyconsulting.com> Message-ID: <033396507CAA439D89AF3873D42A63E3@AB> Happy to know! Keep looking out though for table scans which might appear if the selectivity of your queries drops. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 15. december 2009 17:01 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] SPAM-LOW: Re: How to construct queries Asger, YOU DA MAN!!! > If you really want the optimizer to use index *searches* then you have to > build *a separate index for each field*. The optimizer can use these indexes > for searches and then join the results. This kind of execution is also > "covering" since SQL Server can find all values needed in the indexes and > don't have to go to the actual data pages. But in this case it certainly > matters how selective your condition is. I built a stored procedure to go build individual indexes on each field of the table from hell (~550 fields). On a query which returns a count of 13 million+ records using an or on 20 different fields, the execution plan shows that the query is in fact using index seeks now instead of index scans, and the time dropped from 1:58 to 0:29, from almost two minutes to under 1/2 minute!!! Awesome. Of course I have a total data space of about 40 gbytes and an index space of about 114 gigs, and that is for about 200 indexes, I still have about 300+ indexes to go. So this puppy is going to be large!!! However the upside is that I will have every single field indexed when I am done and not have to worry about "do I need to build an index for this order". The process of building the indexes is averaging somewhere around 7-8 minutes / index, which obviously changes depending on how many data elements are in the indexed field. Thanks again for your very detailed explanations of what the indexes actually do, which allowed me to figure out that this might actually help. John W. Colby www.ColbyConsulting.com Asger Blond wrote: > John > I just reread my previous posting and - stupid me - I totally forgot that > you have OR operators in your queries... > When you have OR operators the query optimizer will never use a composite > index for searches no matter how selective the where condition is - it will > only use the composite index for fetches in an index scan. Why? The query > optimizer could use the condition referencing the first field defined in the > index for a search operation, but then it has to do an index scan anyhow for > the rest of the condition referencing the other fields - and of cause it > decides to just make an index scan. > In this situation you could as well use an index with includes columns. > > If you really want the optimizer to use index *searches* then you have to > build *a separate index for each field*. The optimizer can use these indexes > for searches and then join the results. This kind of execution is also > "covering" since SQL Server can find all values needed in the indexes and > don't have to go to the actual data pages. But in this case it certainly > matters how selective your condition is. > I just made a test on a table with 4 fields and 1 million records having > lots of duplicate values which gives a poor selectivity. If the where clause > only contained two conditions with an OR then the optimizer used a join of > two seeks. But if it contained tree or more conditions the optimizer > reverted to a table scan. > I then changed the values to have much less duplicates (giving better > selectivity) and now the optimizer would use several index seeks and join > the results. > Finally I tested performance for this set of records (having less > duplicates) on 1) separate indexes on each field and 2) a composite index of > all fields. There was a substantial difference: 1) had a much faster > execution time than 2): 35 ms versus 1193 ms... > If you want to test this on your own tables you can use a SSMS-query window > and use Query | Include client statistics. This will give a result tab with > statistical information after running a query - look especially for the > value of "Total execution time". > > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Tue Dec 15 20:56:08 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 15 Dec 2009 21:56:08 -0500 Subject: [dba-SQLServer] Indexes not all listed Message-ID: <4B284C48.7040506@colbyconsulting.com> Well, I just discovered my reason to update to SQL Server 2008. 2005 has a maximum number of non-clustered indexes per table of 250. SQL Server 2008 has a maximum of 999. I have 584 fields that I need to create indexes on. Time to do an install... ;) -- John W. Colby www.ColbyConsulting.com From marklbreen at gmail.com Wed Dec 16 03:29:26 2009 From: marklbreen at gmail.com (Mark Breen) Date: Wed, 16 Dec 2009 09:29:26 +0000 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B284C48.7040506@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> Message-ID: Hello John, It is really going to be the best solution to index every column? Are you really using all columns to search on? I instinctively feel that if you place an index on every column, you will loose the benefits of having an index in the first place, or at least you loose some of the benefits that a neat and quick index delivers. I am imagining Encyclopedia Brittanica if it supplied 25 different indexes, the indexes would be larger that the books. I always imagined we should have as few indexes as you can get away with but as many as we need. In the case where you have an order for a specific column(s), can you not programatically create the indexes on those columns, then run your queries and perhaps even go the final step and drop those indexes you just created after the order has been delivered. And if it does not take too long, I would run the scripts that the maintenance wizard create afterwards everytime also, in the hope that it keeps the database intact. Again, this is just instinct, but I feel you will have other integrity / file size / performance /de-fragmentation / torn pages etc etc with such enormous data and enormous numbers of indexes. What do you think? Mark 2009/12/16 jwcolby > Well, I just discovered my reason to update to SQL Server 2008. > > 2005 has a maximum number of non-clustered indexes per table of 250. SQL > Server 2008 has a maximum > of 999. I have 584 fields that I need to create indexes on. > > Time to do an install... > > ;) > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Wed Dec 16 08:37:18 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Wed, 16 Dec 2009 09:37:18 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> Message-ID: <4B28F09E.1030308@colbyconsulting.com> Mark, > Are you really using all columns to search on? I have not used every one, with 584 columns it would be difficult to do so. However the client calls and says "I need a count where" and rattles off a list of columns. He has a spreadsheet with every single column listed and he uses these to perform very targeted searches. So I have used a ton of them already and could use any of them on a moment's notice. >In the case where you have an order for a specific column(s), can you not programmatically create the indexes on those columns... And if it does not take too long, I would run the scripts that the maintenance wizard create afterwards every time also, in the hope that it keeps the database intact. Yes, except that you are talking about 50 million records. You don't just "bang out an index". > Again, this is just instinct, but I feel you will have other integrity / file size / performance /de-fragmentation / torn pages etc etc with such enormous data and enormous numbers of indexes. On any other database table I would probably agree, however you must always remember that this table is completely static. No inserts, updates or deletes EVER. It is not a relational database, the table does in fact have a one to one with the name / address table but it is that other table which gets updated. Thus I don't see how such issues could occur. To be honest I am such an amateur in SQL Server that I cannot possibly know whether this is the right thing to do. What I do know is that when I started, my searches and sorts would take 20 minutes to two hours - basically SQL Server was doing all table scans. Once I discovered "cover indexes", where I did as you suggested and indexed a group of related fields, I got my searches down to anywhere from 2-10 minutes. With this "every field" indexed paradigm I got a two minute search down to 30 seconds, and went from a bunch of index scans to a bunch of index seeks. All I can say is that it sure seems to be another gigantic leap forward. When you spend as much time waiting on this stuff as I do, you are constantly looking for that next gigantic leap. I truly don't much care about the file size if the results are worthwhile. This database / table is the center of the client's universe. It is THE table that he does selects against. As such I will do whatever I can to make it fast. In fact some day soon I will be placing this file on a Flash drive. You know how much those cost, but again, if I can cut the times in 1/2 or 1/4 then it all becomes worthwhile. When that day comes I will be looking to place these indexes out in a separate file so that only these indexes have to go on flash. John W. Colby www.ColbyConsulting.com Mark Breen wrote: > Hello John, > > It is really going to be the best solution to index every column? > > Are you really using all columns to search on? > > I instinctively feel that if you place an index on every column, you will > loose the benefits of having an index in the first place, or at least you > loose some of the benefits that a neat and quick index delivers. I am > imagining Encyclopedia Brittanica if it supplied 25 different indexes, the > indexes would be larger that the books. > > I always imagined we should have as few indexes as you can get away with but > as many as we need. In the case where you have an order for a specific > column(s), can you not programatically create the indexes on those columns, > then run your queries and perhaps even go the final step and drop those > indexes you just created after the order has been delivered. And if it does > not take too long, I would run the scripts that the maintenance wizard > create afterwards everytime also, in the hope that it keeps the database > intact. > > Again, this is just instinct, but I feel you will have other integrity / > file size / performance /de-fragmentation / torn pages etc etc with such > enormous data and enormous numbers of indexes. > > What do you think? > > Mark From jwcolby at colbyconsulting.com Wed Dec 16 15:40:49 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Wed, 16 Dec 2009 16:40:49 -0500 Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 Message-ID: <4B2953E1.9040600@colbyconsulting.com> What a pita this is. Two failures. I had renamed the sa account and the install failed IN THE MIDDLE because somewhere along the line it needed to use that user in the install process. You would think they would check for that user BEFORE starting the upgrade. Then the Visual Studio install of the compact edition is named something that throws the SQL Server 2008 install for a loop. It turns out that the "sa user missing" was just insurmountable. I was apparently supposed to know what the sa had been renamed to, but I didn't use that account and so had no clue. I ended up just deleting sql server entirely and started from scratch. Which is a royal pita because I had done some major tweaking to get the old "server hangs" issue to go away. I THINK I MIGHT know what to tweak if I ever get this thing to install correctly. 5 hours later and I am just finishing the uninstall and beginning a new install. I do so love this job sometimes. -- John W. Colby www.ColbyConsulting.com From mmattys at rochester.rr.com Wed Dec 16 15:50:49 2009 From: mmattys at rochester.rr.com (Mike Mattys) Date: Wed, 16 Dec 2009 16:50:49 -0500 Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 References: <4B2953E1.9040600@colbyconsulting.com> Message-ID: <70D702450CAC4E1684A2209CF0D7FA51@Mattys> Hi John, I can't tell if this will help but I did at one point post this link http://www.sqldbatips.com/showarticle.asp?ID=46 This allows you to set the active instance of SQL I often can have 4 versions alive on my laptop at the same time Also, note that SQL Mgmt Studio 2005 had to be uninstalled in order to install the 2008 version. - Michael R Mattys MapPoint and Database Dev www.mattysconsulting.com - ----- Original Message ----- From: "jwcolby" To: "Dba-Sqlserver" Sent: Wednesday, December 16, 2009 4:40 PM Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 > What a pita this is. Two failures. > > I had renamed the sa account and the install failed IN THE MIDDLE because > somewhere along the line > it needed to use that user in the install process. You would think they > would check for that user > BEFORE starting the upgrade. > > Then the Visual Studio install of the compact edition is named something > that throws the SQL Server > 2008 install for a loop. > > It turns out that the "sa user missing" was just insurmountable. I was > apparently supposed to know > what the sa had been renamed to, but I didn't use that account and so had > no clue. I ended up just > deleting sql server entirely and started from scratch. Which is a royal > pita because I had done > some major tweaking to get the old "server hangs" issue to go away. I > THINK I MIGHT know what to > tweak if I ever get this thing to install correctly. > > 5 hours later and I am just finishing the uninstall and beginning a new > install. > > I do so love this job sometimes. > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From jwcolby at colbyconsulting.com Wed Dec 16 16:03:00 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Wed, 16 Dec 2009 17:03:00 -0500 Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 In-Reply-To: <70D702450CAC4E1684A2209CF0D7FA51@Mattys> References: <4B2953E1.9040600@colbyconsulting.com> <70D702450CAC4E1684A2209CF0D7FA51@Mattys> Message-ID: <4B295914.1000801@colbyconsulting.com> Holding my breath... it apears that the clean install is going to go just fine. I didn't particularly want to do a clean install, but when do we ever get what we want? John W. Colby www.ColbyConsulting.com Mike Mattys wrote: > Hi John, > > I can't tell if this will help but I did at one point post this link > http://www.sqldbatips.com/showarticle.asp?ID=46 > This allows you to set the active instance of SQL > I often can have 4 versions alive on my laptop at the same time > > Also, note that SQL Mgmt Studio 2005 had to be uninstalled in order > to install the 2008 version. > > - > Michael R Mattys > MapPoint and Database Dev > www.mattysconsulting.com > - > > ----- Original Message ----- > From: "jwcolby" > To: "Dba-Sqlserver" > Sent: Wednesday, December 16, 2009 4:40 PM > Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server > 2008 > > >> What a pita this is. Two failures. >> >> I had renamed the sa account and the install failed IN THE MIDDLE because >> somewhere along the line >> it needed to use that user in the install process. You would think they >> would check for that user >> BEFORE starting the upgrade. >> >> Then the Visual Studio install of the compact edition is named something >> that throws the SQL Server >> 2008 install for a loop. >> >> It turns out that the "sa user missing" was just insurmountable. I was >> apparently supposed to know >> what the sa had been renamed to, but I didn't use that account and so had >> no clue. I ended up just >> deleting sql server entirely and started from scratch. Which is a royal >> pita because I had done >> some major tweaking to get the old "server hangs" issue to go away. I >> THINK I MIGHT know what to >> tweak if I ever get this thing to install correctly. >> >> 5 hours later and I am just finishing the uninstall and beginning a new >> install. >> >> I do so love this job sometimes. >> >> -- >> John W. Colby >> www.ColbyConsulting.com >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From mwp.reid at qub.ac.uk Thu Dec 17 02:32:57 2009 From: mwp.reid at qub.ac.uk (Martin Reid) Date: Thu, 17 Dec 2009 08:32:57 +0000 Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 In-Reply-To: <4B295914.1000801@colbyconsulting.com> References: <4B2953E1.9040600@colbyconsulting.com> <70D702450CAC4E1684A2209CF0D7FA51@Mattys>, <4B295914.1000801@colbyconsulting.com> Message-ID: <631CF83223105545BF43EFB52CB0829502B23881E0@EX2K7-VIRT-2.ads.qub.ac.uk> John Not much use to you now but its a know issue not very well know but know. There is a work around using the command line. The SA account is hard coded into some areas of the upgrade script martin Martin WP Reid Information Services The Library at Queen's Tel : 02890976174 Email : mwp.reid at qub.ac.uk Sharepoint Training Portal ________________________________________ From: dba-sqlserver-bounces at databaseadvisors.com [dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby [jwcolby at colbyconsulting.com] Sent: 16 December 2009 22:03 To: Discussion concerning MS SQL Server Subject: Re: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 Holding my breath... it apears that the clean install is going to go just fine. I didn't particularly want to do a clean install, but when do we ever get what we want? John W. Colby www.ColbyConsulting.com Mike Mattys wrote: > Hi John, > > I can't tell if this will help but I did at one point post this link > http://www.sqldbatips.com/showarticle.asp?ID=46 > This allows you to set the active instance of SQL > I often can have 4 versions alive on my laptop at the same time > > Also, note that SQL Mgmt Studio 2005 had to be uninstalled in order > to install the 2008 version. > > - > Michael R Mattys > MapPoint and Database Dev > www.mattysconsulting.com > - > > ----- Original Message ----- > From: "jwcolby" > To: "Dba-Sqlserver" > Sent: Wednesday, December 16, 2009 4:40 PM > Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server > 2008 > > >> What a pita this is. Two failures. >> >> I had renamed the sa account and the install failed IN THE MIDDLE because >> somewhere along the line >> it needed to use that user in the install process. You would think they >> would check for that user >> BEFORE starting the upgrade. >> >> Then the Visual Studio install of the compact edition is named something >> that throws the SQL Server >> 2008 install for a loop. >> >> It turns out that the "sa user missing" was just insurmountable. I was >> apparently supposed to know >> what the sa had been renamed to, but I didn't use that account and so had >> no clue. I ended up just >> deleting sql server entirely and started from scratch. Which is a royal >> pita because I had done >> some major tweaking to get the old "server hangs" issue to go away. I >> THINK I MIGHT know what to >> tweak if I ever get this thing to install correctly. >> >> 5 hours later and I am just finishing the uninstall and beginning a new >> install. >> >> I do so love this job sometimes. >> >> -- >> John W. Colby >> www.ColbyConsulting.com >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From fhtapia at gmail.com Thu Dec 17 07:29:46 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Thu, 17 Dec 2009 05:29:46 -0800 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B28F09E.1030308@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> Message-ID: Flash drives do not do well with very large files. Flash drives excell at random access wich for SQL makes them good with both tempdb and transaction log files because they both have random inserts and reads. To improve on what you have you will want to double the number of hdd spindles. The more spindles you have the bettertheperformance. We have an enterprise database riding on 40 spindles, this in turn is able to crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? Depending on the query my developers need. We have discussed as an architecture change that we may soon upgrade to 80 spindles. Sent from my mobile On Dec 16, 2009, at 6:37 AM, jwcolby wrote: > Mark, > >> Are you really using all columns to search on? > > I have not used every one, with 584 columns it would be difficult to > do so. However the client > calls and says "I need a count where" and rattles off a list of > columns. He has a spreadsheet with > every single column listed and he uses these to perform very > targeted searches. So I have used a > ton of them already and could use any of them on a moment's notice. > >> In the case where you have an order for a specific column(s), can >> you not programmatically create > the indexes on those columns... And if it does not take too long, I > would run the scripts that the > maintenance wizard create afterwards every time also, in the hope > that it keeps the database intact. > > Yes, except that you are talking about 50 million records. You > don't just "bang out an index". > >> Again, this is just instinct, but I feel you will have other >> integrity / file size / performance > /de-fragmentation / torn pages etc etc with such enormous data and > enormous numbers of indexes. > > On any other database table I would probably agree, however you must > always remember that this table > is completely static. No inserts, updates or deletes EVER. > > It is not a relational database, the table does in fact have a one > to one with the name / address > table but it is that other table which gets updated. Thus I don't > see how such issues could occur. > > To be honest I am such an amateur in SQL Server that I cannot > possibly know whether this is the > right thing to do. What I do know is that when I started, my > searches and sorts would take 20 > minutes to two hours - basically SQL Server was doing all table > scans. Once I discovered "cover > indexes", where I did as you suggested and indexed a group of > related fields, I got my searches down > to anywhere from 2-10 minutes. With this "every field" indexed > paradigm I got a two minute search > down to 30 seconds, and went from a bunch of index scans to a bunch > of index seeks. > > All I can say is that it sure seems to be another gigantic leap > forward. When you spend as much > time waiting on this stuff as I do, you are constantly looking for > that next gigantic leap. > > I truly don't much care about the file size if the results are > worthwhile. This database / table is > the center of the client's universe. It is THE table that he does > selects against. As such I will > do whatever I can to make it fast. > > In fact some day soon I will be placing this file on a Flash drive. > You know how much those cost, > but again, if I can cut the times in 1/2 or 1/4 then it all becomes > worthwhile. When that day comes > I will be looking to place these indexes out in a separate file so > that only these indexes have to > go on flash. > > John W. Colby > www.ColbyConsulting.com > > > Mark Breen wrote: >> Hello John, >> >> It is really going to be the best solution to index every column? >> >> Are you really using all columns to search on? >> >> I instinctively feel that if you place an index on every column, >> you will >> loose the benefits of having an index in the first place, or at >> least you >> loose some of the benefits that a neat and quick index delivers. I >> am >> imagining Encyclopedia Brittanica if it supplied 25 different >> indexes, the >> indexes would be larger that the books. >> >> I always imagined we should have as few indexes as you can get away >> with but >> as many as we need. In the case where you have an order for a >> specific >> column(s), can you not programatically create the indexes on those >> columns, >> then run your queries and perhaps even go the final step and drop >> those >> indexes you just created after the order has been delivered. And >> if it does >> not take too long, I would run the scripts that the maintenance >> wizard >> create afterwards everytime also, in the hope that it keeps the >> database >> intact. >> >> Again, this is just instinct, but I feel you will have other >> integrity / >> file size / performance /de-fragmentation / torn pages etc etc with >> such >> enormous data and enormous numbers of indexes. >> >> What do you think? >> >> Mark > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From fhtapia at gmail.com Thu Dec 17 07:32:37 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Thu, 17 Dec 2009 05:32:37 -0800 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B284C48.7040506@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> Message-ID: Hi my name is John and SQL Server 2008 was my idea (run and duck) Sent from my mobile On Dec 15, 2009, at 6:56 PM, jwcolby wrote: > Well, I just discovered my reason to update to SQL Server 2008. > > 2005 has a maximum number of non-clustered indexes per table of > 250. SQL Server 2008 has a maximum > of 999. I have 584 fields that I need to create indexes on. > > Time to do an install... > > ;) > > -- > John W. Colby > www.ColbyConsulting.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From jwcolby at colbyconsulting.com Thu Dec 17 08:21:27 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 17 Dec 2009 09:21:27 -0500 Subject: [dba-SQLServer] SPAM-LOW: Re: Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> Message-ID: <4B2A3E67.80206@colbyconsulting.com> LOL. uuhhhh yup. I kin do this har database thing. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > Hi my name is John and SQL Server 2008 was my idea (run and duck) > > Sent from my mobile > > On Dec 15, 2009, at 6:56 PM, jwcolby > wrote: > >> Well, I just discovered my reason to update to SQL Server 2008. >> >> 2005 has a maximum number of non-clustered indexes per table of >> 250. SQL Server 2008 has a maximum >> of 999. I have 584 fields that I need to create indexes on. >> >> Time to do an install... >> >> ;) >> >> -- >> John W. Colby >> www.ColbyConsulting.com >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Thu Dec 17 09:14:46 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 17 Dec 2009 10:14:46 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> Message-ID: <4B2A4AE6.3060900@colbyconsulting.com> Francisco, > Flash drives do not do well with very large files. Why do you say this? I have never heard anything like this ever espoused. I have seen file TRANSFER numbers that display this, but transferring files from one disk to another is fundamentally different from reading pieces of a large file for internal processing by a program (database). From a technology perspective flash drives are a page at a time block read system interfaced to a very large cache ram interfaced to an SATA disk controller. Because of this, flash drives have two huge advantages over rotating media - (random) access time and IOPS. Getting at any block of data occurs at the speed of the electronics, but is typically around 100 nanoseconds. Exactly because of this phenomena, the number of IOs that can be processed in any given second skyrockets. Basically IOPs are dispatched instead of being queued waiting for the media to rotate and heads to move. Examine the numbers for flash vs rotating and the REAL IOPS go from the low hundreds to the mid thousands. That is a LOT more data accessed per second. In fact flash drives rapidly become "disk controller bound" precisely because they can shovel data faster than the SATA interface can move it. Even so, rotating media only uses about 10% of the capacity of the SATA interface, so if you turn around and saturate the interface with a flash drive you are getting 10 times the data moved. That is impressive and something worth shooting for. From what I have read, databases absolutely SCREAM when placed on flash drives, in fact some of the big databases are moving there exactly because of the performance gains. Databases need exactly this kind of "read a block from over here" technology that flash drives just naturally excel at. From what I am reading, placing your databases on flash is getting close to "memory resident". In my case, my databases are not transactional, they just sit there handling read requests. As a result even the known issues of wear should not be an issue. Set the db files up on a standard disk and then copy them to a flash drive, sit back and watch it fly. As for the details, what I would LIKE to do is make a raid 0 array using my intelligent raid controllers. If I could get 4 or 5 (or more) "spindles" of flash raid zero... Now back to reality. I haven't done this yet because of cost, I am money bound. ;) When I do, I will do some real life testing and publish results here. On that note, I do have a question, whether it is possible to specify what database files a specific index goes into. It happens that this table from hell uses specific columns much more frequently than others, and some columns (so far) not at all, or only once or twice. If I could create multiple data files, and then move the indexes for the first 200 fields into one file and the rest into another, then I could move that heavily used index file onto a flash and leave the rest on rotating media. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > Flash drives do not do well with very large files. Flash drives excell > at random access wich for SQL makes them good with both tempdb and > transaction log files because they both have random inserts and reads. > To improve on what you have you will want to double the number of hdd > spindles. The more spindles you have the bettertheperformance. We have > an enterprise database riding on 40 spindles, this in turn is able to > crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? > Depending on the query my developers need. We have discussed as an > architecture change that we may soon upgrade to 80 spindles. From jwcolby at colbyconsulting.com Thu Dec 17 09:15:16 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 17 Dec 2009 10:15:16 -0500 Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 In-Reply-To: <631CF83223105545BF43EFB52CB0829502B23881E0@EX2K7-VIRT-2.ads.qub.ac.uk> References: <4B2953E1.9040600@colbyconsulting.com> <70D702450CAC4E1684A2209CF0D7FA51@Mattys>, <4B295914.1000801@colbyconsulting.com> <631CF83223105545BF43EFB52CB0829502B23881E0@EX2K7-VIRT-2.ads.qub.ac.uk> Message-ID: <4B2A4B04.7050504@colbyconsulting.com> LOL. I found those workarounds and typed in exactly what they said to type in but it didn't work. There is a part of that command that went something like or something similar, which I believe was telling me to replace what was between the < > with the ACTUAL user name, which I did not know. In the end I did an uninstall and then a reinstall. As you can imagine, for me that isn't the biggest problem in the world because my setup is so basic. The biggest impact is simply that I had to go setup the server instance with the amount of RAM, CPU binding and such, as well as reconnect all of the databases. I appear to be back up and running, though I will probably find issues with trying to connect from another machine (surface area IIRC), small stuff like that. As of this morning I had created another 200 indexes on the table from hell, with about 150 left to go. John W. Colby www.ColbyConsulting.com Martin Reid wrote: > John > > Not much use to you now but its a know issue not very well know but know. There is a work around using the command line. The SA account is hard coded into some areas of the upgrade script > > martin > > > Martin WP Reid > Information Services > The Library at Queen's > Tel : 02890976174 > Email : mwp.reid at qub.ac.uk > Sharepoint Training Portal > ________________________________________ > From: dba-sqlserver-bounces at databaseadvisors.com [dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby [jwcolby at colbyconsulting.com] > Sent: 16 December 2009 22:03 > To: Discussion concerning MS SQL Server > Subject: Re: [dba-SQLServer] Trials and tribulations - Install of SQL Server 2008 > > Holding my breath... it apears that the clean install is going to go just fine. > > I didn't particularly want to do a clean install, but when do we ever get what we want? > > > > John W. Colby > www.ColbyConsulting.com > > > Mike Mattys wrote: >> Hi John, >> >> I can't tell if this will help but I did at one point post this link >> http://www.sqldbatips.com/showarticle.asp?ID=46 >> This allows you to set the active instance of SQL >> I often can have 4 versions alive on my laptop at the same time >> >> Also, note that SQL Mgmt Studio 2005 had to be uninstalled in order >> to install the 2008 version. >> >> - >> Michael R Mattys >> MapPoint and Database Dev >> www.mattysconsulting.com >> - >> >> ----- Original Message ----- >> From: "jwcolby" >> To: "Dba-Sqlserver" >> Sent: Wednesday, December 16, 2009 4:40 PM >> Subject: [dba-SQLServer] Trials and tribulations - Install of SQL Server >> 2008 >> >> >>> What a pita this is. Two failures. >>> >>> I had renamed the sa account and the install failed IN THE MIDDLE because >>> somewhere along the line >>> it needed to use that user in the install process. You would think they >>> would check for that user >>> BEFORE starting the upgrade. >>> >>> Then the Visual Studio install of the compact edition is named something >>> that throws the SQL Server >>> 2008 install for a loop. >>> >>> It turns out that the "sa user missing" was just insurmountable. I was >>> apparently supposed to know >>> what the sa had been renamed to, but I didn't use that account and so had >>> no clue. I ended up just >>> deleting sql server entirely and started from scratch. Which is a royal >>> pita because I had done >>> some major tweaking to get the old "server hangs" issue to go away. I >>> THINK I MIGHT know what to >>> tweak if I ever get this thing to install correctly. >>> >>> 5 hours later and I am just finishing the uninstall and beginning a new >>> install. >>> >>> I do so love this job sometimes. >>> >>> -- >>> John W. Colby >>> www.ColbyConsulting.com >>> _______________________________________________ >>> dba-SQLServer mailing list >>> dba-SQLServer at databaseadvisors.com >>> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >>> http://www.databaseadvisors.com >>> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From ab-mi at post3.tele.dk Thu Dec 17 13:08:38 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Thu, 17 Dec 2009 20:08:38 +0100 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B2A4AE6.3060900@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: <10540B34047640E6B39BBC525D3A981D@AB> >On that note, I do have a question, whether it is possible to specify what >database files a specific index goes into. It happens that this table from >hell uses specific columns much more frequently than others, and some >columns (so far) not at all, or only once or twice. If I could create >multiple data files, and then move the indexes for the first 200 fields into one file and the rest into another, then I could move that heavily used >index file onto a flash and leave the rest on rotating media. Yes, it's possible and IMO would be a good solution in your case. Like any object in a SQL Server database an index is created on a filegroup, and if you haven?t specifically created filegroups for your database it is created on a filegroup called Primary. You can add a new filegroup and specify a file for it this way: ALTER DATABASE YourDB ADD FILEGROUP YourNewFilegroup GO ALTER DATABASE YourDB ADD FILE (NAME = 'YourDB_IndexFile', FILENAME = 'X:\YourFolder\YourDB_IndexFile.ndf', SIZE = 500GB) TO FILEGROUP YourNewFilegroup GO You then create the indexes on that filegroup (effectively on the specified file) this way: CREATE INDEX YourIndex ON YourTable(YourColumn) ON YourNewFilegroup GO Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 17. december 2009 16:15 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] Indexes not all listed Francisco, > Flash drives do not do well with very large files. Why do you say this? I have never heard anything like this ever espoused. I have seen file TRANSFER numbers that display this, but transferring files from one disk to another is fundamentally different from reading pieces of a large file for internal processing by a program (database). From a technology perspective flash drives are a page at a time block read system interfaced to a very large cache ram interfaced to an SATA disk controller. Because of this, flash drives have two huge advantages over rotating media - (random) access time and IOPS. Getting at any block of data occurs at the speed of the electronics, but is typically around 100 nanoseconds. Exactly because of this phenomena, the number of IOs that can be processed in any given second skyrockets. Basically IOPs are dispatched instead of being queued waiting for the media to rotate and heads to move. Examine the numbers for flash vs rotating and the REAL IOPS go from the low hundreds to the mid thousands. That is a LOT more data accessed per second. In fact flash drives rapidly become "disk controller bound" precisely because they can shovel data faster than the SATA interface can move it. Even so, rotating media only uses about 10% of the capacity of the SATA interface, so if you turn around and saturate the interface with a flash drive you are getting 10 times the data moved. That is impressive and something worth shooting for. From what I have read, databases absolutely SCREAM when placed on flash drives, in fact some of the big databases are moving there exactly because of the performance gains. Databases need exactly this kind of "read a block from over here" technology that flash drives just naturally excel at. From what I am reading, placing your databases on flash is getting close to "memory resident". In my case, my databases are not transactional, they just sit there handling read requests. As a result even the known issues of wear should not be an issue. Set the db files up on a standard disk and then copy them to a flash drive, sit back and watch it fly. As for the details, what I would LIKE to do is make a raid 0 array using my intelligent raid controllers. If I could get 4 or 5 (or more) "spindles" of flash raid zero... Now back to reality. I haven't done this yet because of cost, I am money bound. ;) When I do, I will do some real life testing and publish results here. On that note, I do have a question, whether it is possible to specify what database files a specific index goes into. It happens that this table from hell uses specific columns much more frequently than others, and some columns (so far) not at all, or only once or twice. If I could create multiple data files, and then move the indexes for the first 200 fields into one file and the rest into another, then I could move that heavily used index file onto a flash and leave the rest on rotating media. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > Flash drives do not do well with very large files. Flash drives excell > at random access wich for SQL makes them good with both tempdb and > transaction log files because they both have random inserts and reads. > To improve on what you have you will want to double the number of hdd > spindles. The more spindles you have the bettertheperformance. We have > an enterprise database riding on 40 spindles, this in turn is able to > crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? > Depending on the query my developers need. We have discussed as an > architecture change that we may soon upgrade to 80 spindles. _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From jwcolby at colbyconsulting.com Thu Dec 17 13:29:00 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 17 Dec 2009 14:29:00 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <10540B34047640E6B39BBC525D3A981D@AB> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> <10540B34047640E6B39BBC525D3A981D@AB> Message-ID: <4B2A867C.4080705@colbyconsulting.com> Asger, Thanks for that, I can do that! Next question. I am looking at doing a vertical partition of this table. The table logically groups on a set of 84 fields (name / age / education etc, plus another set of about 150 fields that are heavily used, and the rest of the fields rarely (but occasionally) used. Thus I could split this thing into at least three tables, related one to one. In looking at it closely I might in fact "rearrange the columns" such that all of the heavily used fields are in a single table (including the name / age / education) and place all the rest into a single "other" table. My question then is whether the indexes for each field of these vertical split tables should be in the same file as the data fields, or split out. I guess I still don't have a handle on what part the data field plays. If the table has a clustered index, and then an index on each field, with the data in the index, at what point is the actual data back in the field of the table ever used? I thought that with the data in the index, if the index is used (and the index / field makes it a lot more likely) then I thought that the data itself was actually plucked out of the index leaf. If that is the case, then having the index on a separate database file (without the table itself), and having that database file sitting on a flash drive, I would have the smallest possible footprint to store on the flash. John W. Colby www.ColbyConsulting.com Asger Blond wrote: >> On that note, I do have a question, whether it is possible to specify what >> database files a specific index goes into. It happens that this table from >> hell uses specific columns much more frequently than others, and some >> columns (so far) not at all, or only once or twice. If I could create >> multiple data files, and then move the indexes for the first 200 fields > into one file and the rest into another, then I could move that heavily used >> index file onto a flash and leave the rest on rotating media. > > Yes, it's possible and IMO would be a good solution in your case. > Like any object in a SQL Server database an index is created on a filegroup, > and if you haven?t specifically created filegroups for your database it is > created on a filegroup called Primary. > > You can add a new filegroup and specify a file for it this way: > ALTER DATABASE YourDB ADD FILEGROUP YourNewFilegroup > GO > ALTER DATABASE YourDB ADD FILE (NAME = 'YourDB_IndexFile', > FILENAME = 'X:\YourFolder\YourDB_IndexFile.ndf', > SIZE = 500GB) > TO FILEGROUP YourNewFilegroup > GO > > You then create the indexes on that filegroup (effectively on the specified > file) this way: > CREATE INDEX YourIndex ON YourTable(YourColumn) ON YourNewFilegroup > GO > > Asger From ab-mi at post3.tele.dk Thu Dec 17 15:49:15 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Thu, 17 Dec 2009 22:49:15 +0100 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B2A867C.4080705@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com><10540B34047640E6B39BBC525D3A981D@AB> <4B2A867C.4080705@colbyconsulting.com> Message-ID: <1CD0365C142E47D4ABD8C792DD869FD7@AB> John, Sure, having the index on a separate file sitting on a flash drive will give you the best performance. Separating the data part and index part on different files residing on different spindles is a best practice for performance because both parts can then be read in parallel. But in your case the data part won't even be touched if your queries are indeed covered by the indexes. So in your case parallelism wouldn't be the argument for separation - the argument would be the extraordinary speed (and expense...) of the flash drive hosting the index. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 17. december 2009 20:29 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] Indexes not all listed Asger, Thanks for that, I can do that! Next question. I am looking at doing a vertical partition of this table. The table logically groups on a set of 84 fields (name / age / education etc, plus another set of about 150 fields that are heavily used, and the rest of the fields rarely (but occasionally) used. Thus I could split this thing into at least three tables, related one to one. In looking at it closely I might in fact "rearrange the columns" such that all of the heavily used fields are in a single table (including the name / age / education) and place all the rest into a single "other" table. My question then is whether the indexes for each field of these vertical split tables should be in the same file as the data fields, or split out. I guess I still don't have a handle on what part the data field plays. If the table has a clustered index, and then an index on each field, with the data in the index, at what point is the actual data back in the field of the table ever used? I thought that with the data in the index, if the index is used (and the index / field makes it a lot more likely) then I thought that the data itself was actually plucked out of the index leaf. If that is the case, then having the index on a separate database file (without the table itself), and having that database file sitting on a flash drive, I would have the smallest possible footprint to store on the flash. John W. Colby www.ColbyConsulting.com Asger Blond wrote: >> On that note, I do have a question, whether it is possible to specify what >> database files a specific index goes into. It happens that this table from >> hell uses specific columns much more frequently than others, and some >> columns (so far) not at all, or only once or twice. If I could create >> multiple data files, and then move the indexes for the first 200 fields > into one file and the rest into another, then I could move that heavily used >> index file onto a flash and leave the rest on rotating media. > > Yes, it's possible and IMO would be a good solution in your case. > Like any object in a SQL Server database an index is created on a filegroup, > and if you haven?t specifically created filegroups for your database it is > created on a filegroup called Primary. > > You can add a new filegroup and specify a file for it this way: > ALTER DATABASE YourDB ADD FILEGROUP YourNewFilegroup > GO > ALTER DATABASE YourDB ADD FILE (NAME = 'YourDB_IndexFile', > FILENAME = 'X:\YourFolder\YourDB_IndexFile.ndf', > SIZE = 500GB) > TO FILEGROUP YourNewFilegroup > GO > > You then create the indexes on that filegroup (effectively on the specified > file) this way: > CREATE INDEX YourIndex ON YourTable(YourColumn) ON YourNewFilegroup > GO > > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From ab-mi at post3.tele.dk Thu Dec 17 17:34:19 2009 From: ab-mi at post3.tele.dk (Asger Blond) Date: Fri, 18 Dec 2009 00:34:19 +0100 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <1CD0365C142E47D4ABD8C792DD869FD7@AB> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com><10540B34047640E6B39BBC525D3A981D@AB><4B2A867C.4080705@colbyconsulting.com> <1CD0365C142E47D4ABD8C792DD869FD7@AB> Message-ID: <23844567E5454594973EC65A15382F6E@AB> AND you use OR in your queries... SO the ultimate-extreme-surplus-fast way would be 500+ flash drives, one for each of your indexes... Question is: can you outrun your creditors with this solution... Guess not, but one flash drive hosting all 500+ indexes would be much better than placing the indexes on the same normal HD as your data file. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af Asger Blond Sendt: 17. december 2009 22:49 Til: 'Discussion concerning MS SQL Server' Emne: Re: [dba-SQLServer] Indexes not all listed John, Sure, having the index on a separate file sitting on a flash drive will give you the best performance. Separating the data part and index part on different files residing on different spindles is a best practice for performance because both parts can then be read in parallel. But in your case the data part won't even be touched if your queries are indeed covered by the indexes. So in your case parallelism wouldn't be the argument for separation - the argument would be the extraordinary speed (and expense...) of the flash drive hosting the index. Asger -----Oprindelig meddelelse----- Fra: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] P? vegne af jwcolby Sendt: 17. december 2009 20:29 Til: Discussion concerning MS SQL Server Emne: Re: [dba-SQLServer] Indexes not all listed Asger, Thanks for that, I can do that! Next question. I am looking at doing a vertical partition of this table. The table logically groups on a set of 84 fields (name / age / education etc, plus another set of about 150 fields that are heavily used, and the rest of the fields rarely (but occasionally) used. Thus I could split this thing into at least three tables, related one to one. In looking at it closely I might in fact "rearrange the columns" such that all of the heavily used fields are in a single table (including the name / age / education) and place all the rest into a single "other" table. My question then is whether the indexes for each field of these vertical split tables should be in the same file as the data fields, or split out. I guess I still don't have a handle on what part the data field plays. If the table has a clustered index, and then an index on each field, with the data in the index, at what point is the actual data back in the field of the table ever used? I thought that with the data in the index, if the index is used (and the index / field makes it a lot more likely) then I thought that the data itself was actually plucked out of the index leaf. If that is the case, then having the index on a separate database file (without the table itself), and having that database file sitting on a flash drive, I would have the smallest possible footprint to store on the flash. John W. Colby www.ColbyConsulting.com Asger Blond wrote: >> On that note, I do have a question, whether it is possible to specify what >> database files a specific index goes into. It happens that this table from >> hell uses specific columns much more frequently than others, and some >> columns (so far) not at all, or only once or twice. If I could create >> multiple data files, and then move the indexes for the first 200 fields > into one file and the rest into another, then I could move that heavily used >> index file onto a flash and leave the rest on rotating media. > > Yes, it's possible and IMO would be a good solution in your case. > Like any object in a SQL Server database an index is created on a filegroup, > and if you haven?t specifically created filegroups for your database it is > created on a filegroup called Primary. > > You can add a new filegroup and specify a file for it this way: > ALTER DATABASE YourDB ADD FILEGROUP YourNewFilegroup > GO > ALTER DATABASE YourDB ADD FILE (NAME = 'YourDB_IndexFile', > FILENAME = 'X:\YourFolder\YourDB_IndexFile.ndf', > SIZE = 500GB) > TO FILEGROUP YourNewFilegroup > GO > > You then create the indexes on that filegroup (effectively on the specified > file) this way: > CREATE INDEX YourIndex ON YourTable(YourColumn) ON YourNewFilegroup > GO > > Asger _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From bheid at sc.rr.com Sun Dec 20 17:57:41 2009 From: bheid at sc.rr.com (Bobby Heid) Date: Sun, 20 Dec 2009 18:57:41 -0500 Subject: [dba-SQLServer] Add records to large file In-Reply-To: <4B226E8E.2080109@colbyconsulting.com> References: <4B226E8E.2080109@colbyconsulting.com> Message-ID: <001f01ca81d0$37722a90$a6567fb0$@rr.com> John, If you are going to insert 50 million records into a table, then it should be much faster to create the table without the indexes, then insert the data, then create the index. If the indexes exist before the data is loaded, then it will have to insert data into the index(es) each time a record is inserted. Using a bulk load would be fastest. IIRC, bulk load drops any indexes before doing an insert. Bobby -----Original Message----- From: dba-sqlserver-bounces at databaseadvisors.com [mailto:dba-sqlserver-bounces at databaseadvisors.com] On Behalf Of jwcolby Sent: Friday, December 11, 2009 11:09 AM To: Dba-Sqlserver Subject: [dba-SQLServer] Add records to large file I don't have a clustered index on my database from hell main table, the 50 million record 600 field table. I am going to do that. What I thought I would do is simply make a new database, create a new table, and append the existing data into the new table. There is a unique integer PK which will be the key of the index. My question is whether it is faster to create the clustered index and then insert the records, already sorted in PKID, or create the table and then create the index. Logically it seems that it would be faster to do the insert sorted with the index already in place, but I have heard opinions that it is "often faster" to drop the index and recreate", i.e. do the index after the records are in place. -- John W. Colby www.ColbyConsulting.com _______________________________________________ dba-SQLServer mailing list dba-SQLServer at databaseadvisors.com http://databaseadvisors.com/mailman/listinfo/dba-sqlserver http://www.databaseadvisors.com From fhtapia at gmail.com Mon Dec 21 10:36:33 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Mon, 21 Dec 2009 08:36:33 -0800 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B2A4AE6.3060900@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: I have not tested SQL Server files, but on my 32 gb flash drive, I noticed that bigger files are slower than smaller files to both read and write to. On a few machines where the hdd have been replaced with flash drives, the OS is smoking fast where it boots from cold to full windows in just a few seconds, however even these machines start to degrade in performance whenever we place large VM files on them and whenever there has been enough reads and writes on the drive. The access time is FAST, but for large transfers of data all flash drives I have worked with up to this point have been very slow. I have not worked with any of the intel ssd's which from what I have read are supposed to be extreamly fast, and I have not worked with raid flash drives as some manufactures have architected, so ymmv. I was simply stating from my personal experience what I've come across. Most files sizes I have had problems with are all files over 15gb in size. -Francisco http://sqlthis.blogspot.com | Tsql and More... On Thu, Dec 17, 2009 at 7:14 AM, jwcolby wrote: > Francisco, > > > Flash drives do not do well with very large files. > > Why do you say this? I have never heard anything like this ever espoused. > I have seen file > TRANSFER numbers that display this, but transferring files from one disk to > another is fundamentally > different from reading pieces of a large file for internal processing by a > program (database). > > From a technology perspective flash drives are a page at a time block read > system interfaced to a > very large cache ram interfaced to an SATA disk controller. > > Because of this, flash drives have two huge advantages over rotating media > - (random) access time > and IOPS. Getting at any block of data occurs at the speed of the > electronics, but is typically > around 100 nanoseconds. Exactly because of this phenomena, the number of > IOs that can be processed > in any given second skyrockets. Basically IOPs are dispatched instead of > being queued waiting for > the media to rotate and heads to move. Examine the numbers for flash vs > rotating and the REAL IOPS > go from the low hundreds to the mid thousands. That is a LOT more data > accessed per second. > > In fact flash drives rapidly become "disk controller bound" precisely > because they can shovel data > faster than the SATA interface can move it. Even so, rotating media only > uses about 10% of the > capacity of the SATA interface, so if you turn around and saturate the > interface with a flash drive > you are getting 10 times the data moved. That is impressive and something > worth shooting for. > > From what I have read, databases absolutely SCREAM when placed on flash > drives, in fact some of the > big databases are moving there exactly because of the performance gains. > Databases need exactly > this kind of "read a block from over here" technology that flash drives > just naturally excel at. > From what I am reading, placing your databases on flash is getting close > to "memory resident". > > In my case, my databases are not transactional, they just sit there > handling read requests. As a > result even the known issues of wear should not be an issue. Set the db > files up on a standard disk > and then copy them to a flash drive, sit back and watch it fly. > > As for the details, what I would LIKE to do is make a raid 0 array using my > intelligent raid > controllers. If I could get 4 or 5 (or more) "spindles" of flash raid > zero... > > Now back to reality. I haven't done this yet because of cost, I am money > bound. ;) When I do, I > will do some real life testing and publish results here. > > On that note, I do have a question, whether it is possible to specify what > database files a specific > index goes into. It happens that this table from hell uses specific > columns much more frequently > than others, and some columns (so far) not at all, or only once or twice. > If I could create > multiple data files, and then move the indexes for the first 200 fields > into one file and the rest > into another, then I could move that heavily used index file onto a flash > and leave the rest on > rotating media. > > John W. Colby > www.ColbyConsulting.com > > > Francisco Tapia wrote: > > Flash drives do not do well with very large files. Flash drives excell > > at random access wich for SQL makes them good with both tempdb and > > transaction log files because they both have random inserts and reads. > > To improve on what you have you will want to double the number of hdd > > spindles. The more spindles you have the bettertheperformance. We have > > an enterprise database riding on 40 spindles, this in turn is able to > > crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? > > Depending on the query my developers need. We have discussed as an > > architecture change that we may soon upgrade to 80 spindles. > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Mon Dec 21 11:40:46 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Mon, 21 Dec 2009 12:40:46 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: <4B2FB31E.9060904@colbyconsulting.com> Francisco, Flash drives are notorious for slow writes. One thing to know is that flash drives have historically had an issue with the controller inside of them. There was a company that was "the" supplier and they weren't doing a very good job. This article is old but a good place to start understanding the issues: http://benchmarkreviews.com/index.php?option=com_content&task=view&id=299&Itemid=60&limit=1&limitstart=12 In particular note the pages for random access speed http://benchmarkreviews.com/index.php?option=com_content&task=view&id=299&Itemid=60&limit=1&limitstart=5 and I/Os per second http://benchmarkreviews.com/index.php?option=com_content&task=view&id=299&Itemid=60&limit=1&limitstart=8 I purchased an OCZ Vertex 30 gig drive shortly after reading this stuff and have been quite pleased with the performance. OTOH I have NOT used it as the home for huge database files. That is my intent however. This "new" generation of drives has *mostly* solved the various problems encountered. I can tell you that I partitioned my 30 gig drive and gave each partition to a VM (four VMs total) running on one of my servers. This was used as storage of about 1 gig of foxpro database files for the Accuzip address validation software. These files are read-only. Placing these files on a regular hard disk allowed three VMs to process around 1 million records per hour. Placing these files on a hardware "RAM DISK" (Gigabyte i-Ram) upped that to about 2 million records / hour. Placing these files on a my Vertex 30 gig Flash drive allowed all three VMs to process simultaneously and the speed climbed from around 2 million records per hour to between 5 and 6 million records per hour. Essentially I more than doubled my processing speed for each of three virtual machines using a single flash drive. I credit this to the increased IOPS and streaming read speeds. This technology ROCKS for *some* purposes. We shall have to wait and see if it rocks for large SQL Server read only files, but I suspect that it will. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > I have not tested SQL Server files, but on my 32 gb flash drive, I noticed > that bigger files are slower than smaller files to both read and write to. > On a few machines where the hdd have been replaced with flash drives, the > OS is smoking fast where it boots from cold to full windows in just a few > seconds, however even these machines start to degrade in performance > whenever we place large VM files on them and whenever there has been enough > reads and writes on the drive. The access time is FAST, but for large > transfers of data all flash drives I have worked with up to this point have > been very slow. I have not worked with any of the intel ssd's which from > what I have read are supposed to be extreamly fast, and I have not worked > with raid flash drives as some manufactures have architected, so ymmv. I > was simply stating from my personal experience what I've come across. Most > files sizes I have had problems with are all files over 15gb in size. > > -Francisco > http://sqlthis.blogspot.com | Tsql and More... > > > On Thu, Dec 17, 2009 at 7:14 AM, jwcolby wrote: > >> Francisco, >> >> > Flash drives do not do well with very large files. >> >> Why do you say this? I have never heard anything like this ever espoused. >> I have seen file >> TRANSFER numbers that display this, but transferring files from one disk to >> another is fundamentally >> different from reading pieces of a large file for internal processing by a >> program (database). >> >> From a technology perspective flash drives are a page at a time block read >> system interfaced to a >> very large cache ram interfaced to an SATA disk controller. >> >> Because of this, flash drives have two huge advantages over rotating media >> - (random) access time >> and IOPS. Getting at any block of data occurs at the speed of the >> electronics, but is typically >> around 100 nanoseconds. Exactly because of this phenomena, the number of >> IOs that can be processed >> in any given second skyrockets. Basically IOPs are dispatched instead of >> being queued waiting for >> the media to rotate and heads to move. Examine the numbers for flash vs >> rotating and the REAL IOPS >> go from the low hundreds to the mid thousands. That is a LOT more data >> accessed per second. >> >> In fact flash drives rapidly become "disk controller bound" precisely >> because they can shovel data >> faster than the SATA interface can move it. Even so, rotating media only >> uses about 10% of the >> capacity of the SATA interface, so if you turn around and saturate the >> interface with a flash drive >> you are getting 10 times the data moved. That is impressive and something >> worth shooting for. >> >> From what I have read, databases absolutely SCREAM when placed on flash >> drives, in fact some of the >> big databases are moving there exactly because of the performance gains. >> Databases need exactly >> this kind of "read a block from over here" technology that flash drives >> just naturally excel at. >> From what I am reading, placing your databases on flash is getting close >> to "memory resident". >> >> In my case, my databases are not transactional, they just sit there >> handling read requests. As a >> result even the known issues of wear should not be an issue. Set the db >> files up on a standard disk >> and then copy them to a flash drive, sit back and watch it fly. >> >> As for the details, what I would LIKE to do is make a raid 0 array using my >> intelligent raid >> controllers. If I could get 4 or 5 (or more) "spindles" of flash raid >> zero... >> >> Now back to reality. I haven't done this yet because of cost, I am money >> bound. ;) When I do, I >> will do some real life testing and publish results here. >> >> On that note, I do have a question, whether it is possible to specify what >> database files a specific >> index goes into. It happens that this table from hell uses specific >> columns much more frequently >> than others, and some columns (so far) not at all, or only once or twice. >> If I could create >> multiple data files, and then move the indexes for the first 200 fields >> into one file and the rest >> into another, then I could move that heavily used index file onto a flash >> and leave the rest on >> rotating media. >> >> John W. Colby >> www.ColbyConsulting.com >> >> >> Francisco Tapia wrote: >>> Flash drives do not do well with very large files. Flash drives excell >>> at random access wich for SQL makes them good with both tempdb and >>> transaction log files because they both have random inserts and reads. >>> To improve on what you have you will want to double the number of hdd >>> spindles. The more spindles you have the bettertheperformance. We have >>> an enterprise database riding on 40 spindles, this in turn is able to >>> crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? >>> Depending on the query my developers need. We have discussed as an >>> architecture change that we may soon upgrade to 80 spindles. >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From marklbreen at gmail.com Tue Dec 22 03:31:25 2009 From: marklbreen at gmail.com (Mark Breen) Date: Tue, 22 Dec 2009 09:31:25 +0000 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: Hello Francisco, ymmv ? You may ... ... ? You might ... ...? You must ... ...? Yonder Machines May Virtualise? Thanks Mark 2009/12/21 Francisco Tapia > I have not tested SQL Server files, but on my 32 gb flash drive, I noticed > that bigger files are slower than smaller files to both read and write to. > On a few machines where the hdd have been replaced with flash drives, the > OS is smoking fast where it boots from cold to full windows in just a few > seconds, however even these machines start to degrade in performance > whenever we place large VM files on them and whenever there has been enough > reads and writes on the drive. The access time is FAST, but for large > transfers of data all flash drives I have worked with up to this point have > been very slow. I have not worked with any of the intel ssd's which from > what I have read are supposed to be extreamly fast, and I have not worked > with raid flash drives as some manufactures have architected, so ymmv. I > was simply stating from my personal experience what I've come across. Most > files sizes I have had problems with are all files over 15gb in size. > > -Francisco > http://sqlthis.blogspot.com | Tsql and More... > > > On Thu, Dec 17, 2009 at 7:14 AM, jwcolby >wrote: > > > Francisco, > > > > > Flash drives do not do well with very large files. > > > > Why do you say this? I have never heard anything like this ever > espoused. > > I have seen file > > TRANSFER numbers that display this, but transferring files from one disk > to > > another is fundamentally > > different from reading pieces of a large file for internal processing by > a > > program (database). > > > > From a technology perspective flash drives are a page at a time block > read > > system interfaced to a > > very large cache ram interfaced to an SATA disk controller. > > > > Because of this, flash drives have two huge advantages over rotating > media > > - (random) access time > > and IOPS. Getting at any block of data occurs at the speed of the > > electronics, but is typically > > around 100 nanoseconds. Exactly because of this phenomena, the number of > > IOs that can be processed > > in any given second skyrockets. Basically IOPs are dispatched instead of > > being queued waiting for > > the media to rotate and heads to move. Examine the numbers for flash vs > > rotating and the REAL IOPS > > go from the low hundreds to the mid thousands. That is a LOT more data > > accessed per second. > > > > In fact flash drives rapidly become "disk controller bound" precisely > > because they can shovel data > > faster than the SATA interface can move it. Even so, rotating media only > > uses about 10% of the > > capacity of the SATA interface, so if you turn around and saturate the > > interface with a flash drive > > you are getting 10 times the data moved. That is impressive and > something > > worth shooting for. > > > > From what I have read, databases absolutely SCREAM when placed on flash > > drives, in fact some of the > > big databases are moving there exactly because of the performance gains. > > Databases need exactly > > this kind of "read a block from over here" technology that flash drives > > just naturally excel at. > > From what I am reading, placing your databases on flash is getting close > > to "memory resident". > > > > In my case, my databases are not transactional, they just sit there > > handling read requests. As a > > result even the known issues of wear should not be an issue. Set the db > > files up on a standard disk > > and then copy them to a flash drive, sit back and watch it fly. > > > > As for the details, what I would LIKE to do is make a raid 0 array using > my > > intelligent raid > > controllers. If I could get 4 or 5 (or more) "spindles" of flash raid > > zero... > > > > Now back to reality. I haven't done this yet because of cost, I am money > > bound. ;) When I do, I > > will do some real life testing and publish results here. > > > > On that note, I do have a question, whether it is possible to specify > what > > database files a specific > > index goes into. It happens that this table from hell uses specific > > columns much more frequently > > than others, and some columns (so far) not at all, or only once or twice. > > If I could create > > multiple data files, and then move the indexes for the first 200 fields > > into one file and the rest > > into another, then I could move that heavily used index file onto a flash > > and leave the rest on > > rotating media. > > > > John W. Colby > > www.ColbyConsulting.com > > > > > > Francisco Tapia wrote: > > > Flash drives do not do well with very large files. Flash drives excell > > > at random access wich for SQL makes them good with both tempdb and > > > transaction log files because they both have random inserts and reads. > > > To improve on what you have you will want to double the number of hdd > > > spindles. The more spindles you have the bettertheperformance. We have > > > an enterprise database riding on 40 spindles, this in turn is able to > > > crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? > > > Depending on the query my developers need. We have discussed as an > > > architecture change that we may soon upgrade to 80 spindles. > > > > _______________________________________________ > > dba-SQLServer mailing list > > dba-SQLServer at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > > http://www.databaseadvisors.com > > > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From stuart at lexacorp.com.pg Tue Dec 22 05:49:49 2009 From: stuart at lexacorp.com.pg (Stuart McLachlan) Date: Tue, 22 Dec 2009 21:49:49 +1000 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com>, , Message-ID: <4B30B25D.4855.25E2216B@stuart.lexacorp.com.pg> Your mileage may vary :-) -- Stuart On 22 Dec 2009 at 9:31, Mark Breen wrote: > Hello Francisco, > > ymmv ? > > You may ... ... ? > You might ... ...? > You must ... ...? > Yonder Machines May Virtualise? > > Thanks > > Mark > > > > 2009/12/21 Francisco Tapia > > > I have not tested SQL Server files, but on my 32 gb flash drive, I noticed > > that bigger files are slower than smaller files to both read and write to. > > On a few machines where the hdd have been replaced with flash drives, the > > OS is smoking fast where it boots from cold to full windows in just a few > > seconds, however even these machines start to degrade in performance > > whenever we place large VM files on them and whenever there has been enough > > reads and writes on the drive. The access time is FAST, but for large > > transfers of data all flash drives I have worked with up to this point have > > been very slow. I have not worked with any of the intel ssd's which from > > what I have read are supposed to be extreamly fast, and I have not worked > > with raid flash drives as some manufactures have architected, so ymmv. I > > was simply stating from my personal experience what I've come across. Most > > files sizes I have had problems with are all files over 15gb in size. > > > > -Francisco > > http://sqlthis.blogspot.com | Tsql and More... > > > > > > On Thu, Dec 17, 2009 at 7:14 AM, jwcolby > >wrote: > > > > > Francisco, > > > > > > > Flash drives do not do well with very large files. > > > > > > Why do you say this? I have never heard anything like this ever > > espoused. > > > I have seen file > > > TRANSFER numbers that display this, but transferring files from one disk > > to > > > another is fundamentally > > > different from reading pieces of a large file for internal processing by > > a > > > program (database). > > > > > > From a technology perspective flash drives are a page at a time block > > read > > > system interfaced to a > > > very large cache ram interfaced to an SATA disk controller. > > > > > > Because of this, flash drives have two huge advantages over rotating > > media > > > - (random) access time > > > and IOPS. Getting at any block of data occurs at the speed of the > > > electronics, but is typically > > > around 100 nanoseconds. Exactly because of this phenomena, the number of > > > IOs that can be processed > > > in any given second skyrockets. Basically IOPs are dispatched instead of > > > being queued waiting for > > > the media to rotate and heads to move. Examine the numbers for flash vs > > > rotating and the REAL IOPS > > > go from the low hundreds to the mid thousands. That is a LOT more data > > > accessed per second. > > > > > > In fact flash drives rapidly become "disk controller bound" precisely > > > because they can shovel data > > > faster than the SATA interface can move it. Even so, rotating media only > > > uses about 10% of the > > > capacity of the SATA interface, so if you turn around and saturate the > > > interface with a flash drive > > > you are getting 10 times the data moved. That is impressive and > > something > > > worth shooting for. > > > > > > From what I have read, databases absolutely SCREAM when placed on flash > > > drives, in fact some of the > > > big databases are moving there exactly because of the performance gains. > > > Databases need exactly > > > this kind of "read a block from over here" technology that flash drives > > > just naturally excel at. > > > From what I am reading, placing your databases on flash is getting close > > > to "memory resident". > > > > > > In my case, my databases are not transactional, they just sit there > > > handling read requests. As a > > > result even the known issues of wear should not be an issue. Set the db > > > files up on a standard disk > > > and then copy them to a flash drive, sit back and watch it fly. > > > > > > As for the details, what I would LIKE to do is make a raid 0 array using > > my > > > intelligent raid > > > controllers. If I could get 4 or 5 (or more) "spindles" of flash raid > > > zero... > > > > > > Now back to reality. I haven't done this yet because of cost, I am money > > > bound. ;) When I do, I > > > will do some real life testing and publish results here. > > > > > > On that note, I do have a question, whether it is possible to specify > > what > > > database files a specific > > > index goes into. It happens that this table from hell uses specific > > > columns much more frequently > > > than others, and some columns (so far) not at all, or only once or twice. > > > If I could create > > > multiple data files, and then move the indexes for the first 200 fields > > > into one file and the rest > > > into another, then I could move that heavily used index file onto a flash > > > and leave the rest on > > > rotating media. > > > > > > John W. Colby > > > www.ColbyConsulting.com > > > > > > > > > Francisco Tapia wrote: > > > > Flash drives do not do well with very large files. Flash drives excell > > > > at random access wich for SQL makes them good with both tempdb and > > > > transaction log files because they both have random inserts and reads. > > > > To improve on what you have you will want to double the number of hdd > > > > spindles. The more spindles you have the bettertheperformance. We have > > > > an enterprise database riding on 40 spindles, this in turn is able to > > > > crank out searches for a 1.5 terabyte db in usually 10 seconds to ??? > > > > Depending on the query my developers need. We have discussed as an > > > > architecture change that we may soon upgrade to 80 spindles. > > > > > > _______________________________________________ > > > dba-SQLServer mailing list > > > dba-SQLServer at databaseadvisors.com > > > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > > > http://www.databaseadvisors.com > > > > > > > > _______________________________________________ > > dba-SQLServer mailing list > > dba-SQLServer at databaseadvisors.com > > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > > http://www.databaseadvisors.com > > > > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From fhtapia at gmail.com Tue Dec 22 07:56:12 2009 From: fhtapia at gmail.com (Francisco Tapia) Date: Tue, 22 Dec 2009 05:56:12 -0800 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: <5BBC4402-2206-41C5-B26F-45603800C5AE@gmail.com> Your milage may vary. Like I said my expiriance is very different from what Colby had as results. Part of my issues were that my test involves USB drives an it could just be the bus problems. But I have not seen performance like Colby mentioned I even triedthat speed boost in vista whichwas supposed to be fast by moving in readonly files to a 4gb drive and make it available to the os quicker than the sata drive. On the machine with the ssd drive as the primary drive I am unsure if this drive was intel or some other type. On anandtech.com they did an extensive review on flash ssd and why they slow down over time. Sent from my mobile On Dec 22, 2009, at 1:31 AM, Mark Breen wrote: > Hello Francisco, > > ymmv ? > > You may ... ... ? > You might ... ...? > You must ... ...? > Yonder Machines May Virtualise? > > Thanks > > Mark > > > > 2009/12/21 Francisco Tapia > >> I have not tested SQL Server files, but on my 32 gb flash drive, I >> noticed >> that bigger files are slower than smaller files to both read and >> write to. >> On a few machines where the hdd have been replaced with flash >> drives, the >> OS is smoking fast where it boots from cold to full windows in just >> a few >> seconds, however even these machines start to degrade in performance >> whenever we place large VM files on them and whenever there has >> been enough >> reads and writes on the drive. The access time is FAST, but for >> large >> transfers of data all flash drives I have worked with up to this >> point have >> been very slow. I have not worked with any of the intel ssd's >> which from >> what I have read are supposed to be extreamly fast, and I have not >> worked >> with raid flash drives as some manufactures have architected, so >> ymmv. I >> was simply stating from my personal experience what I've come >> across. Most >> files sizes I have had problems with are all files over 15gb in size. >> >> -Francisco >> http://sqlthis.blogspot.com | Tsql and More... >> >> >> On Thu, Dec 17, 2009 at 7:14 AM, jwcolby >> wrote: >> >>> Francisco, >>> >>>> Flash drives do not do well with very large files. >>> >>> Why do you say this? I have never heard anything like this ever >> espoused. >>> I have seen file >>> TRANSFER numbers that display this, but transferring files from >>> one disk >> to >>> another is fundamentally >>> different from reading pieces of a large file for internal >>> processing by >> a >>> program (database). >>> >>> From a technology perspective flash drives are a page at a time >>> block >> read >>> system interfaced to a >>> very large cache ram interfaced to an SATA disk controller. >>> >>> Because of this, flash drives have two huge advantages over rotating >> media >>> - (random) access time >>> and IOPS. Getting at any block of data occurs at the speed of the >>> electronics, but is typically >>> around 100 nanoseconds. Exactly because of this phenomena, the >>> number of >>> IOs that can be processed >>> in any given second skyrockets. Basically IOPs are dispatched >>> instead of >>> being queued waiting for >>> the media to rotate and heads to move. Examine the numbers for >>> flash vs >>> rotating and the REAL IOPS >>> go from the low hundreds to the mid thousands. That is a LOT more >>> data >>> accessed per second. >>> >>> In fact flash drives rapidly become "disk controller bound" >>> precisely >>> because they can shovel data >>> faster than the SATA interface can move it. Even so, rotating >>> media only >>> uses about 10% of the >>> capacity of the SATA interface, so if you turn around and saturate >>> the >>> interface with a flash drive >>> you are getting 10 times the data moved. That is impressive and >> something >>> worth shooting for. >>> >>> From what I have read, databases absolutely SCREAM when placed on >>> flash >>> drives, in fact some of the >>> big databases are moving there exactly because of the performance >>> gains. >>> Databases need exactly >>> this kind of "read a block from over here" technology that flash >>> drives >>> just naturally excel at. >>> From what I am reading, placing your databases on flash is getting >>> close >>> to "memory resident". >>> >>> In my case, my databases are not transactional, they just sit there >>> handling read requests. As a >>> result even the known issues of wear should not be an issue. Set >>> the db >>> files up on a standard disk >>> and then copy them to a flash drive, sit back and watch it fly. >>> >>> As for the details, what I would LIKE to do is make a raid 0 array >>> using >> my >>> intelligent raid >>> controllers. If I could get 4 or 5 (or more) "spindles" of flash >>> raid >>> zero... >>> >>> Now back to reality. I haven't done this yet because of cost, I >>> am money >>> bound. ;) When I do, I >>> will do some real life testing and publish results here. >>> >>> On that note, I do have a question, whether it is possible to >>> specify >> what >>> database files a specific >>> index goes into. It happens that this table from hell uses specific >>> columns much more frequently >>> than others, and some columns (so far) not at all, or only once or >>> twice. >>> If I could create >>> multiple data files, and then move the indexes for the first 200 >>> fields >>> into one file and the rest >>> into another, then I could move that heavily used index file onto >>> a flash >>> and leave the rest on >>> rotating media. >>> >>> John W. Colby >>> www.ColbyConsulting.com >>> >>> >>> Francisco Tapia wrote: >>>> Flash drives do not do well with very large files. Flash drives >>>> excell >>>> at random access wich for SQL makes them good with both tempdb and >>>> transaction log files because they both have random inserts and >>>> reads. >>>> To improve on what you have you will want to double the number of >>>> hdd >>>> spindles. The more spindles you have the bettertheperformance. We >>>> have >>>> an enterprise database riding on 40 spindles, this in turn is >>>> able to >>>> crank out searches for a 1.5 terabyte db in usually 10 seconds >>>> to ??? >>>> Depending on the query my developers need. We have discussed as an >>>> architecture change that we may soon upgrade to 80 spindles. >>> >>> _______________________________________________ >>> dba-SQLServer mailing list >>> dba-SQLServer at databaseadvisors.com >>> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >>> http://www.databaseadvisors.com >>> >>> >> _______________________________________________ >> dba-SQLServer mailing list >> dba-SQLServer at databaseadvisors.com >> http://databaseadvisors.com/mailman/listinfo/dba-sqlserver >> http://www.databaseadvisors.com >> >> > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > From jwcolby at colbyconsulting.com Tue Dec 22 08:05:55 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 22 Dec 2009 09:05:55 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> Message-ID: <4B30D243.8020708@colbyconsulting.com> Your Mileage May Vary. Used in car commercials here in the US to let you know that there is no way in hell that you will get anything close to the mileage that they are telling you that you will get. We Americans are famous for suing at the drop of a hat, so car commercials (and many others like medical) have an announcer come on at the end of the commercial and read about two minutes of disclaimer stuff in a 30 second period of time. the ones for medicines are often quite humorous because the list of side effects of the medicines often far outweigh what the medicine is supposed to cure. Used in emails like this, YMMV it simply means that you may or may not see the same results. John W. Colby www.ColbyConsulting.com Mark Breen wrote: > Hello Francisco, > > ymmv ? > > You may ... ... ? > You might ... ...? > You must ... ...? > Yonder Machines May Virtualise? > > Thanks > > Mark From jwcolby at colbyconsulting.com Tue Dec 22 08:49:08 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Tue, 22 Dec 2009 09:49:08 -0500 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <5BBC4402-2206-41C5-B26F-45603800C5AE@gmail.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> <5BBC4402-2206-41C5-B26F-45603800C5AE@gmail.com> Message-ID: <4B30DC64.9070205@colbyconsulting.com> >Part of my issues were that my test involves USB drives an it could just be the bus problems. This is absolutely true. There are NO USB drives (or flash memory cards for that matter) that even approach the speeds of flash solid state drives. The SSDs have an entirely different controller internally, they have massive amounts of cache ram, and they interface via the SATA II interface. >On anandtech.com they did an extensive review on flash ssd and why they slow down over time. And all of that is absolutely true, even with the fast flash drives that I mentioned and am using. Windows 7 has built-in stuff (trim) for sensing that it is using a flash and dynamically manipulating the drive to perform housekeeping that keeps the flash drive working at its full potential. Even here the flash drive has to have firmware that supports that. For Vista there are tools available that do the same thing, though I am not familiar with how they are used. Bottom line, Flash drives are NOT rotating media, they do have issues and they do require special handling, particularly if you are using them with older OSes. You cannot expect to just "drop one in" and see all of the advantages forever. That said, much of the issue comes from *writes* over time. As you all know, my Database From Hell is a read-only database, completely static. Thus I have every expectation that *for this database* I could use flash drives without experiencing the issues that flash drives are so famous for. Last week I rebuilt my Windows Media Center HTPC. I decided to upgrade it from Vista to Windows 7 (as a student I got a license for $29). It was not an upgrade in the classic sense, I did a clean install, but I did so on my 30 gig OCZ Vertex SSD. I upgraded the firmware of the flash drive, then did a clean install of Windows 7. So I am now using a modern SSD as the boot drive for Windows 7. I placed all of the TV recordings out on a rotating media, and I am pulling the movie content from my server upstairs in my office. So far the system is fast and stable, much more stable than Vista MCE was. We shall see how it holds up over the long term. John W. Colby www.ColbyConsulting.com Francisco Tapia wrote: > Your milage may vary. > > Like I said my expiriance is very different from what Colby had as > results. Part of my issues were that my test involves USB drives an it > could just be the bus problems. But I have not seen performance like > Colby mentioned I even triedthat speed boost in vista whichwas > supposed to be fast by moving in readonly files to a 4gb drive and > make it available to the os quicker than the sata drive. > > On the machine with the ssd drive as the primary drive I am unsure if > this drive was intel or some other type. On anandtech.com they did an > extensive review on flash ssd and why they slow down over time. > > Sent from my mobile From marklbreen at gmail.com Wed Dec 23 05:17:26 2009 From: marklbreen at gmail.com (Mark Breen) Date: Wed, 23 Dec 2009 11:17:26 +0000 Subject: [dba-SQLServer] Indexes not all listed In-Reply-To: <4B30DC64.9070205@colbyconsulting.com> References: <4B284C48.7040506@colbyconsulting.com> <4B28F09E.1030308@colbyconsulting.com> <4B2A4AE6.3060900@colbyconsulting.com> <5BBC4402-2206-41C5-B26F-45603800C5AE@gmail.com> <4B30DC64.9070205@colbyconsulting.com> Message-ID: YMMV, yes, sorry I saw it before but forgot it. I am looking forward to using it with someone over here where the expression is not so common. Thanks All, Mark 2009/12/22 jwcolby > >Part of my issues were that my test involves USB drives an it could just > be the bus problems. > > This is absolutely true. There are NO USB drives (or flash memory cards > for that matter) that even > approach the speeds of flash solid state drives. The SSDs have an entirely > different controller > internally, they have massive amounts of cache ram, and they interface via > the SATA II interface. > > >On anandtech.com they did an extensive review on flash ssd and why they > slow down over time. > > And all of that is absolutely true, even with the fast flash drives that I > mentioned and am using. > Windows 7 has built-in stuff (trim) for sensing that it is using a flash > and dynamically > manipulating the drive to perform housekeeping that keeps the flash drive > working at its full > potential. Even here the flash drive has to have firmware that supports > that. For Vista there are > tools available that do the same thing, though I am not familiar with how > they are used. > > Bottom line, Flash drives are NOT rotating media, they do have issues and > they do require special > handling, particularly if you are using them with older OSes. You cannot > expect to just "drop one > in" and see all of the advantages forever. > > That said, much of the issue comes from *writes* over time. As you all > know, my Database From Hell > is a read-only database, completely static. Thus I have every expectation > that *for this database* > I could use flash drives without experiencing the issues that flash drives > are so famous for. > > Last week I rebuilt my Windows Media Center HTPC. I decided to upgrade it > from Vista to Windows 7 > (as a student I got a license for $29). It was not an upgrade in the > classic sense, I did a clean > install, but I did so on my 30 gig OCZ Vertex SSD. I upgraded the firmware > of the flash drive, then > did a clean install of Windows 7. So I am now using a modern SSD as the > boot drive for Windows 7. > I placed all of the TV recordings out on a rotating media, and I am pulling > the movie content from > my server upstairs in my office. So far the system is fast and stable, > much more stable than Vista > MCE was. We shall see how it holds up over the long term. > > John W. Colby > www.ColbyConsulting.com > > > Francisco Tapia wrote: > > Your milage may vary. > > > > Like I said my expiriance is very different from what Colby had as > > results. Part of my issues were that my test involves USB drives an it > > could just be the bus problems. But I have not seen performance like > > Colby mentioned I even triedthat speed boost in vista whichwas > > supposed to be fast by moving in readonly files to a 4gb drive and > > make it available to the os quicker than the sata drive. > > > > On the machine with the ssd drive as the primary drive I am unsure if > > this drive was intel or some other type. On anandtech.com they did an > > extensive review on flash ssd and why they slow down over time. > > > > Sent from my mobile > > _______________________________________________ > dba-SQLServer mailing list > dba-SQLServer at databaseadvisors.com > http://databaseadvisors.com/mailman/listinfo/dba-sqlserver > http://www.databaseadvisors.com > > From jwcolby at colbyconsulting.com Thu Dec 31 16:29:43 2009 From: jwcolby at colbyconsulting.com (jwcolby) Date: Thu, 31 Dec 2009 17:29:43 -0500 Subject: [dba-SQLServer] Happy new year Message-ID: <4B3D25D7.2030404@colbyconsulting.com> I will likely be asleep when it actually happens locally, so I wish each and every one of you a MUCH better year in 2010. HAPPY NEW YEAR! -- John W. Colby www.ColbyConsulting.com From garykjos at gmail.com Thu Dec 31 16:35:55 2009 From: garykjos at gmail.com (Gary Kjos) Date: Thu, 31 Dec 2009 16:35:55 -0600 Subject: [dba-SQLServer] [AccessD] Happy new year In-Reply-To: <4B3D25D7.2030404@colbyconsulting.com> References: <4B3D25D7.2030404@colbyconsulting.com> Message-ID: Likewise for me too John. Early to bed, early to rise is my program for the most part. I echo your sentiments. Happy New Year! GK On Thu, Dec 31, 2009 at 4:29 PM, jwcolby wrote: > I will likely be asleep when it actually happens locally, so I wish each and every one of you a MUCH > better year in 2010. > > HAPPY NEW YEAR! > > -- > John W. Colby > www.ColbyConsulting.com -- Gary Kjos garykjos at gmail.com