Archive for February, 2015
i-Blazon Prime
I replaced my OtterBox Defender with an i-Blazon Prime case when upgrading to the iPhone 6. It appeared a good option, and for 4 months it was fine. Yesterday, the latch broke and my iPhone fell to the ground as a walked. Fortunately, my iPhone landed flat, the i-Blazon plastic case absorbed the impact, and my iPhone was undamaged.
Here’s a photograph of the damaged case:
While I wanted to order only the belt portion of the case, that’s not possible like it is with the OtterBox Defender. So, I ordered a new i-Blazon. My plan is to monitor the belt case. If it cracks again, I’ll protect the telephone and I’ll know to move back to the OtterBox Defender.
SQL Server XQuery
I promised my students an example of writing xquery statements in Microsoft SQL Server. This post builds on two earlier posts. The first qualifies how to build a marvel
table with source data, and the second qualifies how you can create an XML Schema Collection and insert relational data into an XML structure.
You can query a sequence with xquery as follows:
DECLARE @x xml; SET @x = N''; SELECT @x.query('(1,2,(10,11,12,13,14,15)),-6'); |
It returns:
1 2 10 11 12 13 14 15 -6 |
You can query a sequence with an xquery FLOWR
statement. FLOWR
stands for: FOR
, LET
, ORDER BY
, WHERE
, and RETURN
. A sample xquery with a FLOWER
statement is:
DECLARE @x xml; SET @x = N''; SELECT @x.query('for $i in ((1,2,(10,11,12,13,14,15)),-6) order by $i return $i'); |
It returns:
-6 1 2 10 11 12 13 14 15 |
You can query the entire node tree with the following xquery statement because it looks for the occurrence of any node with the /*
search string:
DECLARE @x xml; SET @x = N'<marvel> <avenger_name>Captain America</avenger_name> </marvel>'; SELECT @x.query('/*'); |
You can query the avenger_name
elements from the marvel_xml
table with the following syntax:
SELECT xml_table.query('/marvel/avenger_name') FROM marvel_xml; |
It returns the following set of avenger_name
elements:
<avenger_name>Hulk</avenger_name> <avenger_name>Iron Man</avenger_name> <avenger_name>Black Widow</avenger_name> <avenger_name>Thor</avenger_name> <avenger_name>Captain America</avenger_name> <avenger_name>Hawkeye</avenger_name> <avenger_name>Winter Soldier</avenger_name> <avenger_name>Iron Patriot</avenger_name> |
You can query the fourth avenger_name
element from the marvel_xml
table with the following xquery statement:
SELECT xml_table.query('/marvel[4]/avenger_name') FROM marvel_xml; |
It returns the following avenger_name
element:
<avenger_name>Thor</avenger_name> |
You can use the value()
function to verify an avenger_name
element exists:
SELECT CASE WHEN xml_table.value('(/marvel[4]/avenger_name)','nvarchar') = 'T' THEN 'Exists' END AS "Verified" FROM marvel_xml WHERE id = 3; |
The query returns the Exists
string when it finds a valid avenger_name
element. You have a number of other tools to query results sets from the XML node tree.
I hope this helps my students and anybody interested in writing xquery-enable queries.
Insert into XML Column
Working through Chapter 7 of the Querying Microsoft SQL Server 2012 book for Microsoft’s Exam 70-461, I found the XML examples incomplete for my students. I decided to put together a post on how to create:
- An XML Schema Collection type.
- A table that uses an XML Schema Collection as a column’s data type.
- An example on how you can transfer the contents of a table into the XML Schema Collection.
This post assumes you understand the basics about XML structures. If you’re unfamiliar with XML, please note that everything within it is case sensitive unlike SQL. You raise exceptions when the case of your XML fails to match the case of your XML Schema Collection definitions. I raised the following exception by using a Marvel
element tag in title case when the XML Schema Collection uses a lowercase marvel
element tag:
Msg 6913, Level 16, State 1, Line 2 XML Validation: Declaration not found for element 'Marvel'. Location: /*:Marvel[1] |
The basic marvel
table is defined in this earlier blog post. To ensure you don’t run into conflicts with previously existing objects, you can delete the marvel table with the following syntax:
1 2 | IF OBJECT_ID('studentdb.marvel_xml','U') IS NOT NULL DROP TABLE marvel_xml; |
There is no predefined function that lets you conditionally drop the XML Schema Collection from the data base. The alternative is to query the Microsoft SQL Server data catalog for the existence of a row before dropping the XML Schema Collection, like this:
1 2 3 4 | IF EXISTS (SELECT * FROM sys.xml_schema_collections WHERE name = 'MarvelXMLTable') DROP XML SCHEMA COLLECTION MarvelXMLTable; ELSE SELECT 'Not found.'; |
You can now create the MarvelXMLTable
XML Schema Collection with the following syntax:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 | CREATE XML SCHEMA COLLECTION MarvelXMLTable AS N'<?xml version="1.0" encoding="UTF-16"?> <xsd:schema xmlns:xsd="http://www.w3.org/2001/XMLSchema" xmlns:sqltypes="http://schemas.microsoft.com/sqlserver/2004/sqltypes"> <xsd:import namespace="http://schemas.microsoft.com/sqlserver/2004/sqltypes" schemaLocation="http://schemas.microsoft.com/sqlserver/2004/sqltypes/sqltypes.xsd" /> <xsd:element name="Marvel"> <xsd:complexType> <xsd:sequence> <xsd:element name="marvel_id" type="sqltypes:int" /> <xsd:element name="avenger_name" type="sqltypes:nvarchar" /> <xsd:element name="first_name" type="sqltypes:nvarchar" /> <xsd:element name="last_name" type="sqltypes:nvarchar" /> </xsd:sequence> </xsd:complexType> </xsd:element> </xsd:schema>'; |
After creating the XML Schema Collection, you can confirm whether it works correctly with the following statements. It will fail when you use semicolons on the DECLARE
or SET
lines, so avoid them as shown below:
1 2 3 4 5 6 7 8 | DECLARE @marvel AS XML(MarvelXMLTable) SET @marvel = '<marvel> <marvel_id>1</marvel_id> <avenger_name>Falcon</avenger_name> <first_name>Sam</first_name> <last_name>Wilson</last_name> </marvel>' SELECT @marvel; |
After creating and verifying the integrity of the XML Schema Collection, you can create a marvel_xml
table. The xml_table
column of the marvel_xml
table uses a strongly-typed XML type, as shown:
1 2 3 | CREATE TABLE marvel_xml ( id INT IDENTITY(1,1) CONSTRAINT marvel_xml_pk PRIMARY KEY , xml_table XML(MarvelXMLTable)); |
You can write an INSERT
statement with single element like this:
1 2 3 4 5 6 7 8 9 | INSERT INTO marvel_xml ( xml_table ) VALUES ('<Marvel> <marvel_id>9</marvel_id> <avenger_name>Falcon</avenger_name> <first_name>Sam</first_name> <last_name>Wilson</last_name> </Marvel>'); |
You can insert two elements with an INSERT
statement like this:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 | INSERT INTO marvel_xml ( xml_table ) VALUES ('<Marvel> <marvel_id>9</marvel_id> <avenger_name>Falcon</avenger_name> <first_name>Sam</first_name> <last_name>Wilson</last_name> </Marvel> <Marvel> <marvel_id>10</marvel_id> <avenger_name>Scarlet Witch</avenger_name> <first_name>Wanda</first_name> <last_name>Witch</last_name> </Marvel>'); |
There’s a lot of typing to insert XML literal values. It a lot easier to transfer relational data from a table to an XML type. Unfortunately, Microsoft didn’t make it very easy. The FOR XML AUTO
doesn’t work for two reasons. First, the FOR XML AUTO
clause doesn’t render the correct XML structure. Second, the INSERT
statement disallows nested SELECT
queries that include the FOR XML AUTO
clause.
Here’s the way you insert relational data into an XML type column:
1 2 3 4 5 6 7 8 9 10 11 12 13 | DECLARE @xml_elements NVARCHAR(MAX); SET @xml_elements = N''; WITH x AS (SELECT CONCAT(N'<marvel>' ,N'<marvel_id>',marvel_id,N'</marvel_id>' ,N'<avenger_name>',avenger_name,N'</avenger_name>' ,N'<first_name>',first_name,N'</first_name>' ,N'<last_name>',last_name,N'</last_name>' ,N'</marvel>') AS element FROM marvel) SELECT @xml_elements += element FROM x; INSERT INTO marvel_xml (xml_table) VALUES (@xml_elements); |
Line 1 declares an xml_element
session variable. Line 2 initializes the xml_element
session variable as an empty string. The WITH
clause on lines 3 through 10 creates a Common Table Expression (CTE) with the valid XML structure for all rows in the marvel table. The nested SELECT
statement on line 11 returns data from the CTE and adds returned row to the session-level string variable. Finally, the INSERT
statement on lines 12 and 13 inserts the XML table into the xml_table column.
You can then query the table with the following statement:
SELECT xml_table FROM marvel_xml; |
Click on the return type in the SQL Server Management Studio (SSMS), and the XML structure will expand to show this:
<marvel> <marvel_id>1</marvel_id> <avenger_name>Hulk</avenger_name> <first_name>Bruce</first_name> <last_name>Banner</last_name> </marvel> <marvel> <marvel_id>2</marvel_id> <avenger_name>Iron Man</avenger_name> <first_name>Tony</first_name> <last_name>Stark</last_name> </marvel> <marvel> <marvel_id>3</marvel_id> <avenger_name>Black Widow</avenger_name> <first_name>Natasha</first_name> <last_name>Romanoff</last_name> </marvel> <marvel> <marvel_id>4</marvel_id> <avenger_name>Thor</avenger_name> <first_name>Thor</first_name> <last_name>Odinsson</last_name> </marvel> <marvel> <marvel_id>5</marvel_id> <avenger_name>Captain America</avenger_name> <first_name>Steve</first_name> <last_name>Rogers</last_name> </marvel> <marvel> <marvel_id>6</marvel_id> <avenger_name>Hawkeye</avenger_name> <first_name>Clint</first_name> <last_name>Barton</last_name> </marvel> <marvel> <marvel_id>7</marvel_id> <avenger_name>Winter Soldier</avenger_name> <first_name>Bucky</first_name> <last_name>Barnes</last_name> </marvel> <marvel> <marvel_id>8</marvel_id> <avenger_name>Iron Patriot</avenger_name> <first_name>James</first_name> <last_name>Rhodey</last_name> </marvel> |
As always, I hope this post benefits those who read it.
Functions disallow NDS
My students asked if you could embed an OFFSET x ROWS FETCH NEXT y ROWS ONLY
clause in a SQL Server T-SQL user-defined function. The answer is no, it isn’t Oracle (yes, you can do that in Oracle Database 12c with an NDS statement). There’s an example in Chapter 2 of my Oracle Database 12c PL/SQL Programming book if you’re interested. I also demonstrate a different approach to SQL Server T-SQL table functions in this older post. However, an attempt to add the clause to a SQL Server T-SQL function, like this:
CREATE FUNCTION studentdb.getBatch (@rows AS INT ,@offset AS INT) RETURNS @output TABLE ( marvel_id INT , avenger_name VARCHAR(30) , first_name VARCHAR(20) , last_name VARCHAR(20)) AS BEGIN /* Insert the results into the table variable. */ INSERT @output SELECT marvel_id , avenger_name , first_name , last_name FROM studentdb.marvel OFFSET (@offset - 1) ROWS FETCH NEXT @rows ROWS ONLY; /* Return the table variable from the function. */ RETURN; END; |
Throws the following errors trying to compile the function:
Msg 102, Level 15, State 1, Procedure getBatch, Line 16 Incorrect syntax near '@offset'. Msg 153, Level 15, State 2, Procedure getBatch, Line 16 Invalid usage of the option NEXT in the FETCH statement. |
If you have a strong background in Oracle and can sort through the dynamic SQL syntax for T-SQL, you might try re-writing the function to use the EXEC SP_EXECUTESQL @var;
command. That rewrite that attempts to use NDS (Native Dynamic SQL) would look like this:
CREATE FUNCTION studentdb.getBatch (@rows AS INT ,@offset AS INT) RETURNS @output TABLE ( marvel_id INT , avenger_name VARCHAR(30) , first_name VARCHAR(20) , last_name VARCHAR(20)) AS BEGIN DECLARE /* Declare a variable for a dynamic SQL statement. */ @stmt VARCHAR(400); /* Assign the SQL statement to a variable. */ SET @stmt = N'SELECT marvel_id ' + N', avenger_name ' + N', first_name ' + N', last_name ' + N'FROM studentdb.marvel ' + N'OFFSET ' + (@offset - 1) + N' ' + N'ROWS FETCH NEXT ' + @rows + N' ROWS ONLY;'; BEGIN /* Insert the results into the table variable. */ INSERT @output EXEC sp_executesql @stmt; END; /* Return the table variable from the function. */ RETURN; END; |
Throws the following exception because you can’t use dynamic dispatch inside a T-SQL function:
Msg 443, Level 16, State 14, Procedure getBatch, Line 23 Invalid use of a side-effecting operator 'INSERT EXEC' within a function. |
On the other hand you can rewrite the statement with a BETWEEN
operator and it works somewhat like an OFFSET
and FETCH
operation. That refactored function would be written as follows:
CREATE FUNCTION studentdb.getBatch (@rowa AS INT ,@rowb AS INT) RETURNS @output TABLE ( marvel_id INT , avenger_name VARCHAR(30) , first_name VARCHAR(20) , last_name VARCHAR(20)) AS BEGIN /* Insert the results into the table variable. */ INSERT @output SELECT marvel_id , avenger_name , first_name , last_name FROM studentdb.marvel WHERE marvel_id BETWEEN @rowa AND @rowb; /* Return the table variable from the function. */ RETURN; END; |
It doesn’t raise an exception. You can call the table function like this:
SELECT * FROM getBatch(2,3); |
It returns the two rows for Iron Man and Black Widow. As always, I hope this helps.
If you want to create the test case, here’s the script you need:
SELECT 'Conditionally drop studentdb.marvel table.' AS "Statement"; IF OBJECT_ID('studentdb.marvel','U') IS NOT NULL DROP TABLE studentdb.marvel; SELECT 'Create studentdb.marvel table.' AS "Statement"; CREATE TABLE studentdb.marvel ( marvel_id INT NOT NULL IDENTITY(1,1) CONSTRAINT marvel_pk PRIMARY KEY , avenger_name VARCHAR(30) NOT NULL , first_name VARCHAR(20) NOT NULL , last_name VARCHAR(20) NOT NULL); /* Insert the rows. */ INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Hulk','Bruce','Banner'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Iron Man','Tony','Stark'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Black Widow','Natasha','Romanoff'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Thor','Thor','Odinsson'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Captain America','Steve','Rogers'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Hawkeye','Clint','Barton'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Winter Soldier','Bucky','Barnes'); INSERT INTO studentdb.marvel (avenger_name, first_name, last_name) VALUES ('Iron Patriot','James','Rhodey'); /* Query the contents of the MARVEL table. */ SELECT * FROM studentdb.marvel; |
Filtering String Dates
A question came up about how to verify dates from a string without throwing a casting error because of a non-conforming date. You can throw a number of exceptions, and I wrote a function to filter bad string formats like the DD-MON-RR
or DD-MON-YYYY
.
The first one is for a day between 1 and the last day of month, which is:
ORA-01847: day of month must be between 1 and last day of month |
An incorrect string for a month, raises the following error:
ORA-01843: not a valid month |
A date format mask longer than a DD-MON-RR
or DD-MON-YYYY
raises the following exception:
ORA-01830: date format picture ends before converting entire input string |
The verify_date
function checks for non-conforming DD-MON-RR
and DD-MON-YYYY
date masks, and substitutes a SYSDATE
value for a bad date entry:
CREATE OR REPLACE FUNCTION verify_date ( pv_date_in VARCHAR2) RETURN DATE IS /* Local return variable. */ lv_date DATE; BEGIN /* Check for a DD-MON-RR or DD-MON-YYYY string. */ IF REGEXP_LIKE(pv_date_in,'^[0-9]{2,2}-[ADFJMNOS][ACEOPU][BCGLNPRTVY]-([0-9]{2,2}|[0-9]{4,4})$') THEN /* Case statement checks for 28 or 29, 30, or 31 day month. */ CASE /* Valid 31 day month date value. */ WHEN SUBSTR(pv_date_in,4,3) IN ('JAN','MAR','MAY','JUL','AUG','OCT','DEC') AND TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 31 THEN lv_date := pv_date_in; /* Valid 30 day month date value. */ WHEN SUBSTR(pv_date_in,4,3) IN ('APR','JUN','SEP','NOV') AND TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 30 THEN lv_date := pv_date_in; /* Valid 28 or 29 day month date value. */ WHEN SUBSTR(pv_date_in,4,3) = 'FEB' THEN /* Verify 2-digit or 4-digit year. */ IF (LENGTH(pv_date_in) = 9 AND MOD(TO_NUMBER(SUBSTR(pv_date_in,8,2)) + 2000,4) = 0 OR LENGTH(pv_date_in) = 11 AND MOD(TO_NUMBER(SUBSTR(pv_date_in,8,4)),4) = 0) AND TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 29 THEN lv_date := pv_date_in; ELSE /* Not a leap year. */ IF TO_NUMBER(SUBSTR(pv_date_in,1,2)) BETWEEN 1 AND 28 THEN lv_date := pv_date_in; ELSE lv_date := SYSDATE; END IF; END IF; ELSE /* Assign a default date. */ lv_date := SYSDATE; END CASE; ELSE /* Assign a default date. */ lv_date := SYSDATE; END IF; /* Return date. */ RETURN lv_date; END; / |
You can check valid dates with a DD-MON-RR
format:
SELECT verify_date('28-FEB-10') AS "Non-Leap Year" , verify_date('29-FEB-12') AS "Leap Year" , verify_date('31-MAR-14') AS "31-Day Year" , verify_date('30-APR-14') AS "30-Day Year" FROM dual; |
You can check valid dates with a DD-MON-YYYY
format:
SELECT verify_date('28-FEB-2010') AS "Non-Leap Year" , verify_date('29-FEB-2012') AS "Leap Year" , verify_date('31-MAR-2014') AS "31-Day Year" , verify_date('30-APR-2014') AS "30-Day Year" FROM dual; |
They both return:
Non-Leap Leap YEAR 31-DAY YEAR 30-DAY YEAR ----------- --------- ----------- ----------- 28-FEB-10 29-FEB-12 31-MAR-14 30-APR-14 |
You can check badly formatted dates with the following query:
SELECT verify_date('28-FEB-2010') AS "Non-Leap Year" , verify_date('29-FEB-2012') AS "Leap Year" , verify_date('31-MAR-2014') AS "31-Day Year" , verify_date('30-APR-2014') AS "30-Day Year" FROM dual; |
You can screen for an alphanumeric string with the following expression:
SELECT 'Valid alphanumeric string literal' AS "Statement" FROM dual WHERE REGEXP_LIKE('Some Mythical String $200','([:alnum:]|[:punct:]|[:space:])*'); |
You can screen for a numeric literal as a string with the following expression:
SELECT 'Valid numeric literal' AS "Statement" FROM dual WHERE REGEXP_LIKE('123.00','([:digit:]|[:punct:])'); |
As always, I hope this helps those who need this type of solution.