Home > Articles > Data > DB2

This chapter is from the book

2.7 Case Study: DB2 with DPF Environment

Now that you are familiar with DPF, let's review some of the concepts discussed using a simple case study.

Your company is expanding, and it recently acquired two other firms. Since the amount of data will be increased by approximately threefold, you are wondering if your current single-partition DB2 database server will be able to handle the load, or if DB2 with DPF will be required. You are not too familiar with DB2 with DPF, so you decide to play around with it using your test machines: two SMP machines running Linux with four processors each. The previous DBA, who has left the company, had installed DB2 UDB ESE with DPF on these machines. Fortunately, he left a diagram with his design, shown in Figure 2.16.

02fig15.jpg

Figure 2.16 DB2 UDB ESE with DPF design

Figure 2.16 is a combined physical and logical design. When you validate the correctness of the diagram with your system, you note that database mydb1 has been dropped, so you decide to rebuild this database as practice. The instance db2inst1 is still there, as are other databases. These are the steps you follow.

  1. Open two telnet sessions, one for each server. From one of the sessions you issue the commands db2stop followed by db2start , as shown in Figure 2.17.

    The first thing you note is that there is no need to issue these two commands on each partition; issuing them on any partition once will affect all partitions. You also can tell that there are four partitions, since you received a message from each of them.

  2. Review the db2nodes.cfg file to understand the configuration of your partitions (see Figure 2.18). Using operating system commands, you determine that the home directory for instance db2inst1 is /home/db2inst1. The db2nodes.cfg file is stored in the directory /home/db2inst1/sqllib.

    Figure 2.18 shows there are four partitions, two per server. The server host names are aries and saturn.

  3. Create the database mydb1. Since you want partition 0 to be your catalog partition, you must issue the CREATE DATABASE command from partition 0. You issue the statement db2 "values (current dbpartitionnum)" to determine which partition is currently active and find out that partition 3 is the active partition (see Figure 2.19).

    Example 2.17. Running the db2stop and db2start commands

    
                [db2inst1@aries db2inst1]$ db2stop
    
                05-18-2004 23:44:42     3  0   SQL1064N  DB2STOP processing was successful.
    
                05-18-2004 23:44:43     1  0   SQL1064N  DB2STOP processing was successful.
    
                05-18-2004 23:44:44     2  0   SQL1064N  DB2STOP processing was successful.
    
                05-18-2004 23:44:44     0  0   SQL1064N  DB2STOP processing was successful.
    
                SQL1064N  DB2STOP processing was successful.
    
    
                [db2inst1@aries db2inst1]$ db2start
    
                05-18-2004 23:44:51     1  0   SQL1063N  DB2START processing was successful.
    
                05-18-2004 23:44:51     0  0   SQL1063N  DB2START processing was successful.
    
                05-18-2004 23:44:52     3  0   SQL1063N  DB2START processing was successful.
    
                05-18-2004 23:44:53     2  0   SQL1063N  DB2START processing was successful.
    
                SQL1063N  DB2START processing was successful.
    
    
                [db2inst1@aries db2inst1]$
    
             

    Example 2.18. A sample db2nodes.cfg file

    
                [db2inst1@aries sqllib]$ pwd
    
                /home/db2inst1/sqllib
    
    
                [db2inst1@aries sqllib]$ more db2nodes.cfg
    
                0 aries.myacme.com 0
    
                1 aries.myacme.com 1
    
                2 saturn.myacme.com 0
    
                3 saturn.myacme.com 1
    
    
                [db2inst1@aries sqllib]$
    
             

    Example 2.19. Determining the active partition

    
                [db2inst1@saturn db2inst1]$ db2 "values (current dbpartitionnum)"
    
    
                1
    
                -----------
              
                3
    
     
                1 record(s) selected. 
    
             
  4. Next, you change the DB2NODE environment variable to zero (0) as follows (see Figure 2.20):

    
                DB2NODE=0
    
                export DB2NODE
    
                db2 terminate
    
             

    Example 2.20. Switching the active partition, then creating a database

    
                [db2inst1@saturn db2inst1]$ DB2NODE=0
    
                [db2inst1@saturn db2inst1]$ export DB2NODE
    
                [db2inst1@saturn db2inst1]$ db2 terminate
    
                DB20000I  The TERMINATE command completed successfully.
    
    
                [db2inst1@saturn db2inst1]$ db2 list applications
    
                SQL1611W  No data was returned by Database System Monitor. SQLSTATE=00000
    
    
                [db2inst1@saturn db2inst1]$ db2 create db mydb1 on /db2database
    
                DB20000I  The CREATE DATABASE command completed successfully.
    
    
                [db2inst1@saturn db2inst1]$ db2 connect to mydb1
    
       
                Database Connection Information
    
     
                Database server        = DB2/LINUX 8.1.2
     
                SQL authorization ID   = DB2INST1
     
                Local database alias   = MYDB1
    
    
                [db2inst1@saturn db2inst1]$ db2 "values (current dbpartitionnum)"
    
    
                1
    
                -----------
              
                0
    
    
                1 record(s) selected.
    
    
                db2inst1@saturn db2inst1]$
    
             

    In the CREATE DATABASE command you specify the path, /db2database in this example, which is an existing path that has been created locally on all servers so that the data is spread across them.

  5. To confirm that partition 0 is indeed the catalog partition, simply issue a list db directory command and look for the Catalog database partition number field under the entry for the mydb1 database. Alternatively, issue a list tablespaces command from each partition. The SYSCATSPACE table space will be listed only on the catalog partition.

  6. Create partition group pg23 on partitions 2 and 3. Figure 2.21 shows how to accomplish this and how to list your partition groups. Remember that this does not list IBMTEMPGROUP.

  7. Create and manage your buffer pools. Issue this statement to create buffer pool BP23 on partition group pg23:

    
                db2 "create bufferpool BP23 database partition group pg23 size 500"
    
             

    Example 2.21. Creating partition group pg23

    
                [db2inst1@saturn db2inst1]$ db2 "create database partition group pg23 on dbpartitionnum (2 to 3)"
    
                DB20000I  The SQL command completed successfully.
    
    
                [db2inst1@saturn db2inst1]$ db2 "list database partition groups"
    
    
                DATABASE PARTITION GROUP
    
                ----------------------------
    
                IBMCATGROUP
    
                IBMDEFAULTGROUP
    
                PG23
    
     
                3 record(s) selected. 
    
    
                [db2inst1@saturn db2inst1]$
    
             

    Figure 2.22 shows this statement. It also shows you how to associate this buffer pool to another partition group using the ALTER BUFFERPOOL statement.

    To list your buffer pools and associated partition groups, you can query the SYSCAT.BUFFERPOOLS catalog view, also shown in Figure 2.22.

    Example 2.22. Managing buffer pools

    
                [db2inst1@saturn db2inst1]$ db2 "create bufferpool BP23 database partition group pg23 size 500"
    
                DB20000I  The SQL command completed successfully.
    
    
                [db2inst1@saturn db2inst1]$ db2 "alter bufferpool BP23 add database partition group IBMCATGROUP"
    
                DB20000I  The SQL command completed successfully.
    
    
                [db2inst1@saturn db2inst1]$ db2 "select bpname, ngname from syscat.bufferpools"
    
    
                BPNAME                                           NGNAME
    
                --------------------------------------------------------------------------------
    
                IBMDEFAULTBP                                     -
    
    
                BP23                                             PG23
    
    
                BP23                                             IBMCATGROUP
    
     
                3 record(s) selected. 
    
    
                [db2inst1@saturn db2inst1]$
    
             

    Note that a buffer pool can be associated with any partition group. Its definition will be applied to all the partitions in the partition group, and you can specify different sizes on the partitions if required.

  8. Create the table space mytbls1:

    
                db2 "create tablespace mytbls1 in database partition group pg23
             
                managed by system using ('/data') bufferpool bp23"
    
             
  9. Create table table1 in table space mytbls1 with a partitioning key of col1 and col2:

    
                db2 "create table table1 (col1 int, col2 int, col3 char(10))
                
                in mytbls1 
                
                partitioning key (col1, col2)"
    
             
  10. Create the index index1. Note that this doesn't have any syntax specific to a DPF environment:

    
                db2 "create index index1 on table1 (col1, col2)"  
    
             

    The index will be constructed on each partition for its subset of rows.

  11. Test the db2_all command to update the database configuration file for all partitions with one command. Figure 2.23 shows an example of this.

    Example 2.23. Using db2_all to update the db cfg file

    
                [db2inst1@aries sqllib]$ db2 get db cfg for mydb1 | grep LOGFILSIZ
     
                Log file size (4KB)                         (LOGFILSIZ) = 1000
    
                [db2inst1@aries sqllib]$ db2_all "db2 update db cfg for mydb1 using LOGFILSIZ 500"
    
    
                DB20000I  The UPDATE DATABASE CONFIGURATION command completed successfully.
    
                aries.myacme.com: db2 update db cfg for mydb1 using LOGFILSIZ 500 completed ok
    
    
                DB20000I  The UPDATE DATABASE CONFIGURATION command completed successfully.
    
                aries.myacme.com: db2 update db cfg for mydb1 using LOGFILSIZ 500 completed ok
    
    
                DB20000I  The UPDATE DATABASE CONFIGURATION command completed successfully.
    
                saturn.myacme.com: db2 update db cfg for mydb1 using LOGFILSIZ 500 completed ok
    
    
                DB20000I  The UPDATE DATABASE CONFIGURATION command completed successfully.
    
                saturn.myacme.com: db2 update db cfg for mydb1 using LOGFILSIZ 500 completed ok
    
                [db2inst1@aries sqllib]$ db2 get db cfg for mydb1 | grep LOGFILSIZ
     
                Log file size (4KB)                         (LOGFILSIZ) = 500
    
                [db2inst1@aries sqllib]$
    
             

And that's it! In this case study you have reviewed some basic statements and commands applicable to the DPF environment. You reviewed the db2stop and db2start commands, determined and switched the active partition, and created a database, a partition group, a buffer pool, a table space, a table with a partitioning key, and an index. You also used the db2_all command to update a database configuration file parameter.

InformIT Promotional Mailings & Special Offers

I would like to receive exclusive offers and hear about products from InformIT and its family of brands. I can unsubscribe at any time.

Overview


Pearson Education, Inc., 221 River Street, Hoboken, New Jersey 07030, (Pearson) presents this site to provide information about products and services that can be purchased through this site.

This privacy notice provides an overview of our commitment to privacy and describes how we collect, protect, use and share personal information collected through this site. Please note that other Pearson websites and online products and services have their own separate privacy policies.

Collection and Use of Information


To conduct business and deliver products and services, Pearson collects and uses personal information in several ways in connection with this site, including:

Questions and Inquiries

For inquiries and questions, we collect the inquiry or question, together with name, contact details (email address, phone number and mailing address) and any other additional information voluntarily submitted to us through a Contact Us form or an email. We use this information to address the inquiry and respond to the question.

Online Store

For orders and purchases placed through our online store on this site, we collect order details, name, institution name and address (if applicable), email address, phone number, shipping and billing addresses, credit/debit card information, shipping options and any instructions. We use this information to complete transactions, fulfill orders, communicate with individuals placing orders or visiting the online store, and for related purposes.

Surveys

Pearson may offer opportunities to provide feedback or participate in surveys, including surveys evaluating Pearson products, services or sites. Participation is voluntary. Pearson collects information requested in the survey questions and uses the information to evaluate, support, maintain and improve products, services or sites, develop new products and services, conduct educational research and for other purposes specified in the survey.

Contests and Drawings

Occasionally, we may sponsor a contest or drawing. Participation is optional. Pearson collects name, contact information and other information specified on the entry form for the contest or drawing to conduct the contest or drawing. Pearson may collect additional personal information from the winners of a contest or drawing in order to award the prize and for tax reporting purposes, as required by law.

Newsletters

If you have elected to receive email newsletters or promotional mailings and special offers but want to unsubscribe, simply email information@informit.com.

Service Announcements

On rare occasions it is necessary to send out a strictly service related announcement. For instance, if our service is temporarily suspended for maintenance we might send users an email. Generally, users may not opt-out of these communications, though they can deactivate their account information. However, these communications are not promotional in nature.

Customer Service

We communicate with users on a regular basis to provide requested services and in regard to issues relating to their account we reply via email or phone in accordance with the users' wishes when a user submits their information through our Contact Us form.

Other Collection and Use of Information


Application and System Logs

Pearson automatically collects log data to help ensure the delivery, availability and security of this site. Log data may include technical information about how a user or visitor connected to this site, such as browser type, type of computer/device, operating system, internet service provider and IP address. We use this information for support purposes and to monitor the health of the site, identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents and appropriately scale computing resources.

Web Analytics

Pearson may use third party web trend analytical services, including Google Analytics, to collect visitor information, such as IP addresses, browser types, referring pages, pages visited and time spent on a particular site. While these analytical services collect and report information on an anonymous basis, they may use cookies to gather web trend information. The information gathered may enable Pearson (but not the third party web trend services) to link information with application and system log data. Pearson uses this information for system administration and to identify problems, improve service, detect unauthorized access and fraudulent activity, prevent and respond to security incidents, appropriately scale computing resources and otherwise support and deliver this site and its services.

Cookies and Related Technologies

This site uses cookies and similar technologies to personalize content, measure traffic patterns, control security, track use and access of information on this site, and provide interest-based messages and advertising. Users can manage and block the use of cookies through their browser. Disabling or blocking certain cookies may limit the functionality of this site.

Do Not Track

This site currently does not respond to Do Not Track signals.

Security


Pearson uses appropriate physical, administrative and technical security measures to protect personal information from unauthorized access, use and disclosure.

Children


This site is not directed to children under the age of 13.

Marketing


Pearson may send or direct marketing communications to users, provided that

  • Pearson will not use personal information collected or processed as a K-12 school service provider for the purpose of directed or targeted advertising.
  • Such marketing is consistent with applicable law and Pearson's legal obligations.
  • Pearson will not knowingly direct or send marketing communications to an individual who has expressed a preference not to receive marketing.
  • Where required by applicable law, express or implied consent to marketing exists and has not been withdrawn.

Pearson may provide personal information to a third party service provider on a restricted basis to provide marketing solely on behalf of Pearson or an affiliate or customer for whom Pearson is a service provider. Marketing preferences may be changed at any time.

Correcting/Updating Personal Information


If a user's personally identifiable information changes (such as your postal address or email address), we provide a way to correct or update that user's personal data provided to us. This can be done on the Account page. If a user no longer desires our service and desires to delete his or her account, please contact us at customer-service@informit.com and we will process the deletion of a user's account.

Choice/Opt-out


Users can always make an informed choice as to whether they should proceed with certain services offered by InformIT. If you choose to remove yourself from our mailing list(s) simply visit the following page and uncheck any communication you no longer want to receive: www.informit.com/u.aspx.

Sale of Personal Information


Pearson does not rent or sell personal information in exchange for any payment of money.

While Pearson does not sell personal information, as defined in Nevada law, Nevada residents may email a request for no sale of their personal information to NevadaDesignatedRequest@pearson.com.

Supplemental Privacy Statement for California Residents


California residents should read our Supplemental privacy statement for California residents in conjunction with this Privacy Notice. The Supplemental privacy statement for California residents explains Pearson's commitment to comply with California law and applies to personal information of California residents collected in connection with this site and the Services.

Sharing and Disclosure


Pearson may disclose personal information, as follows:

  • As required by law.
  • With the consent of the individual (or their parent, if the individual is a minor)
  • In response to a subpoena, court order or legal process, to the extent permitted or required by law
  • To protect the security and safety of individuals, data, assets and systems, consistent with applicable law
  • In connection the sale, joint venture or other transfer of some or all of its company or assets, subject to the provisions of this Privacy Notice
  • To investigate or address actual or suspected fraud or other illegal activities
  • To exercise its legal rights, including enforcement of the Terms of Use for this site or another contract
  • To affiliated Pearson companies and other companies and organizations who perform work for Pearson and are obligated to protect the privacy of personal information consistent with this Privacy Notice
  • To a school, organization, company or government agency, where Pearson collects or processes the personal information in a school setting or on behalf of such organization, company or government agency.

Links


This web site contains links to other sites. Please be aware that we are not responsible for the privacy practices of such other sites. We encourage our users to be aware when they leave our site and to read the privacy statements of each and every web site that collects Personal Information. This privacy statement applies solely to information collected by this web site.

Requests and Contact


Please contact us about this Privacy Notice or if you have any requests or questions relating to the privacy of your personal information.

Changes to this Privacy Notice


We may revise this Privacy Notice through an updated posting. We will identify the effective date of the revision in the posting. Often, updates are made to provide greater clarity or to comply with changes in regulatory requirements. If the updates involve material changes to the collection, protection, use or disclosure of Personal Information, Pearson will provide notice of the change through a conspicuous notice on this site or other appropriate way. Continued use of the site after the effective date of a posted revision evidences acceptance. Please contact us if you have questions or concerns about the Privacy Notice or any objection to any revisions.

Last Update: November 17, 2020