Share this
Understanding the Implications of Creating a New PDB Using CREATE_FILE_DEST
by Simon Pane on Jul 15, 2021 12:00:00 AM
qOverview
When creating a new pluggable database, or PDB, you can optionally include the CREATE_FILE_DEST clause.
Here’s an example:
create pluggable database PDB1 admin user admin identified by "************" create_file_dest = '+DATA_DG'; |
The value provided can be an ASM (Automatic Storage Management) disk group or an OS filesystem path.
Either way, the question is: “What are the implications of including this clause when creating a PDB?”
The answer is “it’s complicated,” but there are at least four key implications (tested using Oracle Database 19c):
- When the new PDB is first opened, the PDB initialization parameter DB_CREATE_FILE_DEST will be set in the PDB spfile (which is really a catalog table, but that’s beside the point) to the CREATE_FILE_DEST value.
- The behavior of the DB_CREATE_FILE_DEST parameter within the PDB is changed; it becomes a restriction (meaning new datafiles must align with this setting) rather than being just a default. There are some caveats, based on whether Oracle Managed Files (OMFs) or unmanaged files are created, whether they’re inside ASM and whether the CREATE_FILE_DEST option specifies an ASM disk group.
- The DB_CREATE_FILE_DEST parameter within the PDB can now only be changed by SYSDBA connections—not normal PDB DBAs.
- The DB_CREATE_FILE_DEST restrictions not only affect data files and temp files but also extend to RMAN backup pieces.
Of the above, only the first implication is mentioned in the official Oracle documentation for the CREATE PLUGGABLE DATABASE statement. Similarly, the official Oracle documentation for the DB_CREATE_FILE_DEST initialization parameter makes no mention of the other points.
Complexities with DB_CREATE_FILE_DEST
First some important background as a reminder:
- Oracle Managed Files (OMFs) are files with names and paths automatically created and managed by Oracle and are created in the location specified by DB_CREATE_FILE_DEST, DB_CREATE_ONLINE_LOG_DEST_n or DB_RECOVERY_FILE_DEST.
- All files in ASM are OMFs, however you can specify the ASM disk group name—Oracle builds the rest of the path and file name from the disk group onwards.
- File aliases can be used in ASM, but they all reference an OMF.
- Non-Oracle Managed Files are known as “unmanaged files.”
- OMFs and unmanaged files can exist on operating system filesystems.
Now, how the DB_CREATE_FILE_DEST initialization parameter works is dependent on whether the PDB was created with the CREATE_FILE_DEST clause.
When the PDB is not created with the CREATE_FILE_DEST clause, the DB_CREATE_FILE_DEST parameter acts as a default. If no file name is specified in the DDL command, an OMF is created in the location specified by the parameter—simple enough. But unmanaged files can be created in OS filesystem paths and OMFs can be created in ASM (by simply specifying a disk group). It’s only a default and no legitimate file location is blocked.
When the PDB is created with CREATE_FILE_DEST, the situation becomes more complicated. Rather than just being a default, DB_CREATE_FILE_DEST is now enforced but with some variance depending on whether the parameter is set to an ASM disk group or an OS filesystem path, and whether the file being created is in ASM. Confusing!
The full implications and permutations are easiest to summarize in a table (again, applicable only when the PDB was created using the CREATE_FILE_DEST option):
| DB_CREATE_FILE_DEST Set to: | Creating a data file in: | Result: |
| ASM disk group | No-file specification (pure OMF) | PERMITTED |
| A different ASM disk group | INVALID PATH | |
| Unmanaged file in any OS filesystem path | PERMITTED | |
| OS filesystem path | No-file specification (pure OMF) | PERMITTED |
| Any ASM disk group | INVALID PATH | |
| Unmanaged file in a different OS path | INVALID PATH | |
| Unmanaged file in the same OS path | PERMITTED | |
| NULL or an empty string | No-file specification (pure OMF) | INVALID FILE NAME |
| Any ASM disk group | PERMITTED | |
| Unmanaged file in any OS filesystem path | PERMITTED |
These results are a bit surprising. For example, if I created a PDB with CREATE_FILE_DEST (and subsequently DB_CREATE_FILE_DEST) set to an ASM disk group, presumably I want all data files to be in that disk group, so why does Oracle also let me add unmanaged data files to an OS filesystem location?!?!
And, it doesn’t matter what value was used in the CREATE_FILE_DEST clause when the PDB was created (as it can be changed as explained below). All that matters is that the clause was included. After that the DB_CREATE_FILE_DEST parameter enforcement is in place as per the rules in the table above.
Demonstration
First we can create two PDBs: DEMO1 without the CREATE_FILE_DEST clause and DEMO2 with it:
SQL> create pluggable database DEMO1 2 admin user admin identified by "********"; Pluggable database created. SQL> create pluggable database DEMO2 2 admin user admin identified by "********" 3 create_file_dest = '+DATA_DG'; Pluggable database created. SQL> alter pluggable database all open; Pluggable database altered. SQL> |
Now, if we try to create a datafile in DEMO1 outside of the ASM disk group specified in DB_CREATE_FILE_DEST, the command works:
SQL> alter session set container = DEMO1; Session altered. SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +DATA_DG SQL> SQL> SQL> create tablespace USERS datafile '+FRA_DG' size 10m; Tablespace created. SQL> select file_name from dba_data_files where tablespace_name = 'USERS'; FILE_NAME -------------------------------------------------------------------------------- +FRA_DG/ORCL/C1B18FCBEED60ACDE0536B3810AC5C7E/DATAFILE/users.258.1071850539 SQL> |
But if we try the same thing in DEMO2, the command fails:
SQL> alter session set container = DEMO2; Session altered. SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +DATA_DG SQL> SQL> create tablespace USERS datafile '+FRA_DG' size 10m; create tablespace USERS datafile '+FRA_DG' size 10m * ERROR at line 1: ORA-65250: invalid path specified for file - +FRA_DG SQL> |
This illustrates that DB_CREATE_FILE_DEST is a restriction in DEMO2 but only a default in DEMO1.
Surprisingly, this is enforced only for Oracle Managed Files (OMFs)! If we try an unmanaged file (non-OMF), outside of ASM, it works:
SQL> alter session set container = DEMO2; Session altered. SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +DATA_DG SQL> SQL> create tablespace USERS datafile '/u01/oradata/users01.dbf' size 10m; Tablespace created. SQL> |
Testing with RMAN backup pieces yields similar results. This doesn’t seem desirable—arguably it would make sense to enforce the location for data files and temp files (i.e. to a specific ASM disk group) but allow RMAN backups to be written to another disk group.
Adjusting the Parameter
The second change is with respect to which type of user can adjust the parameter.
In the DEMO1 database, any local DBA user can change the parameter:
SQL> alter session set container = DEMO1; Session altered. SQL> grant dba to simon_dba identified by testing; Grant succeeded. SQL> connect simon_dba/testing@localhost:1521/DEMO1 Connected. SQL> SQL> show user con_name USER is "SIMON_DBA" CON_NAME ------------------------------ DEMO1 SQL> SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +DATA_DG SQL> SQL> alter system set db_create_file_dest = '+FRA_DG' scope=both; System altered. SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +FRA_DG SQL> |
But in the DEMO2 database, a local DBA user cannot change it—only a SYSDBA user can:
SQL> alter session set container = DEMO2; Session altered. SQL> grant dba to simon_dba identified by testing; Grant succeeded. SQL> connect simon_dba/testing@localhost:1521/DEMO2 Connected. SQL> SQL> show user con_name USER is "SIMON_DBA" CON_NAME ------------------------------ DEMO2 SQL> SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +DATA_DG SQL> SQL> alter system set db_create_file_dest = '+FRA_DG' scope=both; alter system set db_create_file_dest = '+FRA_DG' scope=both * ERROR at line 1: ORA-32017: failure in updating SPFILE ORA-01031: insufficient privileges SQL> alter system set db_create_file_dest = '+FRA_DG' scope=memory; alter system set db_create_file_dest = '+FRA_DG' scope=memory * ERROR at line 1: ORA-02097: parameter cannot be modified because specified value is invalid ORA-01031: insufficient privileges SQL> alter system reset db_create_file_dest; alter system reset db_create_file_dest * ERROR at line 1: ORA-32017: failure in updating SPFILE ORA-01031: insufficient privileges SQL> connect / as sysdba Connected. SQL> alter session set container = DEMO2; Session altered. SQL> show user con_name USER is "SYS" CON_NAME ------------------------------ DEMO2 SQL> SQL> alter system set db_create_file_dest = '+FRA_DG' scope=both; System altered. SQL> show parameter db_create_file_dest NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ db_create_file_dest string +FRA_DG SQL> |
This is similar behavior to restrictions from a PDB Lockdown Profile, but no PDB Lockdown Profile exists:
SQL> connect / as sysdba Connected. SQL> show parameter pdb_lockdown NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ pdb_lockdown string SQL> SQL> alter session set container = DEMO2; Session altered. SQL> show parameter pdb_lockdown NAME TYPE VALUE ------------------------------------ ----------- ------------------------------ pdb_lockdown string SQL> SQL> select * from dba_lockdown_profiles; no rows selected SQL> |
So, we see PDB Lockdown Profile functionality, but without using an actual Lockdown Profile and only for this one parameter.
Verification
The final question is how to tell whether the PDB was created using CREATE_FILE_DEST. Surprisingly it doesn’t seem to be shown in a catalog view. Rather a BIT flag in CONTAINER$ tracks it using bit 30 (which is 29 in binary, starting at 0):
SQL> SELECT CON_ID_TO_CON_NAME(con_id#) pdb_name, 2 DECODE(BITAND(flags, POWER(2,29)), POWER(2,29), 'YES', 'NO') CREATE_FILE_DEST 3 FROM container$ 4 WHERE status != 4 AND con_id# > 2 5 ORDER BY 1; PDB_NAME CREATE_FILE_DEST ------------------------ ---------------- DEMO1 NO DEMO2 YES SQL> |
Bonus Tip
When decoding bit masks from decimal values, you can use a handy query such as the following provided by Jared Still (just update the con_id# as required) to see which bits are, and are not, set:
WITH
data AS (
SELECT flags
FROM container$
WHERE con_id# = 9
),
masked AS (
SELECT flags
, level-1 bit
, POWER(2,level-1) mask
FROM data
CONNECT BY level <= 64
ORDER BY level
)
SELECT bit
, mask
, DECODE(BITAND(flags, mask), 0, 'NOT SET', ' SET') bitset
FROM masked;
|
Conclusion
Unfortunately, the Oracle documentation is not explicitly clear as to what creating a database using CREATE_FILE_DEST really does.
But testing shows at least four key implications of including this clause:
- It sets the default value for DB_CREATE_FILE_DEST in the PDB (documented).
- DB_CREATE_FILE_DEST in the PDB becomes an enforced restriction instead of a default (with some conditions depending on the parameter setting).
- Only SYSDBAs can change the parameter in the PDB (not regular PDB DBAs).
- The enforcement extends to RMAN backup pieces if they are OMFs written to ASM.
I hope this was helpful. If you have any questions or thoughts, please leave them in the comments.
Oracle Database Consulting Services
Ready to optimize your Oracle Database for the future?
Share this
- Technical Track (816)
- Oracle (488)
- Database (229)
- MySQL (144)
- Cloud (133)
- Microsoft SQL Server (124)
- Open Source (84)
- Google Cloud (82)
- Microsoft Azure (67)
- Amazon Web Services (AWS) (63)
- Big Data (50)
- Cassandra (44)
- Google Cloud Platform (44)
- DevOps (38)
- Linux (28)
- Pythian (27)
- PostgreSQL (26)
- Podcasts (25)
- Site Reliability Engineering (23)
- Performance (22)
- Docker (21)
- Oracle E-Business Suite (21)
- DBA (18)
- Oracle Cloud Infrastructure (OCI) (18)
- MongoDB (17)
- Security (17)
- Hadoop (16)
- BigQuery (15)
- Amazon RDS (14)
- Automation (14)
- Exadata (14)
- Oracleebs (14)
- Snowflake (14)
- Ansible (13)
- Oracle Database (13)
- Oracle Exadata (13)
- ASM (12)
- Data (12)
- LLM (12)
- Artificial Intelligence (AI) (11)
- GenAI (11)
- Kubernetes (11)
- Machine Learning (11)
- Advanced Analytics (10)
- Datascape Podcast (10)
- Oracle Applications (10)
- Replication (10)
- Authentication, SSO and MFA (8)
- ChatGPT (8)
- Cloud Migration (8)
- Infrastructure (8)
- Monitoring (8)
- Percona (8)
- Analytics (7)
- Apache (7)
- Apache Cassandra (7)
- Data Governance (7)
- High Availability (7)
- Mariadb (7)
- Microsoft Azure SQL Database (7)
- Myrocks (7)
- Oracle EBS (7)
- Python (7)
- Rman (7)
- SAP (7)
- Series (7)
- AWR (6)
- Airflow (6)
- Apache Beam (6)
- Data Guard (6)
- Innodb (6)
- Migration (6)
- Oracle Enterprise Manager (OEM) (6)
- Orchestrator (6)
- RocksDB (6)
- Azure Synapse Analytics (5)
- Covid-19 (5)
- Data Enablement (5)
- Disaster Recovery (5)
- Microsoft (5)
- Performance Tuning (5)
- Scala (5)
- Serverless (5)
- Cloud Security (4)
- Cloud Spanner (4)
- CockroachDB (4)
- Data Management (4)
- Data Pipeline (4)
- Data Security (4)
- Data Strategy (4)
- Data Visualization (4)
- Databases (4)
- Dataflow (4)
- Generative AI (4)
- Google (4)
- Google BigQuery (4)
- Oracle Autonomous Database (Adb) (4)
- Oracle Cloud (4)
- Oracle Enterprise Manager (4)
- Redhat (4)
- Ssl (4)
- Windows (4)
- Xtrabackup (4)
- Amazon Relational Database Service (Rds) (3)
- Apex (3)
- Cloud Database (3)
- Cloud FinOps (3)
- Data Analytics (3)
- Data Migrations (3)
- Database Migration (3)
- Digital Transformation (3)
- ERP (3)
- Google Chrome (3)
- Google Cloud Sql (3)
- Google Workspace (3)
- Heterogeneous Database Migration (3)
- Oracle Live Sql (3)
- Oracle Rac (3)
- Perl (3)
- Power Bi (3)
- Prometheus (3)
- Remote Teams (3)
- Slob (3)
- Tensorflow (3)
- Terraform (3)
- Amazon Data Migration Service (2)
- Amazon Ec2 (2)
- Anisble (2)
- Apache Flink (2)
- Apache Kafka (2)
- Apexexport (2)
- Ashdump (2)
- Aurora (2)
- Azure Data Factory (2)
- Cloud Armor (2)
- Cloud Data Fusion (2)
- Cloud Hosting (2)
- Cloud Infrastructure (2)
- Cloud Shell (2)
- Cloud Sql (2)
- Conferences (2)
- Cosmos Db (2)
- Cosmosdb (2)
- Cost Management (2)
- Data Discovery (2)
- Data Integration (2)
- Data Quality (2)
- Data Streaming (2)
- Database Administrator (2)
- Database Consulting (2)
- Database Monitoring (2)
- Database Performance (2)
- Database Troubleshooting (2)
- Dataguard (2)
- Dataops (2)
- Enterprise Data Platform (EDP) (2)
- Events (2)
- Fusion Middleware (2)
- Gemini (2)
- Graphite (2)
- Infrastructure As Code (2)
- Innodb Cluster (2)
- Innodb File Structure (2)
- Innodb Group Replication (2)
- Liquibase (2)
- NLP (2)
- Nosql (2)
- Oracle Data Guard (2)
- Oracle Datase (2)
- Oracle Flashback (2)
- Oracle Forms (2)
- Oracle Installation (2)
- Oracle Io Testing (2)
- Podcast (2)
- Rdbms (2)
- Redshift (2)
- Remote DBA (2)
- Remote Sre (2)
- S3 (2)
- Single Sign-On (2)
- Webinars (2)
- X5 (2)
- AI (1)
- Actifio (1)
- Adop (1)
- Advanced Data Services (1)
- Afd (1)
- Alloydb (1)
- Amazon (1)
- Amazon Aurora Backtrack (1)
- Amazon Efs (1)
- Amazon Redshift (1)
- Amazon S3 (1)
- Amazon Sagemaker (1)
- Amazon Vpc Flow Logs (1)
- Analysis (1)
- Analytical Models (1)
- Anthos (1)
- Application Migration (1)
- Ash (1)
- Asmlib (1)
- Atp (1)
- Autonomous (1)
- Awr Data Mining (1)
- Awr Mining (1)
- Azure Data Lake (1)
- Azure Data Lake Analytics (1)
- Azure Data Lake Store (1)
- Azure Data Migration Service (1)
- Azure OpenAI (1)
- Azure Sql Data Warehouse (1)
- Batches In Cassandra (1)
- Business Insights (1)
- Business Intelligence (1)
- Chown (1)
- Chrome Security (1)
- Cloud Browser (1)
- Cloud Build (1)
- Cloud Consulting (1)
- Cloud Cost Optimization (1)
- Cloud Data Warehouse (1)
- Cloud Database Management (1)
- Cloud Dataproc (1)
- Cloud Foundry (1)
- Cloud Networking (1)
- Cloud SQL Replica (1)
- Cloud Scheduler (1)
- Cloud Services (1)
- Cloud Strategies (1)
- Compliance (1)
- Conversational AI (1)
- Cyber Security (1)
- Data Analysis (1)
- Data Analytics Platform (1)
- Data Box (1)
- Data Classification (1)
- Data Cleansing (1)
- Data Encryption (1)
- Data Engineering (1)
- Data Estate (1)
- Data Insights (1)
- Data Integrity (1)
- Data Leader (1)
- Data Lifecycle Management (1)
- Data Lineage (1)
- Data Masking (1)
- Data Mesh (1)
- Data Migration (1)
- Data Migration Assistant (1)
- Data Migration Service (1)
- Data Mining (1)
- Data Monetization (1)
- Data Policy (1)
- Data Profiling (1)
- Data Protection (1)
- Data Retention (1)
- Data Safe (1)
- Data Sheets (1)
- Data Summit (1)
- Data Vault (1)
- Data Warehouse (1)
- Database Consultant (1)
- Database Link (1)
- Database Management (1)
- Database Migrations (1)
- Database Modernization (1)
- Database Provisioning (1)
- Database Provisioning Failed (1)
- Database Replication (1)
- Database Schemas (1)
- Database Upgrade (1)
- Databricks (1)
- Datascape 59 (1)
- DeepSeek (1)
- Docker-Composer (1)
- Duet AI (1)
- Edp (1)
- Etl (1)
- Gcp Compute (1)
- Gcp-Spanner (1)
- Global Analytics (1)
- Google Analytics (1)
- Google Cloud Architecture Framework (1)
- Google Cloud Data Services (1)
- Google Cloud Partner (1)
- Google Cloud Spanner (1)
- Google Cloud VMware Engine (1)
- Google Compute Engine (1)
- Google Dataflow (1)
- Google Datalab (1)
- Google Grab And Go (1)
- Graph Algorithms (1)
- Graph Inferences (1)
- Graph Theory (1)
- GraphQL (1)
- Health Check (1)
- Healthcheck (1)
- Information (1)
- Infrastructure As A Code (1)
- Innobackupex (1)
- Innodb Concurrency (1)
- Innodb Flush Method (1)
- It Industry (1)
- Kubeflow (1)
- LMSYS Chatbot Arena (1)
- Linux Host Monitoring (1)
- Linux Storage Appliance (1)
- Looker (1)
- MMLU (1)
- Managed Services (1)
- Migrate (1)
- Neo4J (1)
- Newsroom (1)
- Nifi (1)
- OPEX (1)
- Odbcs (1)
- Odbs (1)
- On-Premises (1)
- Open Source Database (1)
- Ora-01852 (1)
- Ora-7445 (1)
- Oracle Cursor (1)
- Oracle Database@Google Cloud (1)
- Oracle Exadata Smart Scan (1)
- Oracle Licensing (1)
- Oracle Linux Virtualization Manager (1)
- Oracle Oda (1)
- Oracle Openworld (1)
- Oracle Parallelism (1)
- Oracle RMAN (1)
- Oracle Rdbms (1)
- Oracle Real Application Clusters (1)
- Oracle Reports (1)
- Oracle Security (1)
- Perfomrance (1)
- Performance Schema (1)
- Policy (1)
- Prompt Engineering (1)
- Public Cloud (1)
- Pythian News (1)
- Rdb (1)
- Replication Error (1)
- Retail (1)
- SAP HANA Cloud (1)
- Securing Sql Server (1)
- Serverless Computing (1)
- Sso (1)
- Tenserflow (1)
- Teradata (1)
- Vertex AI (1)
- Videos (1)
- Workspace Security (1)
- Xbstream (1)
- August 2025 (1)
- July 2025 (3)
- June 2025 (1)
- May 2025 (3)
- March 2025 (2)
- February 2025 (1)
- January 2025 (2)
- December 2024 (1)
- October 2024 (2)
- September 2024 (7)
- August 2024 (4)
- July 2024 (2)
- June 2024 (6)
- May 2024 (3)
- April 2024 (2)
- February 2024 (1)
- January 2024 (11)
- December 2023 (10)
- November 2023 (9)
- October 2023 (11)
- September 2023 (9)
- August 2023 (6)
- July 2023 (2)
- June 2023 (13)
- May 2023 (4)
- April 2023 (6)
- March 2023 (10)
- February 2023 (6)
- January 2023 (5)
- December 2022 (10)
- November 2022 (10)
- October 2022 (10)
- September 2022 (13)
- August 2022 (16)
- July 2022 (12)
- June 2022 (13)
- May 2022 (11)
- April 2022 (4)
- March 2022 (5)
- February 2022 (4)
- January 2022 (14)
- December 2021 (16)
- November 2021 (11)
- October 2021 (6)
- September 2021 (11)
- August 2021 (6)
- July 2021 (9)
- June 2021 (4)
- May 2021 (8)
- April 2021 (16)
- March 2021 (16)
- February 2021 (6)
- January 2021 (12)
- December 2020 (12)
- November 2020 (17)
- October 2020 (11)
- September 2020 (10)
- August 2020 (11)
- July 2020 (13)
- June 2020 (6)
- May 2020 (9)
- April 2020 (18)
- March 2020 (21)
- February 2020 (13)
- January 2020 (15)
- December 2019 (10)
- November 2019 (11)
- October 2019 (12)
- September 2019 (16)
- August 2019 (15)
- July 2019 (10)
- June 2019 (16)
- May 2019 (20)
- April 2019 (21)
- March 2019 (14)
- February 2019 (18)
- January 2019 (18)
- December 2018 (5)
- November 2018 (16)
- October 2018 (12)
- September 2018 (20)
- August 2018 (27)
- July 2018 (31)
- June 2018 (34)
- May 2018 (28)
- April 2018 (27)
- March 2018 (17)
- February 2018 (8)
- January 2018 (20)
- December 2017 (14)
- November 2017 (4)
- October 2017 (1)
- September 2017 (3)
- August 2017 (5)
- July 2017 (4)
- June 2017 (2)
- May 2017 (7)
- April 2017 (7)
- March 2017 (8)
- February 2017 (8)
- January 2017 (5)
- December 2016 (3)
- November 2016 (4)
- October 2016 (8)
- September 2016 (9)
- August 2016 (10)
- July 2016 (9)
- June 2016 (8)
- May 2016 (13)
- April 2016 (16)
- March 2016 (13)
- February 2016 (11)
- January 2016 (6)
- December 2015 (11)
- November 2015 (11)
- October 2015 (5)
- September 2015 (16)
- August 2015 (4)
- July 2015 (1)
- June 2015 (3)
- May 2015 (6)
- April 2015 (5)
- March 2015 (5)
- February 2015 (4)
- January 2015 (3)
- December 2014 (7)
- October 2014 (4)
- September 2014 (6)
- August 2014 (6)
- July 2014 (16)
- June 2014 (7)
- May 2014 (6)
- April 2014 (5)
- March 2014 (4)
- February 2014 (10)
- January 2014 (6)
- December 2013 (8)
- November 2013 (12)
- October 2013 (9)
- September 2013 (6)
- August 2013 (7)
- July 2013 (9)
- June 2013 (7)
- May 2013 (7)
- April 2013 (4)
- March 2013 (7)
- February 2013 (4)
- January 2013 (4)
- December 2012 (6)
- November 2012 (8)
- October 2012 (9)
- September 2012 (3)
- August 2012 (5)
- July 2012 (5)
- June 2012 (7)
- May 2012 (11)
- April 2012 (1)
- March 2012 (8)
- February 2012 (1)
- January 2012 (6)
- December 2011 (8)
- November 2011 (5)
- October 2011 (9)
- September 2011 (6)
- August 2011 (4)
- July 2011 (1)
- June 2011 (1)
- May 2011 (5)
- April 2011 (2)
- February 2011 (2)
- January 2011 (2)
- December 2010 (1)
- November 2010 (7)
- October 2010 (3)
- September 2010 (8)
- August 2010 (2)
- July 2010 (4)
- June 2010 (7)
- May 2010 (2)
- April 2010 (1)
- March 2010 (3)
- February 2010 (3)
- January 2010 (2)
- November 2009 (6)
- October 2009 (6)
- August 2009 (3)
- July 2009 (3)
- June 2009 (3)
- May 2009 (2)
- April 2009 (8)
- March 2009 (6)
- February 2009 (4)
- January 2009 (3)
- November 2008 (3)
- October 2008 (7)
- September 2008 (6)
- August 2008 (9)
- July 2008 (9)
- June 2008 (9)
- May 2008 (9)
- April 2008 (8)
- March 2008 (4)
- February 2008 (3)
- January 2008 (3)
- December 2007 (2)
- November 2007 (7)
- October 2007 (1)
- August 2007 (4)
- July 2007 (3)
- June 2007 (8)
- May 2007 (4)
- April 2007 (2)
- March 2007 (2)
- February 2007 (5)
- January 2007 (8)
- December 2006 (1)
- November 2006 (3)
- October 2006 (4)
- September 2006 (3)
- July 2006 (1)
- May 2006 (2)
- April 2006 (1)
- July 2005 (1)
No Comments Yet
Let us know what you think