前端有可能一次性上传多笔记录,并使用JSON序列化。
现在在MS SQL Server 2016版本上,可以直接处理JSO数据。
如下面的前端序列化的数据:
DECLARE @json_string NVARCHAR(MAX) = N' { "catalog":[ {"ID":23394,"Item":"I32-GG443-QT0098-0001","Category":"S","Qty":423.65}, {"ID":45008,"Item":"I38-AA321-WS0098-0506","Category":"B","Qty":470.87}, {"ID":14350,"Item":"K38-12321-5456UD-3493","Category":"B","Qty":200.28}, {"ID":64582,"Item":"872-RTDE3-Q459PW-2323","Category":"T","Qty":452.44}, {"ID":23545,"Item":"098-SSSS1-WS0098-5526","Category":"S","Qty":500.00}, {"ID":80075,"Item":"B78-F1H2Y-5456UD-2530","Category":"T","Qty":115.06}, {"ID":53567,"Item":"PO0-7G7G7-JJY098-0077","Category":"Q","Qty":871.33}, {"ID":44349,"Item":"54F-ART43-6545NN-2514","Category":"S","Qty":934.39}, {"ID":36574,"Item":"X3C-SDEWE-3ER808-8764","Category":"Q","Qty":607.88}, {"ID":36574,"Item":"RVC-43ASE-H43QWW-9753","Category":"U","Qty":555.19}, {"ID":14350,"Item":"K38-12321-5456UD-3493","Category":"B","Qty":200.28}, {"ID":64582,"Item":"872-RTDE3-Q459PW-2323","Category":"T","Qty":452.44}, {"ID":80075,"Item":"B78-F1H2Y-5456UD-2530","Category":"T","Qty":115.06}, {"ID":53567,"Item":"PO0-7G7G7-JJY098-0077","Category":"Q","Qty":871.33}, {"ID":44349,"Item":"54F-ART43-6545NN-2514","Category":"S","Qty":934.39}, {"ID":44349,"Item":"54F-ART43-6545NN-2514","Category":"S","Qty":934.39}, {"ID":36574,"Item":"X3C-SDEWE-3ER808-8764","Category":"Q","Qty":607.88}] } '
在数据库中,创建一张表来存储这些数据:
CREATE TABLE [dbo].[Parts Catalog] ( [ID] INT, [Item] NVARCHAR(40), [Category] NVARCHAR(25), [Qty] DECIMAL(18,2) ) GO
创建存储过程来接收并处理JSON数据:
CREATE PROCEDURE [dbo].[usp_Parts_Catalog_Insert] ( @json_string NVARCHAR(MAX) ) AS INSERT INTO [dbo].[Parts Catalog]([ID],[Item],[Category],[Qty]) SELECT [ID],[Item],[Category],[Qty] FROM OPENJSON(@json_string,'$.catalog') WITH ( [ID] INT '$.ID', [Item] NVARCHAR(40) '$.Item', [Category] NVARCHAR(25) '$.Category', [Qty] DECIMAL(18,2) '$.Qty' ) GO
执行存储过程,并查询表数据:
以前上传多笔记录,均是使用表函数来处理,现在可以使用OPENJSON方法来进行。