Help: SQL Server

Sharing my knowlege about SQL Server Troubleshooting Skills

  • Blog Stats

    • 2,156,099 hits
  • Select GETDATE()

    February 2026
    M T W T F S S
     1
    2345678
    9101112131415
    16171819202122
    232425262728  

Posts Tagged ‘Hekaton Series’

A-Z of In-Memory OLTP : Checkpoint – Part 1

Posted by blakhani on December 19, 2013


In today’s advance world, RAM is still volatile. Once you pull the power plug out, all the content of RAM is flushed. Since we are talking about in-memory tables, what would happen to data in tables? If we have defined a table as durable (SCHEMA_AND_DATA) in SQL Server, durability has to be maintained. During recovery of the database (also known as crash recovery), all the content should come back. To achieve this, SQL Server does logging into transaction log and writes checkpoint for in-memory tables.

If you are a SQL Server DBA and worked with earlier versions of SQL, checkpoint is definitely known to you. You can read more about earlier version of checkpoint in books online. In short, checkpoint is a process which writes dirty pages from memory to data file. This is done to reduce the recovery time of the database during crash recovery. Checkpoint can be done by system thread based on recovery interval or triggered on demand when system is low on memory, or other operations such as log backup etc.

“Similar” concept of checkpoint exists for In-Memory tables as well. I quoted similar because mechanism is different than the known checkpoint process for disk-based tables. To maintain durability of data for in-memory tables, SQL Server does logging of changes in transaction log (which is also different than disk based tables) and writes information during checkpoint. In this blog, we would try to understand the various things which happens during checkpoint. We should remember that transaction logging is sufficient to recover the data but if there is no checkpoint then we need to read complete transaction log during crash recovery, which would be inefficient. So, periodically checkpoint is fired and data is dumped into checkpoint files. Now, during recovery, we recover from checkpoint and replay only that portion of transaction log which is after checkpoint.

Checkpoint files are created into filegroup MEMORY_OPTIMIZED_DATA which is container for these files. During checkpoint, we try to use log buffer in memory to write information into checkpoint files. There are chances that log buffer is not having sufficient log blocks and then we would end-up in reading transaction log file. SQL Server uses FILESTREAM as underlying storage mechanism for checkpoint files. The checkpoint information is written into the disk by checkpoint streams, which comes in two flavors:

  • DATA streams:
    • These file are approximately 128 MB in size.
    • They contain only inserted rows of the table in the given timestamp range.
  • DELTA streams:
    • These are paired (1:1) with DATA files.
    • Size of these file is not constant.
    • Store the deleted rows with IDs.

Note that both files are “append only” files which means the IO would always be sequential. As soon as table is created, DATA files are pre-allocated with 128 MB size. DATA and DELTA files form a pair for a timestamp range. Once current DATA file becomes full, SQL Server would switch to new DATA file.

Enough of theory? Let’s see a checkpoint in action.

For demo purpose, I am creating table in the database which is having wide row. Here is the complete script.

-- Create database having container C:\IMO_Database\SQLSeverHelp_IMO_dir
CREATE DATABASE SQLSeverHelp_IMO 
    ON PRIMARY (
    NAME = [SQLSeverHelp_IMO_data]
    ,FILENAME = 'C:\IMO_Database\SQLSeverHelp_IMO.mdf'
    )
    
    ,FILEGROUP [SQLSeverHelp_IMO_FG] CONTAINS MEMORY_OPTIMIZED_DATA ( 
    NAME = [SQLSeverHelp_IMO_dir]
    ,FILENAME = 'C:\IMO_Database\SQLSeverHelp_IMO_dir'
    ) 
    
    LOG ON (
    NAME = [SQLSeverHelp_IMO_log]
    ,Filename = 'C:\IMO_Database\SQLSeverHelp_IMO_log.ldf'
    ) 
GO


-- Create In-Memory table
Use SQLSeverHelp_IMO
GO
CREATE TABLE MyFirstMemporyOptimizedTable
(
iID INT NOT NULL PRIMARY KEY NONCLUSTERED HASH WITH (BUCKET_COUNT = 100000),
vFName CHAR(4000) NOT NULL,
vLName CHAR(4000) NOT NULL
) WITH (MEMORY_OPTIMIZED = ON, DURABILITY = SCHEMA_AND_DATA)
GO

As soon as table is created, we would see DATA and DELTA file in the container. We can use DMV sys.dm_db_xtp_checkpoint_files to see the information. Let’s first run a very basic query to understand the files.

SELECT file_id, 
       pair_file_id, 
       file_type_desc, 
       is_active 
FROM   sys.dm_db_xtp_checkpoint_files 
ORDER  BY is_active DESC;   


Here is the output with some highlights. I have put the same color for the matching file_id with pair_file_id column for clarity.

image

As we can see in output, DATA and DELTA files are having pair. I have highlighted only two pairs but if you look carefully, all files are paired. Note that the number of files created is a function of number of CPU cores on the system. My machine has 8 logical CPU so I am seeing 9 pairs. Is_Active column represents whether the files is currently in use or not. Another way to find out paired files is to use column called internal_storage_slot. Only those files which are having not null slot would be used by checkpoint.

SELECT internal_storage_slot,
       file_id, 
       pair_file_id,    
       file_type_desc
FROM   sys.dm_db_xtp_checkpoint_files 
WHERE  internal_storage_slot is NOT NULL

Here is the output. Two files having same slot form a pair of DATA-DELTA (slot 3 in below screenshot).

image

Here is how the physical files on operating system look like:

image

Now, you may ask – how would I associate the file in the OS with the file_id and pair_file_Id column in sys.dm_db_xtp_checkpoint_files? Let’s use other columns of DMV to explore that information.

image

I have tried to make the picture self-explanatory. Highlight with the same color are the matching texts.

Now, lets try and check what happens when we insert some rows in the table. As we discussed earlier, DATA file would contain the rows which are inserted and DELTA file would have entries of deleted rows. I have used below script to load ~10K rows into the table.

DECLARE @counter INT 
SET @counter = 0 
WHILE @counter <= 10000 
  BEGIN 
      INSERT INTO myfirstmemporyoptimizedtable 
      VALUES      (@counter, 
                   'SQLServer-Help.com', 
                   'Balmukund Lakhani'), 
                  (@counter + 1, 
                   'ExtremeExperts.com', 
                   'Vinod Kumar M'), 
                  (@counter + 2, 
                   'SQLAuthority.com', 
                   'Pinal Dave') 

      SET @counter = @counter + 3 
  END

Now, Let’s go ahead and query the DMV again to see if we have something interesting! But Wait! We don’t know if checkpoint has automatically fired or not. So before running the query, I fired manual checkpoint via “CHECKPOINT” command in management studio.

SELECT internal_storage_slot,
       file_id, 
       pair_file_id,    
       file_type_desc,
       file_size_in_bytes / 1024.0 / 1024.0      [File Size in MB], 
       file_size_used_in_bytes / 1024.0 / 1024.0 [File Used in MB], 
       total_bytes / 1024.0 / 1024.0             [Total MB], 
       inserted_row_count 
 FROM   sys.dm_db_xtp_checkpoint_files 
 WHERE  total_bytes > 0        -- non zero size
 and       internal_storage_slot is not null 

As we can see that at this point only one DATA file is having non-zero size and number of rows shown are 10002, which were inserted earlier.

image

As we insert more and more rows, data would be accumulated in DATA file and once its full, next file would be opened used and current file becomes read-only. Please remember that 128 MB is NOT the limit of the checkpoint DATA file. A transaction can’t span across two DATA files, so a bigger transaction could cause a file to go beyond 128 MB size. For demo purposes, instead of 10K rows, I have inserted ~40K rows in one transaction.

image 

If you are wondering why we are not seeing any DELTA file in any of the query output then recall that DELTA file would contain the DELETEed rows identifier and so far I have been doing only INSERTs. To give you some time to grasp information in this blog, I would stop here and we would discuss other aspects of checkpoint in next blog for this A-Z series.

In case you have any question, post them in comment section and I would be happy to answer them.

  • Cheers,
  • Balmukund Lakhani
  • Twitter @blakhani
  • Author: SQL Server 2012 AlwaysOnPaperback, Kindle
  • Posted in Hekaton Series, In Memory OLTP, In-Memory OLTP, SQL Server 2014 | Tagged: , , , , , , , , | 11 Comments »

    A-Z of In-Memory OLTP : Native Compilation

    Posted by blakhani on December 17, 2013


    Imagine that you are participating in a 400 meters running competition and you are the only one to get discount of 300 meters and allowed to start 100 meters before the finish line. What would be the result? All participants have to run 400 meters and you would run only 100 meters. Of course, You would win!!! (terms and condition apply). In the same way, what would happen in SQL world, if we finish a significant amount of work i.e. compilation of stored procedure during creation phase. Yes, you are correct. The time spent in execution of the stored procedure would be less. In this post we would try to learn internals of native compilation.

    In earlier “T-SQL Constructs” post of this series, we have seen syntax of creation of natively compiled stored procedure. Native compilation of the stored procedure causes machine language code (i.e. DLL) to be generated and loaded in SQL Server Memory. Natively compiled stored procedures allows us to execute T-SQL in the fastest way, which includes accessing data in memory-optimized tables. In addition, disk-based tables are not allowed to be accessed at all inside natively compiled stored procedures. If we attempt to create a natively compiled procedure which accesses disk based table, we would get below error. In my test, the table name was DiskBasedTable.

    Msg 10775, Level 16, State 1, Procedure InsertName, Line 14
    Object ‘dbo.DiskBasedTable’ is not a memory optimized table and cannot be accessed from a natively compiled stored procedure.

    The advantages of natively complies stored procedure is that most of the work (permission check, object existence check, query plan generation) is done during compilation/creation of stored procedure. Due to this there are many limitations on the Transact-SQL that is allowed, the data types and collations that can be accessed and processed in natively compiled procedures. SQL Server Product Documentation team has done good amount of work in documenting them (refer Supported Data Types, Unsupported Transact-SQL Constructs)

    To get a list of natively complied stored procedures we can use catalog views as shown below. Highlighted below is the new column added to support in-memory OLTP.

    SELECT uses_native_compilation, 
           object_id, 
           Object_name(object_id) 
    FROM   sys.sql_modules 
    WHERE  uses_native_compilation = 1 
    go 
    
    SELECT uses_native_compilation, 
           object_id, 
           Object_name(object_id) 
    FROM   sys.all_sql_modules 
    WHERE  uses_native_compilation = 1 
    go
    

     

    Here is the output in SSMS

    image

    To convert a stored procedure to DLL, SQL Server engine uses C compiler. Does this mean we need to have C installed on the machine when we install in-memory OLTP? Well, we just need to complie the C code so we just need compiler related files. SQL Server product comes with compiler files. As soon as SQL Engine is installed, these files are installed under <SQL Server Installation Directory>\MSSQL\Binn\Xtp folder. Main compilation files are located under ..\VC\bin folder.

    image

    Sometimes, we might face stored procedure creation failure due to issues in compilation of the C code. To make our life easier, SQL Server generates intermediate files and they are useful for troubleshooting by members of product support team. Here is the text of .out file.

    Microsoft (R) C/C++ Optimizing Compiler Version 17.00.60605.1 for x64

    Copyright (C) Microsoft Corporation.  All rights reserved.

    xtp_p_8_581577110.c

    Microsoft (R) Incremental Linker Version 11.00.60605.1

    Copyright (C) Microsoft Corporation.  All rights reserved.

    /out:xtp_p_8_581577110.dll

    /ltcg

    /debug

    /dll

    /implib:xtp_p_8_581577110.lib

    "/LIBPATH:C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\Binn\Xtp\gen\lib"

    "/LIBPATH:C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\Binn\Xtp\VC\lib"

    /noentry

    /nodefaultlib

    /incremental:no

    /ltcg

    /wx

    /FUNCTIONPADMIN

    xtp_p_8_581577110.obj

    hkgenlib.lib

    hkruntime.lib

    hkengine.lib

    hkgenexp.exp

    hkcrt.lib

    hkk32.lib

    hkversion.obj

    Generating code

    Finished generating code

    If you are a C developer, it may be easy for you to understand the switches passed during calling of CL.exe. There is no real need for a DBA to know all these options. In case you are too excited, read here for the parameters.

    Before I conclude, I would like you to throw ideas about below error, while creation of natively compiled stored procedure.

    image

    Here is the text of the message:

    Msg 41312, Level 16, State 4, Procedure InsertName1, Line 2

    Unable to call into the C compiler. GetLastError = 2.

    Of course, I broke something and above is the error I am getting. Can you guess? Go ahead and comment on the post.

    Stay Tuned for next part of the series.

    Cheers,

    Balmukund Lakhani

    Twitter @blakhani

    Author: SQL Server 2012 AlwaysOnPaperback, Kindle

    Posted in A - Z Series, Hekaton Series, In Memory OLTP, In-Memory OLTP | Tagged: , , , , , , | 1 Comment »

    A-Z of In-Memory OLTP : Behind the scenes

    Posted by blakhani on December 12, 2013


    If you have a kid in your life, you probably get inundated every day with questions starting with word “why” and “what”. Why do kids ask why? One of the answers is, that children are naturally curious about the world around them. After all, there’s much to learn, and much to know. We all have a kid inside us who is very curious, that’s why I thought of writing this blog post.

    In A-Z Series, we have discussed about T-SQL constructs and SSMS enhancements to create In-Memory objects. In this part, we would discuss “behind the scene” of those commands.

    CREATE DATABASE

    Once database is created and one (and only one) filegroup with CONTAINS MEMORY_OPTIMIZED_DATA clause, SQL Server would create a folder which is specified in filename parameter for that filegroup. In our sample database SQLSeverHelp_IMO we have added filename = “C:\IMO_Database\SQLSeverHelp_IMO_dir” which would create a folder behind the scene as shown below.

    image

    If we look inside the folders, the would be empty because there is no in-memory table created so far. We also have MDF and LDF file which are same as earlier version of SQL, nothing new there. We can use catalog view to get details about Memory optimized filegroup

    Use SQLSeverHelp_IMO
    GO
    Select * from sys.data_spaces
    Here is the query in SSMS and the output:
    image 

    CREATE TABLE

    Next logical step is to create a In-Memory table in the database. In our last post, we have created table called MyFirstMemporyOptimizedTable. As soon as table is created, SQL Server is going to create few files into the folder which were created during previous step of database creation.

    image

    Above files are created as soon as I created one table. Don’t worry by seeing so many files as we would discuss about these file later part of the series. All you need to remember that per file is 131072 KB = 128 MB by default. There are files having zero KB size as we have not inserted/updated/deleted any data in the table. In contrast to disk-based tables having 8K size pages in buffer pool, the In-memory tables don’t have pages in buffer pool. Think of this as rows in the memory linked to each other because we have index on table. In-memory data is not stored on data files at all. Instead, its stored as blob data using filestream files, which are shown in picture above. At this point just remember that they are called CheckPoint files which combination is DATA files and DELTA files. We would go deeper into those files once we go into blog about checkpoint for in-memory tables.

    Another thing which has happened behind the scene is to generate the DLL for the table definition and load into SQL Server Memory. Why? Well, In-Memory engine doesn’t have any knowledge about format of data record. It doesn’t know how to access the data which is part of in-memory table. Whenever we create table, a C file is generated which would have all callback functions used by In-Memory Engine. The C file, it’s compiled by C complier and DLL is generated. If you are a developer in C/C++, you can open the file and check the content to get a feeling.

    Here is the query

    use SQLSeverHelp_IMO
    go
    SELECT name, 
           description 
    FROM   sys.dm_os_loaded_modules 
    WHERE  description = 'XTP Native DLL' 
           AND name LIKE '%xtp_t_' + Cast(Db_id() AS VARCHAR(10)) + '_' 
    + Cast(Object_id('dbo.MyFirstMemporyOptimizedTable') AS VARCHAR(10)) + '.dll'
    Here is the query in SSMS and the output:

    image

    Let’s look at windows explorer and see what we have in that folder. If we look at xtp folder, we would see numbered folders. These are databases IDs which have in-memory objects. Default directory of XTP folder is DATA directory (C:\Program Files\Microsoft SQL Server\MSSQL12.MSSQLSERVER\MSSQL\DATA\). Do you remember what XTP stands for? Go back and read first post.

    image

    For database SQLSeverHelp_IMO the database_id is 8 (you may have different ID) so let’s go inside the folder 8 and check what we have got there.

    image

    If you go back and look at the query, which we executed earlier, its easy to understand that DLL (and other files) have name as xtp_t_<DB_ID>_<Object_ID> where t stands for table and rest is self explanatory. Each in-memory table will have one corresponding DLL generated which would be loaded in the memory at all times.The end goal of converting table definition to machine level instruction (using DLL) is to avoid compilation during execution phase. There is no need for a DBA to worry about backup of those files. They would be re-generated as soon as database is opened and recovered. Once SQL Server restarts, it performs recovery of database and table would be loaded into memory again.

    CREATE PROCEDURE

    Before moving any forward, remember that here we are talking about procedure which are natively compiled. In earlier post, we created stored procedure [InsertName]. During creation time of stored procedure, compiler will convert interpreted T-SQL, query plans and expressions into native code.

    Here is the query

    use SQLSeverHelp_IMO
    go
    SELECT name, 
           description 
    FROM   sys.dm_os_loaded_modules 
    WHERE  name LIKE '%xtp_p_' + Cast(Db_id() AS VARCHAR(10)) + '_'        
           + Cast(Object_id('dbo.InsertName') AS VARCHAR(10)) + '.dll' 
    Here is the query in SSMS and the output:

    image

    Now, lets open the same XTP folder and look at content.

    image

    As we can see above, now we have new files having “p” in it and they are for stored procedure. The naming standard of those files is is xtp_p_<DB_ID>_<Object_ID>. Native Compilation of stored procedure takes an abstract tree representation of a stored procedure including queries, table and index metadata, and compiles them into native code designed to execute against tables and indexes managed by In-memory engine.

    What are the other files (.c, .mat, .obj, .pdb) ? Well, they are intermediate files created by complier. They are used for troubleshooting compilation issues. Here is the quick summary table

     

    File Extension

    Usage

    .c

    C source file generated by In-Memory engine

    .dll

    Natively compiled DLL to be loaded into SQL Server process

    .mat.xml

    MAT export file

    .obj

    Object file generated by C compiler

    .out

    Compiler output file

    .pdb

    Symbol file for the dll. Used for debugging code issues.

     

    If you are C++ developer, you can understand those files easily. Since they are not cause of worry for DBAs and Developers, I would not go deeper into explanation.

    With this, I would conclude this blog post and hopefully this has given you some insights about inner working of In-Memory object.

    Stay tuned for more..

    Cheers,

    Balmukund Lakhani

    Twitter @blakhani

    Author: SQL Server 2012 AlwaysOnPaperback, Kindle

    Posted in A - Z Series, Hekaton Series, In Memory OLTP, In-Memory OLTP, Internals, SQL Server 2014, SSMS | Tagged: , , , , , , | 7 Comments »