/**************************************************************************** ** (c) Copyright IBM Corp. 2007 All rights reserved. ** ** The following sample of source code ("Sample") is owned by International ** Business Machines Corporation or one of its subsidiaries ("IBM") and is ** copyrighted and licensed, not sold. You may use, copy, modify, and ** distribute the Sample in any form without payment to IBM, for the purpose of ** assisting you in the development of your applications. ** ** The Sample code is provided to you on an "AS IS" basis, without warranty of ** any kind. IBM HEREBY EXPRESSLY DISCLAIMS ALL WARRANTIES, EITHER EXPRESS OR ** IMPLIED, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF ** MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. Some jurisdictions do ** not allow for the exclusion or limitation of implied warranties, so the above ** limitations or exclusions may not apply to you. IBM shall not be liable for ** any damages you suffer as a result of using, copying, modifying or ** distributing the Sample, even if IBM has been advised of the possibility of ** such damages. ***************************************************************************** ** ** SOURCE FILE NAME: tbonlineinx.sqc ** ** SAMPLE: How to create and reorg indexes on a table ** ** SQL STATEMENTS USED: ** INCLUDE ** CREATE BUFFERPOOL ** CREATE INDEX ** CREATE TABLE ** CREATE TABLESPACE ** DROP BUFFERPOOL ** DROP INDEX ** DROP TABLE ** DROP TABLESPACE ** ** DB2 APIs USED: ** db2Reorg -- Reorganize a Table or Index ** ** SQL STRUCTURES USED: ** sqlca ** ** ***************************************************************************** ** ** For more information on the sample programs, see the README file. ** ** For information on developing embedded SQL applications see the Developing Embedded SQL Applications book. ** ** For information on using SQL statements, see the SQL Reference. ** ** For the latest information on programming, building, and running DB2 ** applications, visit the DB2 Information Center: ** http://publib.boulder.ibm.com/infocenter/db2luw/v9r7/index.jsp ****************************************************************************/ #include <stdio.h> #include <stdlib.h> #include <string.h> #include <sqlenv.h> #include <sqlutil.h> #include <db2ApiDf.h> #include "utilemb.h" EXEC SQL INCLUDE SQLCA; EXEC SQL BEGIN DECLARE SECTION; short len; char stmt[200]; char dbAlias[15]; char user[129]; char pswd[15]; char tableName[129]; char schemaName[129]; EXEC SQL END DECLARE SECTION; int CreateIndex(void); int ReorgIndex(void); int DropIndex(void); int SchemaNameGet(void); int CreateLargeIndex(void); int main(int argc, char *argv[]) { int rc = 0; char dbAlias[SQL_ALIAS_SZ + 1]; char user[USERID_SZ + 1]; char pswd[PSWD_SZ + 1]; /* check the command line arguments */ rc = CmdLineArgsCheck1(argc, argv, dbAlias, user, pswd); if (rc != 0) { return rc; } printf("\nTHIS SAMPLE SHOWS HOW TO CREATE AND REORG ONLINE INDEXES\n"); printf("ON TABLES.\n"); /* connect to database */ rc = DbConn(dbAlias, user, pswd); if (rc != 0) { return rc; } /* create online index on a table */ rc = CreateIndex(); if (rc != 0) { return rc; } /* Creating index key on large size coloumns */ rc = CreateLargeIndex(); if (rc != 0) { return rc; } /* reorg online index on a table */ rc = ReorgIndex(); if (rc != 0) { return rc; } /* disconnect from database */ rc = DbDisconn(dbAlias); if (rc != 0) { return rc; } return 0; } /* main */ /* How to create an index on a table with different levels of access to the table like read-write, read-only, no access */ int CreateIndex(void) { int rc = 0; printf("\n-----------------------------------------------------------"); printf("\nUSE THE SQL STATEMENT\n"); printf(" CREATE INDEX\n"); printf("TO CREATE AN INDEX\n"); /* create an online index with read-write access to the table */ printf("\nTo create an index on a table allowing read-write access\n"); printf("to the table, use the following SQL command:\n\n"); printf(" CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)\n"); strcpy(stmt, "CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)"); EXEC SQL EXECUTE IMMEDIATE :stmt; EMB_SQL_CHECK("Index -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); rc = DropIndex(); if (rc != 0) { return rc; } /* Create an index on a table while allowing only read access to it */ printf("\nTo create an index on a table allowing only read access\n"); printf("to the table, use the following two SQL commands:\n\n"); printf(" LOCK TABLE EMPLOYEE IN SHARE MODE\n"); printf(" CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)\n"); strcpy(stmt, "LOCK TABLE EMPLOYEE IN SHARE MODE"); EXEC SQL EXECUTE IMMEDIATE :stmt; EMB_SQL_CHECK("Lock -- Table"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); strcpy(stmt, "CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)"); EXEC SQL EXECUTE IMMEDIATE :stmt; EMB_SQL_CHECK("Index -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); rc = DropIndex(); if (rc != 0) { return rc; } /* create an online index allowing no access to the table */ printf("\nTo create an index on a table allowing no access to the \n"); printf("table (only uncommitted readers allowed), use the \n"); printf("following two SQL statements:\n\n"); printf(" LOCK TABLE EMPLOYEE IN EXCLUSIVE MODE\n"); printf(" CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)\n"); strcpy(stmt, "LOCK TABLE EMPLOYEE IN EXCLUSIVE MODE"); EXEC SQL EXECUTE IMMEDIATE :stmt; EMB_SQL_CHECK("Lock -- Table"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); strcpy(stmt, "CREATE INDEX INDEX1 ON EMPLOYEE (LASTNAME ASC)"); EXEC SQL EXECUTE IMMEDIATE :stmt; EMB_SQL_CHECK("Index -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); return rc; } /* CreateIndex */ /* To create large indexes with index key part extending upto 8192 bytes */ int CreateLargeIndex(void) { int rc = 0; printf("\n-----------------------------------------------------------"); printf("\nTo create large indexes with index key part extending \n"); printf("upto 8192 bytes:"); printf("\n\nUSE THE SQL STATEMENTS:"); printf("\n CREATE BUFFERPOOL"); printf("\n COMMIT"); printf("\nTO CREATE A BUFFER POOL"); printf("\n\n CREATE BUFFERPOOL bupl32k SIZE 300 PAGESIZE 32K"); printf("\n COMMIT"); /* Create bufferpool with 32K pagesize */ EXEC SQL CREATE BUFFERPOOL bupl32k SIZE 300 PAGESIZE 32K; EMB_SQL_CHECK("Bufferpool -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENTS:"); printf("\n CREATE TABLESPACE"); printf("\n COMMIT"); printf("\nTO CREATE TABLESPACE"); printf("\n\nTo create tablespace using above created bufferpool"); printf("\nuse following SQL statement"); printf("\n\n CREATE TABLESPACE tbsp32k"); printf("\n PAGESIZE 32k"); printf("\n MANAGED BY DATABASE"); printf("\n USING (FILE 'tbsp32k' 300)"); printf("\n BUFFERPOOL bupl32k"); printf("\n COMMIT"); /* Create tablespace using above created bufferpool */ EXEC SQL CREATE TABLESPACE tbsp32k PAGESIZE 32k MANAGED BY DATABASE USING (FILE 'tbsp32k' 300) BUFFERPOOL bupl32k; EMB_SQL_CHECK("Tablespace -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENTS:"); printf("\n CREATE TABLE"); printf("\n COMMIT"); printf("\nTO CREATE TABLE"); printf("\n\n CREATE TABLE inventory_ident (dept INTEGER,"); printf("\n serial_numbers VARCHAR(8190) NOT NULL)"); printf("\n IN tbsp32k"); printf("\n COMMIT"); /* Create table */ EXEC SQL CREATE TABLE inventory_ident (dept INTEGER, serial_numbers VARCHAR(8190) NOT NULL) IN tbsp32k; EMB_SQL_CHECK("Table -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENTS:"); printf("\n CREATE SYSTEM TEMPORARY TABLESPACE"); printf("\n COMMIT"); printf("\nTO CREATE TEMPORARY TABLESPACE"); printf("\n\nTo create a system temporary tablespace that can be used"); printf("\nin case the sort heap overflows, use the following "); printf("\nSQL statement:"); printf("\n\n CREATE SYSTEM TEMPORARY TABLESPACE tmptbsp32k"); printf("\n PAGESIZE 32K"); printf("\n MANAGED BY SYSTEM"); printf("\n USING ('tmp_tbsp_32k')"); printf("\n EXTENTSIZE 2"); printf("\n BUFFERPOOL bupl32k"); printf("\n COMMIT"); /* Create a system temporary table space with 32K pages. */ /* When the INDEXSORT database configuration parameter is set to Yes */ /* (which is the default), then that data is sorted before it is passed */ /* to index manager. If sort heap is big enough for the amount of data */ /* being sorted, the sort will occur entirely in memory. However, just */ /* in case we need to spill to disk, DB2 will ensure that there is a */ /* system temporary tablespace with a large enough page size to spill to.*/ EXEC SQL CREATE SYSTEM TEMPORARY TABLESPACE tmptbsp32k PAGESIZE 32K MANAGED BY SYSTEM USING ('tmp_tbsp_32k') EXTENTSIZE 2 BUFFERPOOL bupl32k; EMB_SQL_CHECK("Temporary Tablespace -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nThere is an upper bound on index key length based on "); printf("the page size."); printf("\nThe maximum length of the index key part can be:"); printf("\n 1024 bytes for 1K page size"); printf("\n 2048 bytes for 8K page size"); printf("\n 4096 bytes for 16K page size"); printf("\n 8192 bytes for 32K page size"); printf("\n\nUSE THE SQL STATEMENTS:"); printf("\n CREATE INDEX"); printf("\n COMMIT"); printf("\nTO CREATE AN INDEX"); printf("\n\nTo create an index on the 'serial_numbers column' of"); printf("\n 'inventory_ident' table, use the following SQL command: "); printf("\n\n CREATE INDEX inventory_serial_number_index_ident"); printf("\n ON inventory_ident (serial_numbers)"); printf("\n COMMIT"); /* Create an index on the serial_numbers column */ /* The upper bound for an index key length is variable based on */ /* page size. The maximum length of an index key part can be: */ /* 1024 bytes for 1K page size, */ /* 2048 bytes for 8K page size, */ /* 4096 bytes for 16K page size, */ /* 8192 bytes for 32K page size, */ /* and, the index name can be upto 128 chars */ EXEC SQL CREATE INDEX inventory_serial_number_index_ident ON inventory_ident (serial_numbers); EMB_SQL_CHECK("Index -- Create"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENT"); printf("\n DROP"); printf("\nTO DROP THE INDEX"); printf("\n\n Execute the statement"); printf("\n DROP INDEX inventory_serial_number_index_ident"); EXEC SQL DROP INDEX inventory_serial_number_index_ident; EMB_SQL_CHECK("Index -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENT"); printf("\n DROP"); printf("\nTO DROP THE TABLE"); printf("\n\n Execute the statement"); printf("\n DROP TABLE inventory_ident"); EXEC SQL DROP TABLE inventory_ident; EMB_SQL_CHECK("Table -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENT"); printf("\n DROP"); printf("\nTO DROP THE TABLESPACE"); printf("\n\n Execute the statement"); printf("\n DROP TABLESPACE tmptbsp32k"); EXEC SQL DROP TABLESPACE tmptbsp32k; EMB_SQL_CHECK("Tablespace -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENT"); printf("\n DROP"); printf("\nTO DROP THE TABLESPACE"); printf("\n\n Execute the statement"); printf("\n DROP TABLESPACE tbsp32k"); EXEC SQL DROP TABLESPACE tbsp32k; EMB_SQL_CHECK("Tablespace -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n\nUSE THE SQL STATEMENT"); printf("\n DROP"); printf("\nTO DROP THE BUFFERPOOL"); printf("\n\n Execute the statement"); printf("\n DROP BUFFERPOOL bupl32k\n"); EXEC SQL DROP BUFFERPOOL bupl32k; EMB_SQL_CHECK("Bufferpool -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); return rc; } /* CreateLargeIndex */ /* How to reorg an index on a table with different levels of access to the table like read-write, read-only, no access */ int ReorgIndex(void) { int rc = 0; struct sqlca sqlca; char fullTableName[258]; db2ReorgStruct paramStruct; db2Uint32 versionNumber = db2Version970; printf("\n-----------------------------------------------------------"); printf("\nUSE THE DB2 APIs:\n"); printf(" db2Reorg -- Reorganize a Table or Index\n"); printf("TO REORGANIZE A TABLE OR INDEX.\n"); /* get fully qualified name of the table */ strcpy(tableName, "EMPLOYEE"); rc = SchemaNameGet(); if (rc != 0) { return rc; } strcpy(fullTableName, schemaName); strcat(fullTableName, "."); strcat(fullTableName, tableName); printf(" Reorganize all indexes defined on table : %s\n", fullTableName); /* setup parameters */ memset(¶mStruct, '\0', sizeof(paramStruct)); paramStruct.reorgObject.tableStruct.pTableName = fullTableName; paramStruct.reorgObject.tableStruct.pOrderByIndex = NULL; paramStruct.reorgObject.tableStruct.pSysTempSpace = NULL; paramStruct.reorgType = DB2REORG_OBJ_INDEXESALL; paramStruct.nodeListFlag = DB2_ALL_NODES; paramStruct.numNodes = 0; paramStruct.pNodeList = NULL; printf(" \nReorganize the indexes on a table allowing read-write\n"); printf(" access to the table (set reorgFlags to DB2REORG_ALLOW_WRITE)\n"); paramStruct.reorgFlags = DB2REORG_ALLOW_WRITE; /* reorganize index */ rc = db2Reorg(versionNumber, ¶mStruct, &sqlca); DB2_API_CHECK("index -- reorganize"); printf(" \nReorganize the indexes on a table allowing read-only\n"); printf(" access to the table (set reorgFlags to DB2REORG_ALLOW_READ)\n"); paramStruct.reorgFlags = DB2REORG_ALLOW_READ; /* reorganize index */ rc = db2Reorg(versionNumber, ¶mStruct, &sqlca); DB2_API_CHECK("index -- reorganize"); printf(" \nReorganize the indexes on a table allowing no access\n"); printf(" to the table (set reorgFlags to DB2REORG_ALLOW_NONE)\n"); paramStruct.reorgFlags = DB2REORG_ALLOW_NONE; /* reorganize index */ rc = db2Reorg(versionNumber, ¶mStruct, &sqlca); DB2_API_CHECK("index -- reorganize"); rc = DropIndex(); if (rc != 0) { return rc; } return rc; } /* ReorgIndex */ /* How to drop the index on a table */ int DropIndex(void) { int rc = 0; printf("\nUSE THE SQL STATEMENT\n"); printf(" DROP\n"); printf("TO DROP AN INDEX:\n"); /* drop the indexes */ printf("\n Execute the statement\n"); printf(" DROP INDEX INDEX1\n"); EXEC SQL DROP INDEX INDEX1; EMB_SQL_CHECK("Index -- Drop"); EXEC SQL COMMIT; EMB_SQL_CHECK("Transaction -- Commit"); printf("\n-----------------------------------------------------------"); return rc; } /* DropIndex */ int SchemaNameGet(void) { struct sqlca sqlca; /* get table schema name */ EXEC SQL SELECT tabschema INTO :schemaName FROM syscat.tables WHERE tabname = :tableName; EMB_SQL_CHECK("table schema name -- get"); /* get rid of spaces from the end of schemaName */ strtok(schemaName, " "); return 0; } /* SchemaNameGet */