Click here to monitor SSC
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


How to get result sets when using dynamic query


How to get result sets when using dynamic query

Author
Message
hafsahafeez91
hafsahafeez91
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 31
Lynn yes i didnt ! I just saw the format in which things were placed in the article!

Table DDL:

USE [OEAS]
GO

/****** Object: Table [dbo].[51] Script Date: 04/05/2013 21:07:16 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE TABLE [dbo].[51](
[ID] [bigint] IDENTITY(1,1) NOT NULL,
[Exam_ID] [bigint] NOT NULL,
[Paper_ID] [bigint] NOT NULL,
[Question_ID] [bigint] NOT NULL,
[Section_ID] [bigint] NOT NULL,
CONSTRAINT [PK_51] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]



Sample data :

INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,3,1)
INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,6,1)
INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,10,1)
INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,14,1)

Output Expected :

1 ; 3 | 2 ; 6 | 3 ; 10 | 4 ; 14 |
hafsahafeez91
hafsahafeez91
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 31
hey lynn !

Table DDL:
USE [OEAS]
GO

/****** Object: Table [dbo].[51] Script Date: 04/05/2013 21:16:07 ******/
SET ANSI_NULLS ON
GO

SET QUOTED_IDENTIFIER ON
GO

CREATE TABLE [dbo].[51](
[ID] [bigint] IDENTITY(1,1) NOT NULL,
[Exam_ID] [bigint] NOT NULL,
[Paper_ID] [bigint] NOT NULL,
[Question_ID] [bigint] NOT NULL,
[Section_ID] [bigint] NOT NULL,
CONSTRAINT [PK_51] PRIMARY KEY CLUSTERED
(
[ID] ASC
)WITH (PAD_INDEX = OFF, STATISTICS_NORECOMPUTE = OFF, IGNORE_DUP_KEY = OFF, ALLOW_ROW_LOCKS = ON, ALLOW_PAGE_LOCKS = ON) ON [PRIMARY]
) ON [PRIMARY]

GO

Sample Data:
INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,3,1)

INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,10,1)

INSERT INTO [OEAS].[dbo].[51] ([Exam_ID] ,[Paper_ID] ,[Question_ID] ,[Section_ID]) VALUES (1,1,12,1)


Expected Output of SP :


1;3|2;10|3;12|
Lynn Pettis
Lynn Pettis
SSC-Insane
SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)SSC-Insane (24K reputation)

Group: General Forum Members
Points: 24180 Visits: 37950
The following should work.



CREATE PROCEDURE [dbo].[Get_Ques_id_for_can](
@candidate_id varchar(max),
@Exam_id varchar(max),
@sec_id bigint,
@Q_id varchar(max) OUTPUT
)
AS
declare @table_query nvarchar(max);
declare @table nvarchar(max);
declare @sparam nvarchar(max);
set @sparam = N'@SecID bigint, @QID varchar(max) OUTPUT';
set @table = @candidate_ID + @Exam_id;
declare @id varchar(50);
declare @ques_id varchar(50);

set @table_query = --N'SELECT @ID = [ID], @QID = [Question_ID] FROM [' + @table + N'] WHERE [Section_ID] = ' + CONVERT(varchar(50),@sec_id)
N'select
@QID = stuff((select
''|'' + cast(ID as varchar) + '';'' + cast(Question_ID as varchar)
from
[' + @table + N']
where
Section_id = @SecID
order by
ID
for xml path(''''),TYPE).value(''.'',''varchar(max)''),1,1,'''')'


exec sp_executesql @table_query, @sparam, @SecID = @sec_id, @QID = @Q_id OUTPUT;

GO

/* how this procedure should be invoked. The ?? represent values passed into the procedure */

declare @QuesID varchar(max);
exec dbo.Get_Ques_id_for_can @candidate_id = ??, @Exam_id = ??, @sec_id = ??, @Q_id = @QuesID OUTPUT;
go




Cool
Lynn Pettis

For better assistance in answering your questions, click here
For tips to get better help with Performance Problems, click here
For Running Totals and its variations, click here or when working with partitioned tables
For more about Tally Tables, click here
For more about Cross Tabs and Pivots, click here and here
Managing Transaction Logs

SQL Musings from the Desert Fountain Valley SQL (My Mirror Blog)
hafsahafeez91
hafsahafeez91
Grasshopper
Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)Grasshopper (16 reputation)

Group: General Forum Members
Points: 16 Visits: 31
Yes i does ! Thanks a lot Lynn! :-)
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search