HOWTO: Use GUID Fields in Access from Visual C++ID: Q170117
|
Microsoft Access 95 introduced a new GUID (Globally Unique Identifier) data type used for database replication. You can use GUID fields (called Replication ID fields in Access) to store any GUID number in a compact 16-byte binary format that can be indexed and used as a primary key for a table. This article explains how to create and use Microsoft Access GUID data type fields with Visual C++ MFC database classes.
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
db.Execute(_T("CREATE TABLE MyGUIDTable (MyGUIDField GUID)"));
The DDL method above will also work using the CDatabase::ExecuteSQL method
against the Microsoft Access Open Database Connectivity (ODBC) driver.
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
// Create new tabledef and create GUID field.
CDaoTableDef td(&;db);
td.Create(_T("MyGUIDTable"));
td.CreateField("MyGuidField", dbGUID, 16); // Note: field size is 16.
// Append table to tabledefs collection to create physical table.
td.Append();
{11223344-1122-1122-1122-AABBCCDDEEFF}
Microsoft Access requires a similar textual format when using GUIDs in SQL
statements:
{guid {11223344-1122-1122-1122-AABBCCDDEEFF}}
The following code will insert a GUID field into the MyGUIDTable table:
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
db.Execute(_T("INSERT INTO MyGUIDTable (MyGuidField) VALUES
({guid {11223344-1122-1122-1122-AABBCCDDEEFF}})"));
You can also use a GUID in the SET portion of an UPDATE SQL statement:
SET MyGuidField = {guid {11223344-1122-1122-1122-AABBCCDDEEFF}}
NOTE: You do not need quotes around the GUID field.
The following example demonstrates how to use literal GUIDs with the Microsoft Access ODBC driver:Syntax error (missing operator) in query expression 'guid 11223344-1122-1122-1122-AABBCCDDEEFF}'. State:37000,Native:-3100,Origin:[Microsoft][ODBC Microsoft Access 97 Driver]
CString strSQL, strDescription;
CDatabase db;
// Open Microsoft Access database using ODBC.
db.OpenEx( "DSN=NW97;", CDatabase::noOdbcDialog );
// Drop and re-create the test table.
try
{
strSQL = "DROP TABLE Literal";
db.ExecuteSQL( strSQL );
}
catch(CDBException *e)
{
e->Delete(); // Ignore errors.
};
strSQL = "CREATE TABLE Literal (LinkID GUID, Description TEXT)";
db.ExecuteSQL( strSQL );
// Turn off driver scanning for escape clauses to give the raw
// SQL to Access.
::SQLSetConnectOption( db.m_hdbc, SQL_NOSCAN, SQL_NOSCAN_ON );
// Run INSERT SQL statements to add two records.
strSQL = "INSERT INTO Literal (LinkID, Description) VALUES "
"({guid {11223344-1122-1122-1122-AABBCCDDEEFF}}, 'Guid 1')";
db.ExecuteSQL( strSQL );
strSQL = "INSERT INTO Literal (LinkID, Description) VALUES "
"({guid {11223344-1122-1122-1122-FFFFFFFFFFFF}}, 'Guid 2')";
db.ExecuteSQL( strSQL );
// Turn the driver scanning for escape clauses back on.
::SQLSetConnectOption( db.m_hdbc, SQL_NOSCAN, SQL_NOSCAN_OFF );
// Now use a literal GUID in a WHERE clause of a select
// statement to find the record.
CRecordset rs( &db );
// Turn off scanning for recordset.
::SQLSetStmtOption( rs.m_hstmt, SQL_NOSCAN, SQL_NOSCAN_ON );
// Open recordset using a literal GUID in a WHERE clause.
strSQL = "SELECT * FROM Literal WHERE LinkID = "
"{guid {11223344-1122-1122-1122-FFFFFFFFFFFF}}";
rs.Open( CRecordset::forwardOnly, strSQL, CRecordset::readOnly );
// Confirm that you found the correct record.
rs.GetFieldValue( "Description", strDescription );
AfxMessageBox( "Found " + strDescription );
// Open database and recordset objects.
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
CDaoRecordset rs(&db);
rs.Open(dbOpenTable,_T("MyGUIDTable"));
// Create VT_BSTRT variant for GUID.
COleVariant varGUIDValue(_T("{guid {11223344-1122-1122-1122-
AABBCCDDEEFF}}"), VT_BSTRT);
// Add a record using CDaoRecordset method.
rs.AddNew();
rs.SetFieldValue(_T("MyGUIDField"),varGUIDValue);
rs.Update();
The same process applies to updating GUID fields, except that you would use
the Edit rather than the AddNew method.
You can use the Seek method with GUIDs:GUID not allowed in Find method criteria expression
// Open database.
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
// Create a table called MySeekTable with a GUID primary key field named
// ID and a field named Found.
db.Execute(_T("create table MySeekTable (ID guid constraint PKEY primary
key, Found text)"));
// Insert a few records using an insert into statement.
db.Execute(_T("insert into MySeekTable (ID, Found) values ({guid
{11111111-aabb-aabb-aabb-aabbccddeeff}},'Guid1')"));
db.Execute(_T("insert into MySeekTable (ID, Found) values ({guid
{22222222-aabb-aabb-aabb-aabbccddeeff}},'Guid2')"));
db.Execute(_T("insert into MySeekTable (ID, Found) values ({guid
{33333333-aabb-aabb-aabb-aabbccddeeff}},'Guid3')"));
// Open table-type recordset (must use table-type for Seek) and select
// index for seek.
CDaoRecordset rs(&db);
rs.Open(dbOpenTable,_T("MySeekTable"));
rs.SetCurrentIndex(_T("PKEY"));
// Construct the GUID you want to find and seek the GUID.
COleVariant varGUIDValue(_T("{guid {22222222-aabb-aabb-aabb-
aabbccddeeff}}"), VT_BSTRT);
if (rs.Seek(_T("="),&varGUIDValue)) {
// GUID found. Retrieve and display value.
CString strResult = V_BSTRT(&rs.GetFieldValue(_T("Found")));
AfxMessageBox("Seek of guid found '" + strResult + "'");
} else {
// GUID not found.
AfxMessageBox("Seek of guid failed.");
}
{guid {11223344-1122-1122-1122-AABBCCDDEEFF}}
// Open database and create tabeldef.
CDaoDatabase db;
db.Open(_T("c:\\db1.mdb"));
CDaoTableDef td(&db);
td.Create(_T("MyGUIDTable"));
// Create and fill out a CDaoFieldInfo structure.
CDaoFieldInfo fi;
fi.m_strName = _T("ID");
fi.m_nType = dbGUID;
fi.m_lSize = 16;
fi.m_nOrdinalPosition = 0;
fi.m_bAllowZeroLength = FALSE;
fi.m_bRequired = FALSE;
fi.m_lAttributes = dbSystemField;
fi.m_strValidationRule = _T("");
fi.m_strValidationText = _T("");
fi.m_strDefaultValue = _T("GenGUID()"); // This generates the GUID.
// Create field using CDaoFieldInfo constructor and append table.
td.CreateField(fi);
td.Append();
Microsoft Jet Database Engine Programmer's Guide, p. 246
Additional query words: kbvc400 kbvc410 kbvc420 kbvc500 kbvc600
Keywords : kbDAO kbDatabase kbMFC kbODBC kbVC
Version : 4.0 4.0a 4.1 4.2 4.2b 5.0 6.0
Platform : WINDOWS winnt
Issue type : kbhowto
Last Reviewed: July 22, 1999