Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
Original file line number Diff line number Diff line change
Expand Up @@ -88,5 +88,40 @@ public async Task Delete(int id)
cmd.Parameters.AddWithValue("id", id);
await sqlCmd.ExecuteNonQuery(cmd);
}

// GET api/Product/Report1
[HttpGet("Report1")]
public async Task Report1()
{
await sqlQuery.Stream(
@"select Color as [key],
AVG( Price ) as value
from Product
group by Color
FOR JSON PATH", Response.Body, "[]");
}

// GET api/Product/Report2
[HttpGet("Report2")]
public async Task Report2()
{
await sqlQuery.Stream(@"
select Color as x,
AVG (Price) / MAX(Price) as y
from Product
group by Color
FOR JSON PATH", Response.Body, "[]");
}

[HttpGet("Report3")]
public async Task Report3()
{
await sqlQuery.Stream(@"
select Color as x,
AVG (Price) / MAX(Price) as y
from Product
group by Color
FOR JSON PATH", Response.Body, "[]");
}
}
}
Original file line number Diff line number Diff line change
Expand Up @@ -19,6 +19,24 @@ group by JSON_VALUE(Data, '$.Type'), Color
having JSON_VALUE(Data, '$.Type') is not null
order by JSON_VALUE(Data, '$.Type')

-- Indexing JSON data
drop index if exists json_index on Product

alter table product
add Type AS JSON_VALUE(Data, '$.Type'),
ManufacturingCost AS cast(JSON_VALUE(Data, '$.ManufacturingCost') as float)

create index json_index on Product(Type, Color)
include (ManufacturingCost)

--Query uses index on JSON and relational columns
select JSON_VALUE(Data, '$.Type') as Type, Color,
AVG( cast(JSON_VALUE(Data, '$.ManufacturingCost') as float) ) as Cost
from Product
group by JSON_VALUE(Data, '$.Type'), Color
having JSON_VALUE(Data, '$.Type') is not null
order by JSON_VALUE(Data, '$.Type')

--Update JSON Data
--Current values in row:
select Data,Tags
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -29,7 +29,7 @@ SET IDENTITY_INSERT Product ON
GO

DECLARE @products NVARCHAR(MAX) =
N'[{"ProductID":15,"Name":"Adjustable Race","Color":"Magenta","Size":"62","Price":100.0000,"Quantity":75,"Data":{"Type":"Part","MadeIn":"China"}},{"ProductID":16,"Name":"Bearing Ball","Color":"Magenta","Size":"62","Price":15.9900,"Quantity":90,"Data":{"ManufacturingCost":11.672700,"Type":"Part","MadeIn":"China"},"Tags":["promo"]},{"ProductID":17,"Name":"BB Ball Bearing","Color":"Magenta","Size":"62","Price":28.9900,"Quantity":80,"Data":{"ManufacturingCost":21.162700,"Type":"Part","MadeIn":"China"}},{"ProductID":18,"Name":"Blade","Color":"Magenta","Size":"62","Price":18.0000,"Quantity":45,"Data":{},"Tags":["new"]},{"ProductID":19,"Name":"Sport-100 Helmet, Red","Color":"Red","Size":"72","Price":41.9900,"Quantity":38,"Data":{"ManufacturingCost":30.652700,"Type":"Еquipment","MadeIn":"China"},"Tags":["promo"]},{"ProductID":20,"Name":"Sport-100 Helmet, Black","Color":"Black","Size":"72","Price":31.4900,"Quantity":60,"Data":{"ManufacturingCost":22.987700,"Type":"Еquipment","MadeIn":"China"},"Tags":["new","promo"]},{"ProductID":21,"Name":"Mountain Bike Socks, M","Color":"White","Size":"M","Price":560.9900,"Quantity":30,"Data":{"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":22,"Name":"Mountain Bike Socks, L","Color":"White","Size":"L","Price":120.9900,"Quantity":20,"Data":{"ManufacturingCost":88.322700,"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":23,"Name":"Long-Sleeve Logo Jersey, XL","Color":"Multi","Size":"XL","Price":44.9900,"Quantity":60,"Data":{"ManufacturingCost":32.842700,"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":24,"Name":"Road-650 Black, 52","Color":"Black","Size":"52","Price":704.6900,"Quantity":70,"Data":{"Type":"Bike","MadeIn":"UK"}},{"ProductID":25,"Name":"Mountain-100 Silver, 38","Color":"Silver","Size":"38","Price":359.9900,"Quantity":45,"Data":{"ManufacturingCost":262.792700,"Type":"Bike","MadeIn":"UK"},"Tags":["promo"]},{"ProductID":26,"Name":"Road-250 Black, 48","Color":"Black","Size":"48","Price":299.0200,"Quantity":25,"Data":{"ManufacturingCost":218.284600,"Type":"Bike","MadeIn":"UK"},"Tags":["new","promo"]},{"ProductID":27,"Name":"ML Bottom Bracket","Price":101.2400,"Quantity":50,"Data":{"Type":"Part","MadeIn":"China"}},{"ProductID":28,"Name":"HL Bottom Bracket","Price":121.4900,"Quantity":65,"Data":{"ManufacturingCost":88.687700,"Type":"Part","MadeIn":"China"}}]'
N'[{"ProductID":15,"Name":"Adjustable Race","Color":"Magenta","Size":"62","Price":100.0000,"Quantity":75,"Data":{"Type":"Part","MadeIn":"China"}},{"ProductID":16,"Name":"Bearing Ball","Color":"Magenta","Size":"62","Price":15.9900,"Quantity":90,"Data":{"ManufacturingCost":11.672700,"Type":"Part","MadeIn":"China"},"Tags":["promo"]},{"ProductID":17,"Name":"BB Ball Bearing","Color":"Magenta","Size":"62","Price":28.9900,"Quantity":80,"Data":{"ManufacturingCost":21.162700,"Type":"Part","MadeIn":"China"}},{"ProductID":18,"Name":"Blade","Color":"Magenta","Size":"62","Price":18.0000,"Quantity":45,"Data":{},"Tags":["new"]},{"ProductID":19,"Name":"Sport-100 Helmet, Red","Color":"Red","Size":"72","Price":41.9900,"Quantity":38,"Data":{"ManufacturingCost":30.652700,"Type":"Еquipment","MadeIn":"China"},"Tags":["promo"]},{"ProductID":20,"Name":"Sport-100 Helmet, Black","Color":"Black","Size":"72","Price":31.4900,"Quantity":60,"Data":{"ManufacturingCost":22.987700,"Type":"Еquipment","MadeIn":"China"},"Tags":["new","promo"]},{"ProductID":21,"Name":"Mountain Bike Socks, M","Color":"White","Size":"M","Price":560.9900,"Quantity":30,"Data":{"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":22,"Name":"Mountain Bike Socks, L","Color":"White","Size":"L","Price":120.9900,"Quantity":20,"Data":{"ManufacturingCost":88.322700,"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":23,"Name":"Long-Sleeve Logo Jersey, XL","Color":"Multi","Size":"XL","Price":44.9900,"Quantity":60,"Data":{"ManufacturingCost":32.842700,"Type":"Clothes"},"Tags":["sales","promo"]},{"ProductID":24,"Name":"Road-650 Black, 52","Color":"Black","Size":"52","Price":704.6900,"Quantity":70,"Data":{"Type":"Bike","MadeIn":"UK","Tyres":["300c","35C"],"Weight":9.5,"Gender":"M"}},{"ProductID":25,"Name":"Mountain-100 Silver, 38","Color":"Silver","Size":"38","Price":359.9900,"Quantity":45,"Data":{"ManufacturingCost":262.792700,"Type":"Bike","MadeIn":"UK","Gears":20,"Weight":9.5,"Gender":"M"},"Tags":["promo"]},{"ProductID":26,"Name":"Road-250 Black, 48","Color":"Black","Size":"48","Price":299.0200,"Quantity":25,"Data":{"ManufacturingCost":218.284600,"Type":"Bike","MadeIn":"UK"},"Tags":["new","promo"]},{"ProductID":27,"Name":"ML Bottom Bracket","Price":101.2400,"Quantity":50,"Data":{"Type":"Part","MadeIn":"China"}},{"ProductID":28,"Name":"HL Bottom Bracket","Price":121.4900,"Quantity":65,"Data":{"ManufacturingCost":88.687700,"Type":"Part","MadeIn":"China"}},{"ProductID":29,"Name":"Sport Helmet","Color":"Black","Size":"72","Price":55.9900,"Quantity":20,"Data":{"Visor":true, "WxDxH": [32,26.4,22]},"Tags":["promo"]},{"ProductID":30,"Name":"Hybrid Car XLV","Color":"Silver","Price":29500.0000,"Quantity":5,"Data":{"Type":"Car","Doors":4,"Seats":5,"MPG":29}},{"ProductID":31,"Name":"Car, Hybrid (OM)","Color":"White","Price":35000.0000,"Quantity":2,"Data":{"Type":"Car","Doors":2,"Seats":2,"MPG":35},"Tags":["promo"]}]'
INSERT INTO Product (ProductID, Name, Color, Size, Price, Quantity, Data, Tags)
SELECT ProductID, Name, Color, Size, Price, Quantity, Data, Tags
FROM OPENJSON (@products) WITH(
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,52 @@
<!DOCTYPE html>
<html>
<head>
<script src="/media/js/jquery.js"></script>
<script src="/media/js/d3/d3.v4.min.js"></script>
<script src="/media/js/d3/pie.js"></script>
<script src="/media/js/d3/barChart.js"></script>
<style>
.bar {
fill: steelblue;
}
.bar:hover {
fill: brown;
}
</style>
</head>
<body>

<h1>Dashboard</h1>

<svg id="pie" width="600" height="400"></svg>

<svg id="chart" width="600" height="400"></svg>

<svg id="chart2" width="600" height="400"></svg>

<script>

$(function () {

$.getJSON("/api/Product/Report1")
.done(function (data) {
var c = new Pie("svg#pie", { "innerRadius": 100 });
c.Data(data);
});

$.getJSON("/api/Product/Report2")
.done(function (data) {
var c = new BarChart("svg#chart", { "innerRadius": 100 });
c.Data(data);
});

$.getJSON("/api/Product/Report3")
.done(function (data) {
var c = new BarChart("svg#chart2", { "innerRadius": 20 });
c.Data(data);
});

});
</script>
</body>
</html>
Binary file not shown.
Binary file not shown.
Original file line number Diff line number Diff line change
@@ -0,0 +1,59 @@
/*
* D3 BarChart Control.
* Encapsulated example from: https://bl.ocks.org/mbostock/3885304
* Licence: GNU General Public License, version 3
* Authors: Mike Bostock, Jovan Popovic
**************************************************************************/

var BarChart = function(target, options) {

options = options || {};
this.options = options;

var svg = d3.select(target),
margin = options.margin || {top: 20, right: 20, bottom: 30, left: 40},
width = (options.width||0)+svg.attr("width") - margin.left - margin.right,
height = (options.height||0)+svg.attr("height") - margin.top - margin.bottom;

var x = d3.scaleBand().rangeRound([0, width]).padding(0.1),
y = d3.scaleLinear().rangeRound([height, 0]);

var g = svg.append("g")
.attr("transform", "translate(" + margin.left + "," + margin.top + ")");


this.Data = function(data) {

x.domain(data.map(function(d) { return d.x; }));
y.domain([0, d3.max(data, function(d) { return d.y; })]);

g.append("g")
.attr("class", "axis axis--x")
.attr("transform", "translate(0," + height + ")")
.call(d3.axisBottom(x));

g.append("g")
.attr("class", "axis axis--y")
.call(d3.axisLeft(y).ticks(10, "%"))
.append("text")
.attr("transform", "rotate(-90)")
.attr("y", 6)
.attr("dy", "0.71em")
.attr("text-anchor", "end")
.text("Frequency");

g.selectAll(".bar")
.data(data)
.enter().append("rect")
.attr("class", "bar")
.attr("x", function(d) { return x(d.x); })
.attr("y", function(d) { return y(d.y); })
.attr("width", x.bandwidth())
.attr("height", function(d) { return height - y(d.y); });
}

};




Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
@@ -0,0 +1,51 @@
/*
* D3 PieChart Control.
* Encapsulated example from: https://bl.ocks.org/mbostock/3887235
* Licence: GNU General Public License, version 3
* Authors: Mike Bostock, Jovan Popovic
**************************************************************************/

var Pie = function(target, options) {

options = options || {};
this.options = options;
var _fnGetDate = options.date || function(d) { return d.Date; };
var _fnGetValue = options.value || function(d) { return d[0].Value; };

var svg = d3.select(target),
width = options.width||0+svg.attr("width"),
height = options.height||0+svg.attr("height"),
radius = Math.min(width, height) / 2,
g = svg.append("g").attr("transform", "translate(" + width / 2 + "," + height / 2 + ")");

var color = d3.scaleOrdinal(options.colors || ["#98abc5", "#8a89a6", "#7b6888", "#6b486b", "#a05d56", "#d0743c", "#ff8c00"]);

var pie = d3.pie()
.sort(null)
.value(function(d) { return d.value; });

var path = d3.arc()
.outerRadius(radius - 10)
.innerRadius(options.innerRadius || 0);

var label = d3.arc()
.outerRadius(radius - 40)
.innerRadius(radius - 40);

this.Data = function(data) {
var arc = g.selectAll(".arc")
.data(pie(data))
.enter().append("g")
.attr("class", "arc");

arc.append("path")
.attr("d", path)
.attr("fill", function(d) { return color(d.data.key); });

arc.append("text")
.attr("transform", function(d) { return "translate(" + label.centroid(d) + ")"; })
.attr("dy", "0.35em")
.text(function(d) { return d.data.key; });
}

};
Original file line number Diff line number Diff line change
@@ -0,0 +1,6 @@
.vs/*
node_modules/*
bin/*.dll
obj/*
*.sln
*.log
Original file line number Diff line number Diff line change
@@ -0,0 +1,21 @@
{
// Use IntelliSense to learn about possible Node.js debug attributes.
// Hover to view descriptions of existing attributes.
// For more information, visit: https://go.microsoft.com/fwlink/?linkid=830387
"version": "0.2.0",
"configurations": [
{
"type": "node",
"request": "launch",
"name": "Launch Program",
"program": "${workspaceRoot}\\bin\\www"
},
{
"type": "node",
"request": "attach",
"name": "Attach to Port",
"address": "localhost",
"port": 5858
}
]
}
Original file line number Diff line number Diff line change
@@ -0,0 +1,92 @@
# Node.js Product Catalog application that uses SQL/JSON functionalities

This project contains an example implementation of Node.js application that shows how to display list of products, add, edit, or delete products in the list.

## Contents

[About this sample](#about-this-sample)<br/>
[Before you begin](#before-you-begin)<br/>
[Run this sample](#run-this-sample)<br/>
[Sample details](#sample-details)<br/>
[Disclaimers](#disclaimers)<br/>
[Related links](#related-links)<br/>

<a name=about-this-sample></a>

## About this sample

- **Applies to:** SQL Server 2016 (or higher), Azure SQL Database
- **Key features:** JSON functions in SQL Server 2016/Azure SQL Database
- **Programming Language:** Html/JavaScript/Node.js, Transact-SQL
- **Authors:** Jovan Popovic

<a name=before-you-begin></a>

## Before you begin

To run this sample, you need the following prerequisites.

**Software prerequisites:**

1. SQL Server 2016 (or higher) or an Azure SQL Database
2. Node.js installation

**Azure prerequisites:**

1. Permission to create an Azure SQL Database

<a name=run-this-sample></a>

## Run this sample

1. Create a database on SQL Server 2016 or Azure SQL Database and set compatibility level to 130.

2. From SQL Server Management Studio or Sql Server Data Tools connect to your SQL Server 2016 or Azure SQL database and execute [sql-scripts/setup.sql](sql-scripts/setup.sql) script that will create and populate Product table and create required stored procedures.

3. From command line run **npm update** to update node.js packages.

4. Setup connection information db.js

5. Build and run sample using **npm build** and **npm run**.

6. Run the sample app using F5 or Ctrl+F5 in Visual Studio 2015, or using **dotnet run** executed in the command prompt of the project root folder.
1. Open http://localhost:3000/index.html to get all products from database,
2. Use **Add** button to add a new product,
3. Edit a product using **Edit** button in table,
4. Delete a product using **Delete** button in table,

<a name=sample-details></a>

## Sample details

This sample application shows how to display list of products, add, edit or delete some product.
Front-end code is implemented using JQuery/Bootstrap libraries, and JQuery DataTable component for displaying data in table.
Server-side code is implemented using Node.js Express4 REST API.
SQL Server JSON functions are used to format product data that will be sent to front-end page.

<a name=disclaimers></a>

## Disclaimers
The code included in this sample is not intended demonstrate some general guidance and architectural patterns for web development. It contains minimal code required to create REST API.
You can easily modify this code to fit the architecture of your application.

<a name=related-links></a>

## Related Links

You can find more information about the components that are used in this sample on these locations:
- [JSON Support in Sql Server](https://msdn.microsoft.com/en-us/library/dn921897.aspx).
- [JQuery](https://jquery.com/).
- [Bootstrap](http://getbootstrap.com/).
- [JQuery DataTables](https://datatables.net/).
- [JQuery SerializeJson](https://github.com/marioizquierdo/jquery.serializeJSON/).
- [Toastr](http://codeseven.github.io/toastr/).

## Code of Conduct
This project has adopted the [Microsoft Open Source Code of Conduct](https://opensource.microsoft.com/codeofconduct/). For more information see the [Code of Conduct FAQ](https://opensource.microsoft.com/codeofconduct/faq/) or contact [opencode@microsoft.com](mailto:opencode@microsoft.com) with any additional questions or comments.

## License
These samples and templates are all licensed under the MIT license. See the license.txt file in the root.

## Questions
Email questions to: [sqlserversamples@microsoft.com](mailto: sqlserversamples@microsoft.com).
Original file line number Diff line number Diff line change
@@ -0,0 +1,22 @@
var express = require('express');
var bodyParser = require('body-parser');

var app = express();
app.use(express.static('wwwroot'));
//app.use(bodyParser.json());
app.use(bodyParser.text({ type: 'application/json' }))
app.use('/api/Product', require('./routes/products'));

// catch 404 and forward to error handler
app.use(function (req, res, next) {
var err = new Error('Not Found' + req.originalUrl);
err.status = 404;
next(err);
});
app.set('port', process.env.PORT || 3000);

var server = app.listen(app.get('port'), function() {
console.log('Express server listening on port ' + server.address().port);
});

module.exports = app;
Original file line number Diff line number Diff line change
@@ -0,0 +1,3 @@
#!/usr/bin/env node
var debug = require('debug')('nodejs_express4_rest_api');
var app = require('../app');
Loading