Introduction to Database Mirroring

Overview of Mirroring:

Mirroring is mainly implemented for increasing the database availability. Similar to log shipping mirroring is also implemented on per database basis. Database mirroring maintains two copies of a single database that must reside on different instances of SQL Server Database Engine (server instances). Typically, these server instances reside on computers in different locations. One server instance serves the database to clients (the principal server), while the other server instance acts as a hot or warm standby server (the mirror server).

Mirroring provides a hybrid solution i.e

1. Provides a copy of the database like Log Shipping and
2. Rapid failover capabilities like Clustering

Advantages of Mirroring :

* Increases data protection —> Depending on the mode of operation Mirroring provides minimal data loss.

* Increases availability of a database —> In the event of a disaster, in high-safety mode with automatic failover, failover quickly brings the standby copy of the database online (with no data loss). In the other operating modes, the database administrator has the alternative of forcing service (with possible data loss) to the standby copy of the database.

* Improves the availability of the production database during upgrades —> During service packs installation or any patch applied on Principal server which requires downtime, the standby comes into effect.

Components in Mirroring :

Database mirroring consist of the following components, lets discuss each one in detail.

1. Principal —> The Principal is the originating server i.e it is the source server which contains the database which is configured for mirroring.There can be only one principal database and it has to be in a separate SQL Server instance than the mirror database.

2. Mirror —> The Mirror is the receiving database in a mirror pair i.e it is the destination server which contains the mirrored database.There can be only one mirror for each principal database.The mirror needs to be on its own separate SQL Server instance preferably on separate physical server.

3. Mirrored Pair —> A Principal and Mirror operating together are called a Mirrored Pair.The changes on the principal are reflected in the mirrored database

4. Witness —> A Witness is optional and it monitors the Mirrored Pair.It ensures that both principal and mirror are functioning properly.The Witness is also a seperate SQL Server instance preferably on a seperate physical server than principal and mirror.One Witness server can monitor multiple Mirrored Pairs.

5. Quorum —> A Quorum is the relationship between the Witness,Principal and the Mirror.It will be discussed later in this article

6. Endpoint —> Endpoint is the method by which SQL Server Database engine communicates with applications.In the context of Database mirroring endpoint is the method by which the Prinicpal communicates with the Mirror.The mirror listens on a port defined in the endpoint.The default is 5022.Each database mirror pair listens on its own unique port.To list all the database mirror endpoints run,

Select * from sys.database_mirroring_endpoints

To list all the endpoints

Select * from sys.tcp_endpoints

Prerequisites for Database Mirroring

I feel its essential to know about the prerequisites before configuring mirroring. Lets discuss each one of them.

1. Make sure that the two partners, that is the principal server and mirror server, are running the same edition of Microsoft SQL Server 2005. The partners require either SQL Server 2005 Standard Edition, SQL Server 2005 Enterprise Edition or SQL Server 2005 Developer Edition.

2. If you are using a witness, make sure that SQL Server 2005 is installed on its system. The witness can run on any reliable computer system that supports SQL Server 2005 Standard Edition, Enterprise Edition, Workgroup Edition, SQL Server 2005 Developer Edition or Express Edition.

3. SQL 2005 SP1 or later version is required for Mirroring

4. The principal database must be in the FULL recovery model. Log records that result from bulk-logged operations cannot be sent to the mirror database.

5. Verify that the mirror server has enough disk space for the mirror database.

6. All of the server instances in a mirroring session should use the same master code page and collation. Differences can cause a problem during mirroring setup.

7. The mirror database must have the same name as the principal database.

8. The mirror database must be initialized from a restore of the principal database with NORECOVERY, followed by restores in sequence of principal transaction log backups.Prior to configuring mirroring ensure that atleast 1 tran log is restored in addition to full backup with NORECOVERY mode.

Snippets about Mirroring

Lets discuss few snippets about database mirroring

Creating endpoint using T-SQL :
Establishing endpoints requires that you have system administrator rights to the SQL Server instance. You must set up endpoints on each server that are specifically created as database mirroring endpoints. The easiest way to set up endpoints is to use the Configure Database Mirroring Security Wizard, which we used while configuring mirroring.

If you are setting up database mirroring on a domain, and all SQL Server instances use the same service login and password, you do not need to create logins on each server. Similarly, on a workgroup, if all SQL Server instances use the same service login and password, you do not need to create logins on the servers. Just leave the logins blank on the Configure Database Mirroring Security Wizard when setting up endpoints.

Each database endpoint must specify a unique port on the server. When working with SQL Server instances on separate machines, these port numbers can all be the same and the Configure Database Mirroring Security Wizard will automatically suggest port 5022 as the port. If any of the SQL Server instances are on the same machine, each instance must have a distinct port and the port numbers must be unique.

Suppose you want to have three servers in a High Availability mirroring session. Server A will be the principal, server B the mirror, and server W the witness. For server A, the following command will create an endpoint on port 5022 :

CREATE ENDPOINT [Mirroring]
AS TCP (LISTENER_PORT = 5022)
FOR DATA_MIRRORING (ROLE = PARTNER, ENCRYPTION = ENABLED)

Note that the role has been specified as PARTNER, so that this server may take on the role of principal or mirror for any given database mirroring database. The same command is issued on server B. Since server B is a SQL Server instance on a distinct physical machine, the port number is the same. Then for server W, you can issue

CREATE ENDPOINT [Mirroring]
AS TCP (LISTENER_PORT = 5022)
FOR DATA_MIRRORING (ROLE = WITNESS, ENCRYPTION = ENABLED)

Note that for server W, the role is specified as WITNESS.
By default, the endpoint is not started. You can next start each endpoint using the following query on each server:

ALTER ENDPOINT [Mirroring] STATE = STARTED

Fully Qualified Domain Name :
To start database mirroring, you next specify the partners and witness. You need database owner permissions to start and administer a given database mirroring session. On server A, the intended principal server, you tell SQL Server to give a particular database the principal role and what its partner (mirror) server is :

ALTER DATABASE [AdventureWorks] SET PARTNER = N'TCP://B.corp.mycompany.com:5022'

The partner name must be the fully qualified computer name of the partner. Finding fully qualified names can be a challenge, but the Configure Database Mirroring Security Wizard will find them automatically when establishing endpoints.
The fully qualified computer name of each server can also be found running the following from the command prompt :

IPCONFIG /ALL
Concatenate the “Host Name” and “Primary DNS Suffix”. If you see something like:
Host Name . . . . . . . . . . . . : A
Primary Dns Suffix . . . . . . . : corp.mycompany.com

Then the computer name is just A.corp.mycompany.com. Prefix ‘TCP://’ and append ‘:’ and you then have the partner name.
On the mirror server, you would just repeat the same command, but with the principal server named :

ALTER DATABASE [AdventureWorks] SET PARTNER = N'TCP://A.corp.mycompany.com:5022'

On the principal server, you next specify the witness server:

ALTER DATABASE [AdventureWorks]
SET WITNESS = N'TCP://W.corp.mycompany.com:5026'

Finally, you specify the safety level of the session, on the principal server:

ALTER DATABASE [AdventureWorks] SET SAFETY FULL

At this point, mirroring will start automatically, and the principal and mirror servers will synchronize.

Database Mirroring Catalog Views :

A database mirroring session consists of the relationship formed between the partner serves and potentially the witness server. Each of the participating servers keeps some metadata about the session and the current state of the databases.

* sys.database_mirroring —> provides information about principal and mirror

* sys.database_mirroring_witnesses —> provides information about witness server

All the metadata required for database mirroring (in particular the mirroring failover lsn and partner server names) are kept by the mirroring partners. The witness only keeps data necessary for its role as a witness in a High Availability mode, in particular the role sequence number, which tracks the number of role changes in the session.

Database mirroring states and transition :

Database states for each server are kept during the database mirroring session, recorded on each partner server, and reported by the sys.database_mirroring catalog view. The mirroring_state column returns a number for the state, and the mirroring_state_desc column returns the descriptive name for the state. State information about the witness is also reported from the same catalog view.

In addition to the states reported for each database, there are three phrases that are useful in describing the servers and databases involved in database mirroring.

1. Exposed – The data on the principal is exposed when it is processing transactions but no log data is being sent to the mirror. When a principal database is exposed, it is active with user connections and processing transactions. However, no log records are being sent to the mirror database, and if the principal should fail, the mirror will not have any of the transactions from the principal from the point the principal entered the exposed state. Also, the principal’s transaction log cannot be truncated, so the log file will be growing indefinitely.

2. Cannot serve the database – When a principal server does not allow any user connections to the database and any transactions to be processed. When a witness has been set, if the principal server cannot form a quorum with another server, it will stop serving the database. It will not allow user connections and transactions on the principal database, and will disconnect all current users. As soon as it can form a quorum again, it will return to serving the database.

3. Isolated – A server is isolated when it cannot contact any of the other servers in the database mirroring session, and they cannot contact it.A server may be operational but communication lines are down between it and both other servers in the database mirroring session. In that case, we’ll call the server isolated. If a witness has been set, then, if the principal server becomes isolated, it will no longer be able to serve the database, because there is no server in the session with which it can form a quorum.

When safety is FULL, the principal first enters the SYNCHRONIZING state and as soon as it synchronizes with the mirror, both partners enter the SYNCHRONIZED state. When safety is OFF, the partner databases start with the SYNCHRONIZING state. Once the mirror has caught up, the state goes to SYNCHRONIZED and stays there regardless of how far behind it is.
For both safety settings, if the session is paused or there are redo errors on the mirror, the principal enters the SUSPENDED state. If the mirror becomes unavailable, the principal will enter the DISCONNECTED state.

In the DISCONNECTED and SUSPENDED states:

* When a witness has been set, if the principal can form a quorum with the witness or mirror server, the principal database is considered exposed. That means the principal database is active with user connections and processing transactions. However, no log records are being sent to the mirror database, and if the principal should fail, the mirror will not have any of the transactions from the principal from the point the principal entered that state. Also, the principal’s transaction log cannot be truncated, so the log file will be growing indefinitely.

* When a witness has been set, if the principal cannot form a quorum with another server, it cannot serve the database. All users will be disconnected and no new transactions will be processed.

* When safety is OFF, the principal database is considered exposed, because no transaction log records are being sent to the mirror.


Posted

in

by

Tags:

Comments

Leave a Reply

Your email address will not be published. Required fields are marked *