Labels

admin (1) aix (1) alert (1) always-on (2) Architecture (1) aws (3) Azure (1) backup (3) BI-DWH (10) Binary (3) Boolean (1) C# (1) cache (1) casting (3) cdc (1) certificate (1) checks (1) cloud (3) cluster (1) cmd (7) collation (1) columns (1) compilation (1) configurations (7) Connection-String (2) connections (6) constraint (6) copypaste (2) cpu (2) csv (3) CTE (1) data-types (1) datetime (23) db (547) DB2 (1) deadlock (2) Denali (7) device (6) dotNet (5) dynamicSQL (11) email (5) encoding (1) encryption (4) errors (124) excel (1) ExecutionPlan (10) extended events (1) files (7) FIPS (1) foreign key (1) fragmentation (1) functions (1) GCP (2) gMSA (2) google (2) HADR (1) hashing (3) in-memory (1) index (3) indexedViews (2) insert (3) install (10) IO (1) isql (6) javascript (1) jobs (11) join (2) LDAP (2) LinkedServers (8) Linux (15) log (6) login (1) maintenance (3) mariadb (1) memory (4) merge (3) monitoring (4) MSA (2) mssql (444) mssql2005 (5) mssql2008R2 (20) mssql2012 (2) mysql (36) MySQL Shell (5) network (1) NoSQL (1) null (2) numeric (9) object-oriented (1) offline (1) openssl (1) Operating System (4) oracle (7) ORDBMS (1) ordering (2) Outer Apply (1) Outlook (1) page (1) parameters (2) partition (1) password (1) Performance (103) permissions (10) pivot (3) PLE (1) port (4) PostgreSQL (14) profiler (1) RDS (3) read (1) Replication (12) restore (4) root (1) RPO (1) RTO (1) SAP ASE (48) SAP RS (20) SCC (4) scema (1) script (8) security (10) segment (1) server (1) service broker (2) services (4) settings (75) SQL (74) SSAS (1) SSIS (19) SSL (8) SSMS (4) SSRS (6) storage (1) String (35) sybase (57) telnet (2) tempdb (1) Theory (2) tips (120) tools (3) training (1) transaction (6) trigger (2) Tuple (2) TVP (1) unix (8) users (3) vb.net (4) versioning (1) windows (14) xml (10) XSD (1) zip (1)

Passing a datatable to a Stored Procedure in SQL Server 2008

Table-valued parameters are a new parameter type in SQL Server 2008. 
Table-valued parameters are declared by using user-defined table types.

You can use table-valued parameters to send multiple rows of data to a Transact-SQL statement or a routine, such as a stored procedure or function, without creating a temporary table or many parameters.
Of course you can use table-valued parameters in the SQL code.

----------------------------------------
-- create table type
----------------------------------------
CREATE TYPE dbo.TableVariableTest AS TABLE
(
ID int
)
GO
--Note: You can declare a table-valued parameter also with PKs etc.

----------------------------------------
-- create SP that uses the table type
----------------------------------------
SET ANSI_NULLS ON
GO
SET QUOTED_IDENTIFIER ON
GO
CREATE PROCEDURE dbo.SelectTableVariableTestItai
(
    @TableVar dbo.TableVariableTest READONLY
)
AS
BEGIN
    SET NOCOUNT ON;
    
SELECT * 
FROM dbo.Calendar c
JOIN @TableVar v ON v.ID = c.CalID
END
GO

----------------------------------------
-- test:
----------------------------------------
DECLARE @MyTable TableVariableTest

INSERT INTO @MyTable(ID)
VALUES (392),
(477),
(506)

EXEC SelectTableVariableTestItai @TableVar = @MyTable
go


----------------------------------------
-- in the trace it's look like:
----------------------------------------
declare @p1 dbo.TableVariableTest
insert into @p1 values(392)
insert into @p1 values(477)

exec SelectTableVariableTestItai @TableVar=@p1

----------------------------------------
-- the .net code:
----------------------------------------
public DataTable SelectTableVariableTestItai()
{
    DataTable dt = new DataTable();
    dt.Columns.Add("ID", typeof(int));
    DataRow row1 = dt.NewRow();
    DataRow row2 = dt.NewRow();
    row1["ID"] = 392;
    row2["ID"] = 477;
    dt.Rows.Add(row1);
    dt.Rows.Add(row2);

    db.CreateCommand("SelectTableVariableTestItai");
    db.AddParameter("TableVar", dt, SqlDbType.Structured);

    return db.ExecuteDataTable();
}

No comments:

Post a Comment