May 11, 2006 at 10:27 am
I was asked to QA this proc.
To me it looks like a big mess..
Which would be better to use cursor, loop or case statements?
I'ved included the SP and the table schema.. any help would be greatly appreciated.
ALTER PROCEDURE dbo.usp_GetRNLeadsCapOptimization
@LookBackDays INT,
@LeadTimeFrame INT,
@PropertyValue INT,
@WorkWithRealtor TINYINT,
@LeadTypeID TINYINT,
@strZIP VARCHAR(5)
AS
DECLARE @PriceRange MONEY,
@DateIn DATETIME
BEGIN
SET @DateIn = CAST(CONVERT(VARCHAR(10), DATEADD(d, -@LookBackDays, CURRENT_TIMESTAMP), 101) AS DATETIME) + CAST('12:00:00AM' AS DATETIME)
SET @PriceRange = 100000.0000
IF (@PropertyValue = 1)
SET @PriceRange = 100000.0000
ELSE IF (@PropertyValue = 2)
SET @PriceRange = 200000.0000
ELSE IF (@PropertyValue = 3)
SET @PriceRange = 300000.0000
ELSE IF (@PropertyValue = 4)
SET @PriceRange = 400000.0000
ELSE IF (@PropertyValue = 5)
SET @PriceRange = 500000.0000
ELSE IF (@PropertyValue = 6)
SET @PriceRange = 600000.0000
ELSE IF (@PropertyValue = 7)
SET @PriceRange = 700000.0000
ELSE IF (@PropertyValue = 8)
SET @PriceRange = 800000.0000
ELSE IF (@PropertyValue = 9)
SET @PriceRange = 900000.0000
ELSE IF (@PropertyValue = 10)
SET @PriceRange = 1000000.0000
ELSE IF (@PropertyValue = 11)
SET @PriceRange = 2000000.0000
ELSE IF (@PropertyValue = 12)
SET @PriceRange = 3000000.0000
ELSE IF (@PropertyValue = 13)
SET @PriceRange = 4000000.0000
ELSE IF (@PropertyValue = 14)
SET @PriceRange = 5000000.0000
ELSE IF (@PropertyValue = 15)
SET @PriceRange = 6000000.0000
ELSE IF (@PropertyValue = 16)
SET @PriceRange = 7000000.0000
ELSE IF (@PropertyValue = 17)
SET @PriceRange = 8000000.0000
ELSE IF (@PropertyValue = 18)
SET @PriceRange = 9000000.0000
ELSE IF (@PropertyValue = 19)
SET @PriceRange = 10000000.0000
IF (@WorkWithRealtor = 0)
BEGIN
IF (@LeadTimeFrame = 1)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1 -- BUY
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3 --BUY/SELL
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2 --SELL
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3 --BUY/SELL
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 2)
BEGIN
IF(@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 3)
BEGIN
IF(@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 4)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 5)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
END
ELSE IF (@WorkWithRealtor = 1)
BEGIN
IF (@LeadTimeFrame = 1)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 2)
BEGIN
IF(@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 3)
BEGIN
IF(@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 4)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (23, 24, 25, 107)
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
ELSE IF(@LeadTimeFrame = 5)
BEGIN
IF (@LeadTypeID = 1)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 1
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 2
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.lead_type_id = 3
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 96
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
END
END
END
END
---Table schema
CREATE TABLE [dbo].[tbl_leads_queue] (
[lead_id] [bigint] IDENTITY (1, 1) NOT NULL ,
[parent_lead_id] [bigint] NOT NULL ,
[partner_id] [int] NOT NULL ,
[RealtorCompanyID] [bigint] NOT NULL ,
[RealtorPrimaryContactUserName] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorPrimaryContactFirstName] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorPrimaryContactLastName] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorCompanyName] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorTotalOffices] [int] NOT NULL ,
[RealtorTotalAgents] [int] NOT NULL ,
[RealtorBrandLogoURL] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorMoreInfoURL] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[RealtorWeekendCoverage] [bit] NOT NULL ,
[RealtorCustomerServiceRating] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[DesiredMonthlyPayment] [float] NOT NULL ,
[realtor_id] [bigint] NULL ,
[lead_type_id] [int] NOT NULL ,
[lead_status_id] [int] NOT NULL ,
[buy_property_type_id] [int] NULL ,
[sell_property_type_id] [int] NULL ,
[time_frame_id] [int] NOT NULL ,
[best_time_id] [int] NOT NULL ,
[matched_on] [varchar] (200) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[first_name] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[last_name] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[address] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[city] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[state] [varchar] (2) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[zip] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[phone_area] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[phone_prefix] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[phone_suffix] [varchar] (4) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[phone_ext] [varchar] (10) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[phone_area2] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[phone_prefix2] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[phone_suffix2] [varchar] (4) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_zip_1] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_city_state_1] [varchar] (150) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_zip_2] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[buy_city_state_2] [varchar] (150) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[buy_zip_3] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[buy_city_state_3] [varchar] (150) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[buy_price_range_start] [money] NOT NULL ,
[buy_price_range_end] [money] NOT NULL ,
[buy_square_footage] [varchar] (25) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_bedroom_count] [varchar] (5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_bathroom_count] [varchar] (5) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[buy_detail_list] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[sell_price_desired] [money] NULL ,
[sell_price_qualifying] [money] NULL ,
[sell_square_footage] [varchar] (25) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[sell_bedroom_count] [varchar] (5) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[sell_bathroom_count] [varchar] (5) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[sell_detail_list] [varchar] (255) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[comments] [varchar] (1000) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[additional_info] [varchar] (1000) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[lead_fee] [money] NOT NULL ,
[no_charge] [int] NULL ,
[credited] [int] NOT NULL ,
[lead_problem] [int] NULL ,
[date_in] [datetime] NOT NULL ,
[date_sent] [datetime] NULL ,
[TrafficLogID] [bigint] NOT NULL ,
[notify_offers] [bit] NOT NULL ,
[credit_history] [varchar] (50) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[has_agent] [bit] NOT NULL ,
[found_home] [bit] NOT NULL ,
[cell_area] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[cell_prefix] [varchar] (3) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[cell_suffix] [varchar] (4) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[why_selling] [varchar] (100) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[is_buysell] [bit] NOT NULL ,
[Affiliate_ID] [bigint] NULL ,
[free_mortgage_quote] [bit] NOT NULL ,
[loan_type] [varchar] (100) COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[gross_monthly_income] [float] NOT NULL ,
[can_verify_income] [bit] NOT NULL ,
[desired_loan_amount] [float] NOT NULL ,
[existing_loan_balance] [float] NOT NULL ,
[first_mortgage_monthly_payment] [float] NOT NULL ,
[current_interest_rate] [float] NOT NULL ,
[RealtorNotes] [text] COLLATE SQL_Latin1_General_CP1_CI_AS NOT NULL ,
[NumSold] [int] NOT NULL ,
[is_available] [bit] NOT NULL ,
[Date_Declined] [datetime] NULL ,
[Expired] [bit] NOT NULL ,
[Original_Affiliate] [bigint] NULL ,
[lead_distance] [float] NULL ,
[lead_Problem_Comments] [varchar] (2500) COLLATE SQL_Latin1_General_CP1_CI_AS NULL ,
[AdminUserID] [int] NULL ,
[dateCredited] [datetime] NULL ,
[OriginalAffiliateID] [bigint] NULL
) ON [PRIMARY] TEXTIMAGE_ON [PRIMARY]
GO
May 11, 2006 at 11:08 am
I can't think why you think it looks like a big mess!
For a start there's nothing in the proc which tells anyone what it's supposed to do. But then there's nothing in your post either. Can you give us some help?
Ryan Randall
Solutions are easy. Understanding the problem, now, that's the hard part.
May 11, 2006 at 11:23 am
i can see a minor improvement; it looks like that huge if-then-else to get the @PriceRange could be replaced by a three line case statement:
SET @PriceRange = (CASE WHEN @PropertyValue BETWEEN 1 AND 10 THEN @PropertyValue * 100000
WHEN @PropertyValue BETWEEN 11 AND 18 THEN (@PropertyValue -10) * 1000000 + 1000000
ELSE 10000000)
the rest, i think we need to know what it is doing; it looks like it could be merged , but it would take some analysis
Lowell
May 11, 2006 at 11:39 am
Yep - I agree with all of that
Ryan Randall
Solutions are easy. Understanding the problem, now, that's the hard part.
May 11, 2006 at 11:53 am
MAYBE another indicator is this: the only difference i see forwhen
IF (@LeadTimeFrame = 1)
is evaluated, the SQL is the same except for an additional check in the WHERE condition:
AND tlq.time_frame_id IN (23, 24, 25, 107)
@LeadTimeFrame = 1 = IN(23)
@LeadTimeFrame = 2 = IN(23,24)
@LeadTimeFrame = 3 = IN(23,24,25)
@LeadTimeFrame = 4 = IN(23,24,25,107)
@LeadTimeFrame = 5 = IN(96)
changes the in() statement; by evaluating that at the very top, you could get rid of 10 groups of repetitious code. maybe using the split() function from ssc to use an table variable.
Lowell
May 11, 2006 at 12:18 pm
Just started here, so here's what I got. I would ask the developer, but he's already gone (now I see why;-))
We are trying to pull leads from a table that have not been sold (numbsold), is available, not expired, has no agent
Here's an example of a leadtimeframeid - 1= 1month , 2=1-3months 3= 4-5months
Here's an example of LeadtypeID 1= sell 2=buy 3=buy/sell
He seems to be going through the table and looking for a variation of each..
Such as for leadtimeframe 1, pull leadstypes 1 and 2 and union each on the 3.
The result set should be as follows -
lead_id,parent_lead_id,lead_type_id, buy_zip_1, buy_zip_2, buy_zip_3, zip
Hope that explains it!!
May 11, 2006 at 12:29 pm
Lowell,
Can you provide me with an example of the split function you mentioned?
I don't see it in BOL
Thanks
Susan
May 11, 2006 at 1:00 pm
there are quite a few on this site;
here is an example using this version of split:
http://www.sqlservercentral.com/scripts/viewscript.asp?scriptid=225
declare @string varchar(200),
@LeadTimeFrame int
set @LeadTimeFrame=3
if @LeadTimeFrame = 1 set @string='24'
else if @LeadTimeFrame = 2 set @string='23,24'
else if @LeadTimeFrame = 3 set @string='23,24,25'
else if @LeadTimeFrame = 4 set @string='23,24,25,107'
else if @LeadTimeFrame = 5 set @string='96'
select element from master.dbo.split(@string,',')
results:
element
-------
23
24
25
so that one section id change to:
AND tlq.time_frame_id IN (
select element from master.dbo.split(@string,',')
)
Lowell
May 11, 2006 at 3:00 pm
I've made the modifications suggested, but am having trouble creating it.
I get the following error - Maybe I've been looking at it too long, but I don't see the issue
Server: Msg 170, Level 15, State 1, Procedure usp_GetRNLeadsCapOptimizationNEW, Line 23
Line 23: Incorrect syntax near ')'.
alter PROCEDURE dbo.usp_GetRNLeadsCapOptimizationNEW --30,1,1, 0, 1, 94546
@LookBackDays INT,
@LeadTimeFrame INT,
@PropertyValue INT,
@WorkWithRealtor TINYINT,
@LeadTypeID TINYINT,
@strZIP VARCHAR(5)
AS
DECLARE @PriceRange MONEY,
@DateIn DATETIME,
@string varchar(200)
BEGIN
SET @DateIn = CAST(CONVERT(VARCHAR(10), DATEADD(d, -@LookBackDays, CURRENT_TIMESTAMP), 101) AS DATETIME) + CAST('12:00:00AM' AS DATETIME)
SET @PriceRange =
(CASE WHEN @PropertyValue BETWEEN 1 AND 10
THEN @PropertyValue * 100000
WHEN @PropertyValue BETWEEN 11 AND 18
THEN (@PropertyValue -10) * 1000000 + 1000000
ELSE 10000000)
if @LeadTimeFrame = 1 set @string='24'
else if @LeadTimeFrame = 2 set @string='23,24'
else if @LeadTimeFrame = 3 set @string='23,24,25'
else if @LeadTimeFrame = 4 set @string='23,24,25,107'
else if @LeadTimeFrame = 5 set @string='96'
IF (@WorkWithRealtor = 0)
BEGIN
IF (@LeadTypeID = 1)
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 1 -- BUY
AND ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
AND tlq.time_frame_id IN (select element from master.dbo.split(@string,','))
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3 --BUY/SELL
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id IN (select element from master.dbo.split(@string,','))
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND (tlq.buy_zip_1 = @strZIP OR ISNULL(tlq.buy_zip_2, '') = @strZIP OR ISNULL(tlq.buy_zip_3, '') = @strZIP)
ORDER BY tlq.lead_id, tlq.lead_type_id
END
ELSE IF(@LeadTypeID = 2)
BEGIN
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 2 --SELL
AND ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
UNION
SELECT tlq.lead_id, tlq.parent_lead_id, tlq.lead_type_id,
tlq.buy_zip_1, ISNULL(tlq.buy_zip_2, '') AS buy_zip_2, ISNULL(tlq.buy_zip_3, '') AS buy_zip_3, tlq.zip
FROM tbl_leads_queue tlq WITH (NOLOCK)
WHERE tlq.lead_id = tlq.parent_lead_id
AND tlq.NumSold = 0
AND tlq.is_available = 1
AND tlq.Expired = 0
AND tlq.has_agent = 0
AND tlq.lead_type_id = 3 --BUY/SELL
AND (
ISNULL(tlq.buy_price_range_start, 0) >= @PriceRange
OR
ISNULL(tlq.sell_price_qualifying, 0) >= @PriceRange
)
AND tlq.time_frame_id = 23
AND NOT EXISTS (SELECT lead_id FROM tbl_leads_queue WITH (NOLOCK)
WHERE parent_lead_id = tlq.parent_lead_id
AND (lead_status_id = 3 OR lead_status_id = 4))
AND tlq.date_in >= @DateIn
AND tlq.zip = @strZIP
ORDER BY tlq.lead_id, tlq.lead_type_id
end
end
GO
May 11, 2006 at 3:22 pm
just missing the END command of the case statement: let me know how this seems to work now
(CASE WHEN @PropertyValue BETWEEN 1 AND 10
THEN @PropertyValue * 100000
WHEN @PropertyValue BETWEEN 11 AND 18
THEN (@PropertyValue -10) * 1000000 + 1000000
ELSE 10000000 END)
Lowell
May 12, 2006 at 5:44 am
You have my sympathy... this is really a terrible piece of code, especially with no comments. What I would probably attempt (except kicking the author of procedure in the ...) is :
- find all uses of the procedure - when it is called, how the result is used further
- break down the procedure into pieces and describe (in words) what every piece does
- check whether the pieces can be logically better organized and try to find the shortest way how to fully describe the process - still only in words
- write a new procedure from scratch to fit the new description and include descriptive comments
In my opinion, we can try and offer some minor improvements that will make the code shorter and more readable, but we can not decide whether the entire procedure couldn't be written differently (and if so, then how), if we have no idea what it is and how it is used.
HTH, Vladan
May 12, 2006 at 9:40 am
Thanks for your help. It did the trick and doesn't look like such a mess..
Thanks again
Susan
Viewing 12 posts - 1 through 11 (of 11 total)
You must be logged in to reply to this topic. Login to reply