Thursday, November 14, 2013

Curing slow INSERTs and CREATE TABLEs I.

Sponsored by PRISE Ltd.
www.prisetools.com

Eliminating hash collisions

Case description

We have an INSERT or CREATE TABLE operation that runs unreasonably long time compared to the affected number of rows, in spite the table is not skewed.

What is hash collision?

Hash collision is when two or more records in a table have the same hash value.

SET type of tables ensure that there are no more records with exactly the same record content within a table. How does Teradata do it?

Teradata stores the records in a hash filesystem, where each record has a hash value calculated from the Primary Index (PI) value. If the PI values are the same in more records, they will surely have the same hash value either.

When INSERTING a record, Teradata has to compare the new record to the table's only those records that have the same hash value that new record has, since all records with different hash value will surely differ at least at the PI columns.
If we have to INSERT N records with the same hash value into an empty table, Teradata has to do N*(N-1)/2 times - very CPU demanding - full record comparisons.

How to identify

Hash collisions can be easily found by using PRISE Tuning Assistant tool also, or follow this method:

DBQL filtering for qualifying queries:
The Merge (MRG) phase of the INSERT/CREATE TABLE operation consumes lot of CPU.
Look for high CPU consuming 'MRG' steps in the dbc.DBQLStepTbl:

sel a.cputime,a.MaxAmpCPUTime * (hashamp() +1) CoveringCPUTIme,  a.stepname,a.RowCount,b.* from
     dbc.DBQLStepTbl a
join dbc.DBQLogTbl   b on a.ProcId=b.ProcId and a.QueryId=b.QueryId
where
    a.StepName in ('MRG' /*, 'MRU' for UPDATEs also*/)
and a.CPUTime > 100 /* Performance boost: eliminates most of the records (small cpu seconds) at low processing cost. Adapt number to your site */
qualify sum(1) over (order by a.cputime desc rows unbounded preceding) <= 100;

 

At a specific SQL statement (INSERT or CREATE TABLE) you have to check your PI for level of hash collisions (number of records where the hash values are the same) in the target table.

How to make sure that the hash-collision is the reason? Let the target table be TableA, with primary index: ColA,ColB,ColC (can be any number of columns in practice)

select top 100 hashrow(ColA,ColB,ColC), count(*) from TableA group by 1 order by 2 desc;


The top row(s) will show the most frequent hash values. Count values >>1 mean significant hash collisions in the order of N * N. Each high frequency hash value will generate a hash-collision group causing comparisons in the order of N*N.

If the table still not exists, embed the producing "SELECT" statement into the script above, and count those field values that would get to the PI columns.


Explanation

If we use "SET" type of table (this is the default setting), Teradata ensures that there will be no perfectly alike records in the table. This can be ensured by comparing the inserted/updated record with the existing ones.
Teradata's "hash filesystem" gives a very effective trick: only those records must be compared, whose RowID (hash) equals, otherwise at least the PI fields must differ.
If we've chosen the Primary Index for UNIQUE, or non-UNIQUE, but on field(s) that are almost unique, then the "SET comparison"
restricts to zero or one records in most cases.


Solution

For good solution unfortunately we have to modify the table structure.
  • Option 1: Change table type to MULTISET. This will eliminate duplication checks, but its disadvantage is the same. If the process falls back on the de-duplication of SET table, you have to replace it with programmed de-duplication (group by, left join...).
  • Option2: Change the table's PI to a unique or nearly unique column set. Be prudent, consider the workload also. (joins, where conditions, group by expressions, etc.)

Summary

Tables with strongly non unique PI are highly dangered for hash collision slowed INSERTs/CREATE TABLEs (or UPDATEs), even if they are not skewed. Use "more unique" PI, or MULTISET table.

Typical mistake: if a CREATE TABLE ... as SELECT... lacks the PRIMARY INDEX() section. In this case Teradata chooses the first column as PI, which often causes terrible performance.

What's next

Next post will discuss Multi Value Compress (MVC) optimization.

Sponsored by PRISE Ltd.
www.prisetools.com

6 comments:

  1. Hi,
    I have a SET table which is 1TB of size and it has UPI on it. Will it cause and performance issue? Explain in detail.

    ReplyDelete
  2. Hi Agilan,

    Concerning "hash collision" there will be no problem at all, since PI is unique.
    However you can experience I/O problems when you insert lots of data into it, if you do not use partitioning (PPI). The reason is that the table is huge, the records reside in large amount of data blocks. Since the loaded records will distribute among the data blocks (not just the AMPs) evenly, so you will modify probably as many data blocks as many records you insert, and in addition these blocks reside randomly on the disk. It is not effective. However if you apply partitioning, that is coherent with the increment data to be inserted. Typically it is a date partitionong and the increment data is related to the last day or something. This way the increment data will reside densely in much less data blocks since the data is physically ordered by the partition_id. The result is: much less data blocks to be written, and most of them reside continouosly on the disk and can be handled by multi-block operations.

    Additionally I always suggest to use multi value compression on big tables, since that reduces the I/O and sometimes CPU(!) requirements.

    I hope it helped.

    ReplyDelete
    Replies
    1. Hi Akos,

      Thanks for the explanation.

      During the data load, The SET and UPI will act together.
      SET behaviour checks for full row duplication and UPI check for column level duplication.
      So if we have SET and UPI in a table, the insert may take long time.
      I feel UPI with MULTISET table may result better.

      Can you add your comment/solution on this?

      P:S:- NO PPI included in the table.

      Delete
  3. Hi,

    I do not know the internal algorithms, but UPI ensures the uniqueness of the PI part of the row, therefore the whole row is unique as a consequence. So the SET row-deduplication need not to be executed in this case.
    I executed a small test and did not experience significant difference between SET and MULTISET cases. (10M records)
    Properly chosen PPI will speed up the INSERT dramatically, and help a lot with SELECT also in case of appropriate workload.

    ReplyDelete
  4. Agilan,

    One more thought:
    If SET de-duplication if still in effect at UPI tables it will not cause performance issues, since SET de-duplication only examines the hash-synonyms of the record to be inserted. Since the PI is unique the probablity of hash collisions (existing synonym) is very very low, so the number of comparisons are very low.
    As a summary my opinion is that "SET" performance issue may occure only in case of NUPI tables, while SET gives no extra benefit in case of UPI tables, since uniqueness is already ensured by the PI.

    ReplyDelete
  5. hi,
    How can we identify the username among number of users that one user who has deleted the table from database by using DBQLs of Teradata admin Tool, if possible snap shot to setup of DBQL logs and all monitoring steps:

    ReplyDelete