Contains some sample scripts using the JSON sample functions with more
complex JSON examples.

Will need data and more comments in code.
This commit is contained in:
Mike Rys 2016-09-27 17:25:58 -04:00
Родитель 46403f6906
Коммит c2c14d628d
7 изменённых файлов: 324 добавлений и 0 удалений

Просмотреть файл

@ -0,0 +1,34 @@

Microsoft Visual Studio Solution File, Format Version 12.00
# Visual Studio 2013
VisualStudioVersion = 12.0.31101.0
MinimumVisualStudioVersion = 10.0.40219.1
Project("{182E2583-ECAD-465B-BB50-91101D7C24CE}") = "JSONExamples", "JSONExamples\JSONExamples.usqlproj", "{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}"
EndProject
Global
GlobalSection(SolutionConfigurationPlatforms) = preSolution
Debug|Any CPU = Debug|Any CPU
Debug|x64 = Debug|x64
Debug|x86 = Debug|x86
Release|Any CPU = Release|Any CPU
Release|x64 = Release|x64
Release|x86 = Release|x86
EndGlobalSection
GlobalSection(ProjectConfigurationPlatforms) = postSolution
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|Any CPU.ActiveCfg = Debug|Any CPU
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|Any CPU.Build.0 = Debug|Any CPU
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|x64.ActiveCfg = Debug|x64
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|x64.Build.0 = Debug|x64
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|x86.ActiveCfg = Debug|x86
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Debug|x86.Build.0 = Debug|x86
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|Any CPU.ActiveCfg = Release|Any CPU
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|Any CPU.Build.0 = Release|Any CPU
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|x64.ActiveCfg = Release|x64
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|x64.Build.0 = Release|x64
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|x86.ActiveCfg = Release|x86
{A3BBEA95-FD9E-4198-8F5F-D0DE13248E37}.Release|x86.Build.0 = Release|x86
EndGlobalSection
GlobalSection(SolutionProperties) = preSolution
HideSolutionNode = FALSE
EndGlobalSection
EndGlobal

Просмотреть файл

@ -0,0 +1,7 @@
DROP DATABASE IF EXISTS JSONBlog;
CREATE DATABASE JSONBlog;
// Now register the DataFormats and Newtonsoft.Json assemblies in this database.
// Easiest way is to load the solution from https://github.com/Azure/usql/tree/master/Examples/DataFormats, right click on the Microsoft.Analytics.Samples.Formats project and select the Register Assembly menu option.
// See TBD for more details on the registration steps.

Просмотреть файл

@ -0,0 +1,37 @@
REFERENCE ASSEMBLY JSONBlog.[Newtonsoft.Json];
REFERENCE ASSEMBLY JSONBlog.[Microsoft.Analytics.Samples.Formats];
USING Microsoft.Analytics.Samples.Formats.Json;
// Extract schema specifies the properties to extract from JSON document at specified location (in this example at the root of the documents)
@data =
EXTRACT
id string, // id of document
Revision string, // revision number of document
Camera string // data of document (another JSON object)
FROM @"/Samples/Blogs/MRys/JSON/camera.json"
USING new JsonExtractor();
@jsondocs =
SELECT id, Revision, JsonFunctions.JsonTuple(Camera) AS cam
FROM @data;
@camera =
SELECT
id,
Revision,
cam["Manufacturer"] AS make,
cam["Model"] AS model,
cam["Type"] AS type,
cam["Sensor"] AS sensor,
cam["MP"] AS res,
cam["['Image Processor']"] AS image_processor
FROM @jsondocs;
OUTPUT @camera
TO "/output/camera.json"
USING new JsonOutputter();
OUTPUT @camera
TO "/output/json/camera.csv"
USING Outputters.Csv();

Просмотреть файл

@ -0,0 +1,31 @@
/*
[{
"field1": [
"This is ",
"a double "
],
"field2": [
"Field2 ",
"in object 1 "
]
}, {
"field2": [
"field 2 ",
"in object 2"
]
}]
*/
DECLARE @input string = "/Samples/Blogs/MRys/JSON/objectarray.json";
REFERENCE ASSEMBLY JSONBlog.[Newtonsoft.Json];
REFERENCE ASSEMBLY JSONBlog.[Microsoft.Analytics.Samples.Formats];
@data0 =
EXTRACT field2 string
FROM @input
USING new Microsoft.Analytics.Samples.Formats.Json.JsonExtractor("[*]");
OUTPUT @data0 TO "/output/json/objarray.csv" USING Outputters.Csv();

Просмотреть файл

@ -0,0 +1,81 @@
DECLARE @input string = "/Samples/Blogs/MRys/JSON/complex.json";
REFERENCE ASSEMBLY JSONBlog.[Newtonsoft.Json];
REFERENCE ASSEMBLY JSONBlog.[Microsoft.Analytics.Samples.Formats];
USING Microsoft.Analytics.Samples.Formats.Json;
@json =
EXTRACT personid int,
name string,
addresses string
FROM @input
USING new JsonExtractor("[*].person");
@person =
SELECT personid,
name,
JsonFunctions.JsonTuple(addresses, "address")["address"] AS address_array
FROM @json;
@addresses =
SELECT personid,
name,
JsonFunctions.JsonTuple(address) AS address
FROM @person
CROSS APPLY
EXPLODE (JsonFunctions.JsonTuple(address_array).Values) AS A(address);
@result =
SELECT personid,
name,
address["addressid"]AS addressid,
address["street"]AS street,
address["postcode"]AS postcode,
address["city"]AS city
FROM @addresses;
//Output the file to a tool of your choice.
OUTPUT @result
TO "/output/json/persons.csv"
USING Outputters.Csv();
/* [{
"person": {
"personid": 123456,
"name": "Person 1",
"addresses": {
"address": [{
"addressid": "2",
"street": "Street 2",
"postcode": "1234 AB",
"city": "City 1"
}, {
"addressid": "2",
"street": "Street 2",
"postcode": "5678 CD",
"city": "City 2"
}]
}
}
}, {
"person": {
"personid": 798,
"name": "Person 2",
"addresses": {
"address": [{
"addressid": "1",
"street": "Street 1",
"postcode": "1234 AB",
"city": "City 1"
}, {
"addressid": "4",
"street": "Street 7",
"postcode": "98799",
"city": "City 3"
}]
}
}
}]
*/

Просмотреть файл

@ -0,0 +1,102 @@
REFERENCE ASSEMBLY JSONBlog.[Newtonsoft.Json];
REFERENCE ASSEMBLY JSONBlog.[Microsoft.Analytics.Samples.Formats];
USING Microsoft.Analytics.Samples.Formats.Json;
DECLARE @in_single string="/Samples/Blogs/MRys/JSON/{date:yyyy}/{date:MM}/{date:dd}/{*}.json";
DECLARE @in_multiple string="/Samples/Blogs/MRys/JSON/games.json.csv";
DECLARE @out_single string="/output/json/PlayerCountsRaw_S.csv";
DECLARE @out_multiple string="/output/json/PlayerCountsRaw_M.csv";
// if one document in a file
@events2 =
EXTRACT date DateTime,
id string,
timeentry DateTime,
messagetypename string,
componentid string,
environmentid string,
sessionid string,
transactionid string,
level string,
messageobject string,
renderedMessage string
FROM @in_single
USING new JsonExtractor();
@events2 =
SELECT date,
id,
timeentry,
messagetypename,
componentid,
environmentid,
sessionid,
transactionid,
level,
JsonFunctions.JsonTuple(messageobject, "..*") AS msg,
renderedMessage
FROM @events2;
@events2 =
SELECT date,
id,
timeentry,
messagetypename,
componentid,
environmentid,
sessionid,
transactionid,
level,
msg["eventId"] AS eventId,
msg["eventName"] AS eventName,
msg["exception"] AS exception,
msg["messageTemplate"] AS messageTemplate,
msg["properties.0"] AS porperties0,
msg["properties.1"] AS porperties1,
msg["properties.processId"] AS processId,
msg["properties.threadId"] AS threadId,
msg["properties.messageVersion"] AS messageVersion,
String.Join(",", msg.Select(p => String.Format("{0}:{1}", p.Key, p.Value))) AS msg,
renderedMessage
FROM @events2;
OUTPUT @events2
TO @out_single
USING Outputters.Csv();
//////////////////////////////////////////////
// if more than one JSON document in a file
@events =
EXTRACT jsonString string // limited to 128kB
FROM @in_multiple
USING Extractors.Text(delimiter : '\b', quoting : false);
@jsonify = SELECT JsonFunctions.JsonTuple(jsonString, "..*") AS rec FROM @events;
@columnized = SELECT
rec["id"] AS id,
rec["timeentry"] AS timeentry,
rec["messagetypename"] AS messagetypename,
rec["componentid"] AS componentid,
rec["environmentid"] AS environmentid,
rec["sessionid"] AS sessionid,
rec["transactionid"] AS transactionid,
rec["level"] AS level,
rec["messageobject.eventId"] AS eventId,
rec["messageobject.eventName"] AS eventName,
rec["messageobject.exception"] AS exception,
rec["messageobject.messageTemplate"] AS messageTemplate,
rec["messageobject.properties.0"] AS porperties0,
rec["messageobject.properties.1"] AS porperties1,
rec["messageobject.properties.processId"] AS processId,
rec["messageobject.properties.threadId"] AS threadId,
rec["messageobject.properties.messageVersion"] AS messageVersion,
rec["messageobject.renderedMessage"] AS renderedMessage
FROM @jsonify;
OUTPUT @columnized TO @out_multiple USING Outputters.Csv();

Просмотреть файл

@ -0,0 +1,32 @@
<?xml version="1.0" encoding="utf-8"?>
<Project ToolsVersion="4.0" DefaultTargets="Build" xmlns="http://schemas.microsoft.com/developer/msbuild/2003">
<PropertyGroup>
<Configuration Condition=" '$(Configuration)' == '' ">Debug</Configuration>
<Platform Condition=" '$(Platform)' == '' ">AnyCPU</Platform>
<SchemaVersion>2.0</SchemaVersion>
<ProjectGuid>a3bbea95-fd9e-4198-8f5f-d0de13248e37</ProjectGuid>
<OutputType>File</OutputType>
<AssemblyName>Algebra.xml</AssemblyName>
<TargetFrameworkVersion>v4.5</TargetFrameworkVersion>
<Name>JSONExamples</Name>
<RootNamespace>JSONExamples</RootNamespace>
<RuntimeVersion>default</RuntimeVersion>
<OutputStreamPath>C:\LocalRunDataRoot</OutputStreamPath>
</PropertyGroup>
<PropertyGroup Condition=" '$(Configuration)|$(Platform)' == 'Debug|AnyCPU' ">
<DebugSymbols>true</DebugSymbols>
<OutputPath>bin\Debug\</OutputPath>
</PropertyGroup>
<PropertyGroup Condition=" '$(Configuration)|$(Platform)' == 'Release|AnyCPU' ">
<DebugSymbols>false</DebugSymbols>
<OutputPath>bin\Release\</OutputPath>
</PropertyGroup>
<ItemGroup>
<Script Include="1-CreateDB.usql" />
<Script Include="2-IntroExample.usql" />
<Script Include="4-ArrayOfObjects.usql" />
<Script Include="5-ComplexJSON.usql" />
<Script Include="6-SingleJSONvsMultiJSON.usql" />
</ItemGroup>
<Import Project="$(AppData)\Microsoft\DataLake\MsBuild\1.0\Usql.targets" />
</Project>