Home > Articles

This chapter is from the book

Database Creation

An absolute necessity of building databases that interact with SQL Server 2000 is using the appropriate database objects to obtain a usable database system while improving response times and maintaining data integrity. There are considerations and trade-offs for choosing one technique over the other. The selection of the most appropriate method to obtain the desired result requires that you know where each technique is best implemented. The exam will test on the appropriate application of each of these objects.

Creating and altering databases involves selecting the physical volume type for each database file, setting the appropriate file properties, placing the objects into the files/filegroups, and ensuring that appropriate adjustments are made as the database matures. The type of business needs that the database is being designed to meet helps to indicate the measures needed to ensure adequate performance.

Try to place onto separate volumes any files that might tend to compete with each other for read cycles during a single operation. Place log files away from the data to ensure adequate recovery, and make sure that database properties have been set in such a way as to ensure that maintenance tasks can be performed.

When you create a database for the first time, that database initially takes most of its attributes from the Model database. The Model database is a system database that SQL Server uses as a kind of template for database creations. It is a good and common practice to set the properties and contents of the Model database based on the majority of new databases that are to be created.

In practice, many objects are stored in the Model database to minimize the need to re-create these objects every time a database is created. Common elements placed in the Model often include specialized user-defined functions and data types that are present and frequently used by the development staff in their coding. In theory, objects are created for use in a single database, but all developers realize that object and code reuse is an important facet of easing the development process.

Often an object, such as a user-defined function, standard security role, or corporate information table, can be found in most if not all databases within a company. A property value, such as recovery level, might also have a standard implementation across all servers in the enterprise. If an object or a property value will be present in most of the user databases, placing the object into the Model database or setting a property accordingly can save you the work of performing the activity as a post-creation task.

All files needed for a database can be created through a single activity using SQL Server’s Enterprise Manager (as shown in Figure 3.1) or with a single CREATE DATABASE Transact SQL statement. Either of these methods can be used to initialize all files and create the database and logs in a single step.

Figure 3.1

Figure 3.1 Database creation from the Enterprise Manager.

SQL Server 2000 enables you to set database files so that they expand and shrink automatically, eliminating the need for additional administration. By default, SQL Server enables data files to increase in size as needed for data storage. Therefore, a file can grow to the point where all disk space is exhausted. You can specify that a file is not to grow beyond its creation size or implement a maximum size for file growth. Ensure that disk space is not exhausted by using the MAXSIZE option of the CREATE DATABASE or ALTER DATABASE statements to indicate the largest size to which a file can grow.

The default names for the primary database and transaction log files are created using the database name you specified as the prefix—for example, NewDatabase_Data.mdf and NewDatabase_Log.ldf. These names and locations can be changed, if desired, from the default values provided for the new database file. The T-SQL syntax for creating a simple database is as follows:

CREATE DATABASE MyDatabase
ON
(NAME = ‘DataStore’,
  FILENAME = ‘d:\data directory\DataStore_MyDatabase.mdf’,
  SIZE = 1MB, MAXSIZE = 5MB, FILEGROWTH = 1MB)
LOG ON
(NAME =’LogStore’,
  FILENAME = ‘e:\log directory\LogStore_MyDatabase.ldf’,
  SIZE = 1MB, MAXSIZE = 5MB, FILEGROWTH = 1MB)

Following are some important issues with regard to appropriate use of the CREATE DATABASE statement:

  • The default growth increment measure is MB, but it can also be specified with a KB or a % suffix. When % is specified, the growth increment size is the specified percentage of the size of the file at the time the increment occurs.

  • A maximum of 32,767 databases can be defined on a server.

  • The minimum size for a log file is 512KB.

  • Each database has an owner. The owner is the user who creates the database. The database owner can be changed through sp_changedbowner.

  • The Master database should be backed up after a user database is created.

  • The default unit of measure for the size and maxsize settings is MB if you supply a number, but no measure is provided. If no options are supplied, maxsize defaults to unlimited and the filegrowth is 10%.

In a volatile environment, the database and its related files might frequently increase and decrease in size, and this activity might be the desired operation of the server. In most instances, an implementation providing for more stability in the file system is the desired result. A determination has to be made as to whether the database stays at about the same size or grows or shrinks over time. In most scenarios, a database grows over time and needs to be reduced only when data is archived.

When creating the files, you should set the SIZE, MAXSIZE, and FILEGROWTH parameters so that the database can increase in volume over time. The FILEGROWTH configuration should be implemented in larger increments so that growth within the file system isn’t occupying too much of the server’s resources. Growth of files occurs in the background and can be minimized by using a larger growth increment. Always provide a MAXSIZE entry even if the entry itself is close to the capacity of the volume.

You can use the CREATE DATABASE statement to create a database from script. Saving the script enables you to re-create a similar database on another server in the future. Any SQL Server object can have its creation script saved. Using the CREATE DATABASE statement to create a database using multiple files and log files would look similar to this:

CREATE DATABASE Example
ON
PRIMARY ( NAME = ExampleData,
FILENAME = ‘c:\mssql\data\sampdat.mdf’,
     SIZE = 10MB,
     MAXSIZE = 20MB,
     FILEGROWTH = 2MB),
    ( NAME = ExampleIndexes,
FILENAME = ‘c:\mssql\data\sampind2.ndf’,
     SIZE = 10MB,
     MAXSIZE = 20MB,
     FILEGROWTH = 2MB),
    ( NAME = ExampleArchive,
FILENAME = ‘c:\mssql\data\samparch.ndf’,
     SIZE = 10MB,
     MAXSIZE = 20MB,
     FILEGROWTH = 2MB)
LOG ON ( NAME = ExampleLog1,
FILENAME = ‘d:\mssql\log\samplog1.ldf’,
     SIZE = 10MB,
     MAXSIZE = 20MB,
     FILEGROWTH = 2MB),
    ( NAME = ExampleLog2,
FILENAME = ‘d:\mssql\log\samplog2.ldf’,
     SIZE = 10MB,
     MAXSIZE = 20MB,
     FILEGROWTH = 2MB)

When you create the database and its associated files, you provide values to determine the initial file sizes, indicate whether and how the files will grow, and specify some other basic database and file properties. The initial settings are used as a basis for future file-system activities. If the initial settings are in need of alteration later, you can perform this activity through the Enterprise Manager or by using the ALTER DATBASE T-SQL statement. Alterations can impact the front-end applications, so extra caution must be taken when changing a database from its original form. In particular, the alteration of the collating sequence can have serious repercussions.

Using a Collation Sequence

A collation sequence is a set of rules governing the characters that are used within a database and the means by which characters are sorted and compared. In SQL Server 2000 this sequence can be set on a database-by-database basis. In previous versions of SQL Server, the collation sequence was a server-wide setting. You therefore had to either perform a whole series of rebuilding actions to create a database that did not use the server collation, or install the database on a separate server altogether.

In SQL Server 2000 you can specify a nondefault collation for any database on the server. This means that one database does not have to have the same characters or sorting rules as the rest of the databases on the server. If all but one or two of your databases have the same set of characters, a single server can now implement the functionality that previously would have taken two separate machines.

To create a database with a nondefault collating sequence, provide the COLLATE clause on the CREATE DATABASE command. You might also select the collation name from the drop-down box in the Enterprise Manager when you create the database from the GUI.

Collation for an individual column can be different. A collation can be selected for an individual column but is not recommended because it causes great difficulty in the development of front-end applications. Be careful in the use of multiple collating sequences because it makes the transfer and entry of data more complex. It might also limit the application development environment and techniques normally used for data entry and editing.

Be certain of the collation sequence used upon creation of a database. After the collation sequence is set, it can be changed only through rebuilding of the database. If possible, collation decisions should be made during the logical design of the system so that you don’t have to rebuild. Although collations can be different, if you want to change the sequence post-creation, you will have to rebuild the database.

Altering Database Properties

Several database properties affect the way in which some SQL Server commands operate. You can use the Enterprise Manager to make appropriate adjustments to some of the database properties. Alternatively, you can use the ALTER DATABASE T-SQL statement to script these changes. You may prefer setting options using T-SQL. The system-stored procedure sp_dboption can still be used to set database options, but Microsoft has stated that in future versions of SQL Server this functionality might not be supported.

In altering a database, you can add or remove files and filegroups and/or modify attributes of the files and filegroups. ALTER DATABASE also enables you to set database properties, whereas in previous versions these properties could be changed only using the sp_dboption stored procedure.

After you’ve set up the options, the next thing to consider is the creation of objects within the database. Database objects include constraints, indexes, stored procedures, tables, triggers, user-defined functions, views, and more. Each object is discussed in detail, paying particular attention to the impact on the system as a whole. In many implementations, there are various approaches to meeting a particular need. Selecting the appropriate technique for a task requires trade-offs among functionality, performance, and resource utilization.

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