USP_DATAFORMTEMPLATE_VIEW_NEWCHILDELIGIBILITY

The load procedure used by the view dataform template "Sponsorship Settings Default Child Eligibility View Form"

Parameters

Parameter Parameter Type Mode Description
@DATALOADED bit INOUT Output parameter indicating whether or not data was actually loaded.
@DEFAULTCHILDELIGIBILITY nvarchar(8) INOUT For default eligibility
@REASONS nvarchar(500) INOUT Pending eligibility reason(s)

Definition

Copy


                CREATE procedure dbo.USP_DATAFORMTEMPLATE_VIEW_NEWCHILDELIGIBILITY
                (
                    @DATALOADED bit = 0 output,
                    @DEFAULTCHILDELIGIBILITY nvarchar(8) = null output,
                    @REASONS nvarchar(500) = null output
                )
                as
                    set nocount on;

                    -- be sure to set this, in case the select returns no rows

                    set @DATALOADED = 0;

                    -- populate the output parameters, which correspond to fields on the form.  Note that

                    -- we set @DATALOADED = 1 to indicate that the load was successful.  Otherwise, the system

                    -- will display a "no data loaded" message.

                    select 
                        @DATALOADED = 1,
                        @DEFAULTCHILDELIGIBILITY = DEFAULTCHILDELIGIBILITY
                    from 
                        dbo.SPONSORSHIPINFO
                    order by DATEADDED

                    -- assume default eligibility will be Eligible

                    set @REASONS = 'N/A'

                    if @DEFAULTCHILDELIGIBILITY = 'Pending'
                    begin

                        declare @SPONSORSHIPREASONID uniqueidentifier
                        declare @REASONSXML xml = (select top 1 CHILDPENDINGREASONS from dbo.SPONSORSHIPINFO)
                        declare @NEXTREASON nvarchar(100)

                        -- get all applicable reasons

                        declare REASONSCURSOR cursor local fast_forward for
                        select
                            T.c.value('(SPONSORSHIPREASONID)[1]','uniqueidentifier')
                        from
                            @REASONSXML.nodes('/CHILDPENDINGREASONS/ITEM') T(c)

                        open REASONSCURSOR

                        -- get first reason, overwriting default

                        fetch next from REASONSCURSOR into @SPONSORSHIPREASONID
                        select @REASONS = REASON from dbo.SPONSORSHIPREASON where ID = @SPONSORSHIPREASONID
                        fetch next from REASONSCURSOR into @SPONSORSHIPREASONID

                        -- get additional reasons, appending commas

                        while @@FETCH_STATUS = 0
                        begin
                            select @NEXTREASON = REASON from dbo.SPONSORSHIPREASON where ID = @SPONSORSHIPREASONID
                            set @REASONS = @REASONS + ', ' + @NEXTREASON
                            fetch next from REASONSCURSOR into @SPONSORSHIPREASONID
                        end

                        --When a cursor is used, it should be explicitly closed/deallocated in case of blocking or USP running long

                        close REASONSCURSOR;
                        deallocate REASONSCURSOR;

                    end

                    return 0;